├── .github ├── ISSUE_TEMPLATE.md └── PULL_REQUEST_TEMPLATE.md ├── .gitignore ├── queries ├── README.md ├── enrollments │ ├── GrabActiveEnrollments.sql │ ├── GrabStudentEnrollments.sql │ └── README.md ├── requests │ ├── LastTeacherActivity.sql │ ├── StudentLoginToCourseCounter.sql │ └── README.md ├── scores │ ├── README.md │ ├── GrabZeroScores.sql │ ├── GrabAverageScore.sql │ └── GrabLowScores.sql └── submissions │ ├── GrabLateSubmissions.sql │ ├── GrabNoSubmissions.sql │ ├── README.md │ └── GrabNoSubmissionsChecker.sql ├── README.md ├── LICENSE └── CONTRIBUTING.md /.github/ISSUE_TEMPLATE.md: -------------------------------------------------------------------------------- 1 | ### Summary: 2 | 3 | ### Expected behavior: 4 | 5 | ### Additional notes: 6 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # History files 2 | .Rhistory 3 | .Rapp.history 4 | 5 | # Example code in package build process 6 | *-Ex.R 7 | 8 | # RStudio files 9 | .Rproj.user/ 10 | 11 | # produced vignettes 12 | vignettes/*.html 13 | vignettes/*.pdf 14 | -------------------------------------------------------------------------------- /queries/README.md: -------------------------------------------------------------------------------- 1 | # queries/ # 2 | 3 | Each set of queries are broken up into their own directory. This will hopefully make it easier to 4 | help find exactly what it is you're looking for. If you don't see it here, chances are it could 5 | be answered somewhere in the community. Just not added inside the repo yet. So it's best to search/ask 6 | in the community. 7 | -------------------------------------------------------------------------------- /queries/enrollments/GrabActiveEnrollments.sql: -------------------------------------------------------------------------------- 1 | SELECT u.id, 2 | u.canvas_id, 3 | u.name, 4 | u.sortable_name, 5 | COUNT( DISTINCT e.course_section_id ) as enrollment_count 6 | FROM enrollment_dim e 7 | INNER JOIN user_dim u ON e.user_id = u.id 8 | WHERE ( e.workflow_state = 'active' ) 9 | GROUP BY u.id, u.canvas_id, u.name, u.sortable_name 10 | ORDER BY enrollment_count DESC; 11 | -------------------------------------------------------------------------------- /queries/enrollments/GrabStudentEnrollments.sql: -------------------------------------------------------------------------------- 1 | SELECT DISTINCT(u.id), 2 | u.canvas_id, 3 | u.name, 4 | u.sortable_name, 5 | COUNT( DISTINCT e.course_section_id ) as student_enrollment_count 6 | FROM enrollment_dim e 7 | INNER JOIN user_dim u ON e.user_id = u.id 8 | WHERE ( e.type = 'StudentEnrollment' ) 9 | GROUP BY u.id, u.canvas_id, u.name, u.sortable_name 10 | ORDER BY student_enrollment_count DESC; 11 | -------------------------------------------------------------------------------- /queries/requests/LastTeacherActivity.sql: -------------------------------------------------------------------------------- 1 | SELECT DISTINCT(requests.user_id), 2 | MAX(requests.timestamp_day), 3 | u.canvas_id, 4 | u.name, 5 | count(1) 6 | FROM requests 7 | INNER JOIN user_dim AS u ON requests.user_id = u.id 8 | INNER JOIN enrollment_dim AS ed ON ed.course_id = requests.course_id AND ed.user_id = u.id AND ed.type='TeacherEnrollment' 9 | GROUP BY requests.user_id,requests.timestamp_day,u.canvas_id,u.name; 10 | -------------------------------------------------------------------------------- /queries/requests/StudentLoginToCourseCounter.sql: -------------------------------------------------------------------------------- 1 | SELECT DISTINCT(ed.course_id), 2 | requests.user_id, 3 | u.canvas_id, 4 | u.name, 5 | COUNT(DISTINCT requests.session_id) 6 | FROM requests 7 | INNER JOIN user_dim AS u ON requests.user_id = u.id 8 | INNER JOIN enrollment_dim AS ed ON ed.course_id = requests.course_id AND ed.user_id = u.id AND ed.type='StudentEnrollment' 9 | GROUP BY requests.user_id,ed.course_id,u.canvas_id,u.name; 10 | -------------------------------------------------------------------------------- /queries/enrollments/README.md: -------------------------------------------------------------------------------- 1 | # enrollments/ # 2 | 3 | | Filename | Function | 4 | |:---------------------------|:--------------------------------------------------------------------------| 5 | | GrabStudentEnrollments.sql | Grabs the number of student enrollments per user. | 6 | | GrabActiveEnrollments.sql | Grabs the number of active enrollments regardless of the enrollment type. | 7 | -------------------------------------------------------------------------------- /queries/requests/README.md: -------------------------------------------------------------------------------- 1 | # requests/ # 2 | 3 | | Filename | Function | 4 | |:--------------------------------|:---------------------------------------------------------------------------------------| 5 | | LastTeacherActivity.sql | Checks the requests table to find the last time a teacher was "active", on canvas. | 6 | | StudentLoginToCourseCounter.sql | Counts all the times the student has made a new login to canvas, and visited a course. | 7 | -------------------------------------------------------------------------------- /.github/PULL_REQUEST_TEMPLATE.md: -------------------------------------------------------------------------------- 1 | *Before* submitting a pull request, please make sure the following is done... 2 | 3 | 1. Fork the repo and create your branch from `master`. 4 | 2. Write your queries, and add them to the repo. 5 | 3. If you've written any queries that are not compatible with redshift make note of it, and which 6 | engine the SQL query is for. 7 | 4. Ensure your commit message follows the contributing guidelines. 8 | 9 | Please use the simple form below as a guideline for describing your pull request. 10 | 11 | Thanks for contributing to Canvas Hosted Data Examples! 12 | 13 | - 14 | 15 | **Summary** 16 | 17 | [...] 18 | -------------------------------------------------------------------------------- /queries/scores/README.md: -------------------------------------------------------------------------------- 1 | # scores/ # 2 | 3 | | Filename | Function | 4 | |:---------------------|:------------------------------------------------------------------------------------------------------| 5 | | GrabAverageScore.sql | Grabs the Average Score for each Student in each course. | 6 | | GrabLowScores.sql | Grabs scores that are less than 60% of the total points, but greater than 0 points for an assignment. | 7 | | GrabZeroScores.sql | Grabs scores that are 0 for a particular submission. | 8 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Canvas Hosted-Data Examples # 2 | 3 | Collection of examples that use Canvas Hosted Data to answer questions. Specifically some example 4 | queries that you can run inside your redshift instance in order to get useful data out of the queries. 5 | If you have some queries that are proving very useful to solve problems in your institution, we'd love 6 | for you to share it by opening a pull request! See `CONTRIBUTING.md` in the root of this repo. 7 | 8 | ## queries/ ## 9 | 10 | The `queries/` folder is where you'll find all the juicy stuff. These are where queries that can be 11 | copy/pasted into redshift are located. You'll want to connect with either SQLWorkbenchJ, PSQL, or some 12 | other raw SQL tool in order to run these queries. 13 | -------------------------------------------------------------------------------- /queries/submissions/GrabLateSubmissions.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | u.id, 3 | u.canvas_id, 4 | u.name, 5 | u.sortable_name, 6 | c.id, 7 | c.name, 8 | c.code, 9 | a.id, 10 | a.title, 11 | a.due_at, 12 | sd.submitted_at, 13 | sd.attempt, 14 | sd.excused, 15 | sd.grade_state, 16 | sd.workflow_state 17 | FROM enrollment_dim e 18 | INNER JOIN course_dim c ON e.course_id = c.id 19 | INNER JOIN assignment_dim a ON c.id = a.course_id 20 | INNER JOIN submission_fact sf ON a.id = sf.assignment_id AND e.user_id = sf.user_id 21 | INNER JOIN submission_dim sd ON sf.submission_id = sd.id 22 | INNER JOIN user_dim u ON sf.user_id = u.id 23 | WHERE 24 | (e.type = 'StudentEnrollment' AND e.workflow_state = 'active') AND 25 | (a.workflow_state = 'published') AND 26 | (sd.submitted_at > a.due_at); 27 | -------------------------------------------------------------------------------- /queries/submissions/GrabNoSubmissions.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | u.id, 3 | u.canvas_id, 4 | u.name, 5 | u.sortable_name, 6 | c.id, 7 | c.name, 8 | c.code, 9 | a.id, 10 | a.title, 11 | sd.graded_at, 12 | sd.attempt, 13 | sd.excused, 14 | sd.grade_state, 15 | sd.workflow_state 16 | FROM enrollment_dim e 17 | INNER JOIN course_dim c ON e.course_id = c.id 18 | INNER JOIN assignment_dim a ON c.id = a.course_id 19 | LEFT OUTER JOIN submission_fact sf ON a.id = sf.assignment_id AND e.user_id = sf.user_id 20 | LEFT OUTER JOIN submission_dim sd ON sf.submission_id = sd.id 21 | INNER JOIN user_dim u ON sf.user_id = u.id 22 | WHERE 23 | (e.type = 'StudentEnrollment' AND e.workflow_state = 'active') AND 24 | (a.workflow_state = 'published') AND 25 | (sd.id IS NULL OR sd.workflow_state IN ('unsubmitted')); 26 | -------------------------------------------------------------------------------- /queries/submissions/README.md: -------------------------------------------------------------------------------- 1 | # submissions/ # 2 | 3 | | Filename | Function | 4 | |:-----------------------------|:---------------------------------------------------------------------------------------------------------------------------| 5 | | GrabLateSubmissions.sql | Grabs a list of all students who have submitted an assignment late. | 6 | | GrabNoSubmissions.sql | Grabs a list of all students who have not yet submitted to published assignment. | 7 | | GrabNoSubmissionsChecker.sql | Grabs a list of all students who have not yet submitted to published assignment, yet actually checks assignment due dates. | 8 | -------------------------------------------------------------------------------- /queries/submissions/GrabNoSubmissionsChecker.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | u.id, 3 | u.canvas_id, 4 | u.name, 5 | u.sortable_name, 6 | c.id, 7 | c.name, 8 | c.code, 9 | a.id, 10 | a.title, 11 | sd.graded_at, 12 | sd.attempt, 13 | sd.excused, 14 | sd.grade_state, 15 | sd.workflow_state 16 | FROM enrollment_dim e 17 | INNER JOIN course_dim c ON e.course_id = c.id 18 | INNER JOIN assignment_dim a ON c.id = a.course_id 19 | LEFT OUTER JOIN submission_fact sf ON a.id = sf.assignment_id AND e.user_id = sf.user_id 20 | LEFT OUTER JOIN submission_dim sd ON sf.submission_id = sd.id 21 | INNER JOIN user_dim u ON e.user_id = u.id 22 | WHERE 23 | (e.type = 'StudentEnrollment' AND e.workflow_state = 'active') AND 24 | (a.workflow_state = 'published') AND 25 | (sd.id IS NULL OR sd.workflow_state IN ('unsubmitted')) AND 26 | (a.due_at < getdate()); 27 | -------------------------------------------------------------------------------- /queries/scores/GrabZeroScores.sql: -------------------------------------------------------------------------------- 1 | --- It should be noted that this isn't a perfect query. There's a lot of logic that goes into grades, and this 2 | --- is fairly naive. You should take this into account as this is just to get you started. 3 | 4 | SELECT 5 | u.id, 6 | u.canvas_id, 7 | u.name, 8 | u.sortable_name, 9 | c.id, 10 | c.name, 11 | c.code, 12 | a.canvas_id, 13 | a.title, 14 | a.description, 15 | a.due_at, 16 | a.points_possible 17 | FROM enrollment_dim e 18 | INNER JOIN course_dim c ON e.course_id = c.id 19 | INNER JOIN assignment_dim a ON c.id = a.course_id 20 | LEFT OUTER JOIN submission_fact sf ON a.id = sf.assignment_id AND e.user_id = sf.user_id 21 | INNER JOIN user_dim u ON e.user_id = u.id 22 | WHERE 23 | (e.type = 'StudentEnrollment' AND e.workflow_state = 'active') AND 24 | (a.workflow_state = 'published') AND 25 | sf.score = 0; 26 | -------------------------------------------------------------------------------- /queries/scores/GrabAverageScore.sql: -------------------------------------------------------------------------------- 1 | --- It should be noted that this isn't a perfect query. There's a lot of logic that goes into grades, and this 2 | --- is fairly naive. You should take this into account as this is just to get you started. 3 | 4 | SELECT 5 | u.id, 6 | u.canvas_id, 7 | u.name, 8 | u.sortable_name, 9 | c.id, 10 | c.name, 11 | c.code, 12 | (SUM(sf.score) / NULLIF(SUM(a.points_possible), 0)) as avg 13 | FROM enrollment_dim e 14 | INNER JOIN course_dim c ON e.course_id = c.id 15 | INNER JOIN assignment_dim a ON c.id = a.course_id 16 | LEFT OUTER JOIN submission_fact sf ON a.id = sf.assignment_id AND e.user_id = sf.user_id 17 | INNER JOIN user_dim u ON e.user_id = u.id 18 | WHERE 19 | (e.type = 'StudentEnrollment' AND e.workflow_state = 'active') AND 20 | (a.workflow_state = 'published') AND 21 | sf.score IS NOT NULL 22 | GROUP BY u.id, u.canvas_id, u.name, u.sortable_name, c.id, c.name, c.code; 23 | -------------------------------------------------------------------------------- /queries/scores/GrabLowScores.sql: -------------------------------------------------------------------------------- 1 | --- It should be noted that this isn't a perfect query. There's a lot of logic that goes into grades, and this 2 | --- is fairly naive. You should take this into account as this is just to get you started. 3 | 4 | SELECT 5 | u.id, 6 | u.canvas_id, 7 | u.name, 8 | u.sortable_name, 9 | c.id, 10 | c.name, 11 | c.code, 12 | a.canvas_id, 13 | a.title, 14 | a.description, 15 | a.due_at, 16 | a.points_possible, 17 | sf.score 18 | FROM enrollment_dim e 19 | INNER JOIN course_dim c ON e.course_id = c.id 20 | INNER JOIN assignment_dim a ON c.id = a.course_id 21 | LEFT OUTER JOIN submission_fact sf ON a.id = sf.assignment_id AND e.user_id = sf.user_id 22 | INNER JOIN user_dim u ON e.user_id = u.id 23 | WHERE 24 | (e.type = 'StudentEnrollment' AND e.workflow_state = 'active') AND 25 | (a.workflow_state = 'published') AND 26 | sf.score IS NOT NULL AND 27 | sf.score > 0 AND 28 | sf.score < (a.points_possible * 0.60); 29 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2015 Instructure, Inc. 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | 23 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | # Contributing to Hosted-Data-Examples # 2 | 3 | If you choose to contribute a pull request to Hosted-Data-Examples, following these guidelines will make things easier 4 | for you and for us: 5 | 6 | - Your pull request should generally consist of a single commit. This helps keep the git history clean 7 | by keeping each commit focused on a single purpose. If you have multiple commits that keep that focus 8 | then that is acceptable, however "train of thought" commits should not be in the history. 9 | - Your commit message should follow this general format: 10 | 11 | ``` 12 | Summary of the commit (Subject) 13 | 14 | Further explanation of the commit, specifically how it will come in useful to other schools, 15 | and maybe even a little bit about how it's helped you. 16 | 17 | closes gh-123 (if this closes a GitHub Issue) 18 | ``` 19 | 20 | - The process your pull request goes through is as follows: 21 | - An Instructure engineer will pull the request down and run it in a demo redshift making sure it returns what appears to be expected results. 22 | - An Instructure engineer will look through your SQL, and make sure there are no "Huge" performance issues that can be quickly resolved. 23 | - Once all these things have occurred then an engineer will merge your commit into the repository. 24 | - Congratulations! You are now a Hosted Data Example contributor! Thank you for helping make Hosted Data Example great. 25 | --------------------------------------------------------------------------------