Good evening to this amazing community. @stimme @KeithSmith_au @James @kyle_cole We have taken all your suggestions, and incorporated them, where possible. (It was not always possible, mainly due to time constraints to check them out fully).
I think we may not yet be capturing "nuance" that is possible with Canvas Data (especially as it applies to roles) but I do think the simple report we are generating here gives them (the administrators) what they are asking for. We understand that we need to work further with administrators to better understand and explain the data. (For example, we can get a last date of submission, but I found in spot-checking, that students may have made a submission without receiving a grade for it -- from a teacher's point of view, the submission may not have been "blessed".)
Our team cannot thank you enough for your input. SQL, the database, and understanding Canvas combine together to make the report. What this group brought forward to us was powerful in the extreme, and again, we can't thank you enough for it. Thank you, thank you, thank you.
Below is the latest summary, which our team will now check with API calls and individual course investigation. Again, thank you, and if you see red flags, please feel free to say something.
WITH EmailAddresses AS (
SELECT
p.sis_user_id AS p_sisuserid,
cc.path AS email_address
FROM
public.pseudonyms p
JOIN
public.communication_channels cc ON p.user_id = cc.user_id
WHERE
cc.path_type = 'email'
),
LatestSubmissions AS (
SELECT
SPLIT_PART(u.name, ' ', 2) AS last_name,
SPLIT_PART(u.name, ' ', 1) AS first_name,
p.sis_user_id AS user_id,
et.name AS term_name,
TO_CHAR(et.start_at - INTERVAL '4 hours', 'MM-DD-YYYY HH:MI:SS AM "ET"') AS term_start_date,
c.course_code,
c.name AS course_name,
teachers.teacher_name AS teacher_name,
s.submission_type AS submission_type,
TO_CHAR(s.submitted_at - INTERVAL '4 hours', 'MM-DD-YYYY HH:MI:SS AM "ET"') AS submitted_at,
a.title AS assignment_title,
e.workflow_state AS course_enrollment_status,
ROW_NUMBER() OVER (PARTITION BY u.id, c.id ORDER BY COALESCE(s.submitted_at, '0001-01-01'::timestamp) DESC) AS row_num
FROM
public.users u
JOIN
public.enrollments e ON u.id = e.user_id
JOIN
public.courses c ON e.course_id = c.id
JOIN
public.enrollment_terms et ON c.enrollment_term_id = et.id
JOIN
(SELECT enroll.course_id, users.name AS teacher_name
FROM public.enrollments AS enroll
JOIN public.users AS users ON enroll.user_id = users.id
WHERE enroll.type = 'TeacherEnrollment') AS teachers ON c.id = teachers.course_id
JOIN
public.pseudonyms p ON u.id = p.user_id
JOIN
public.assignments a ON c.id = a.context_id
JOIN
public.submissions s ON s.assignment_id = a.id AND s.user_id = u.id
WHERE
e.type = 'StudentEnrollment'
AND et.sis_source_id = 'SP_2024'
GROUP BY
u.id, c.id, p.sis_user_id, et.name, et.start_at, s.submitted_at, e.workflow_state, teacher_name, submission_type, assignment_title
)
SELECT
last_name,
first_name,
user_id,
ea.email_address,
term_name,
term_start_date,
course_code,
course_name,
teacher_name,
submission_type,
submitted_at,
assignment_title,
course_enrollment_status
FROM
LatestSubmissions
LEFT JOIN
EmailAddresses ea ON LatestSubmissions.user_id = ea.p_sisuserid
WHERE
row_num = 1
ORDER BY
last_name, course_code ASC;