select enrollment_term_id ,count(enrollment_term_id) as count from canvas.courses group by enrollment_term_id order by enrollment_term_id desc; select id, name, sis_source_id from canvas.enrollment_terms order by sis_source_id ; select c.id, c.workflow_state, c.sis_source_id, c.course_code, c.enrollment_term_id, t.name from canvas.courses c join canvas.enrollment_terms t on c.enrollment_term_id=t.id order by c.sis_source_id, c.course_code; SELECT * FROM information_schema.tables; INSERT INTO canvas.schedule (canvascourse, crn, code, units, teacher, start,"end", type, loc, site, partofday, cap, act, sem) VALUES (9651, '40724', 'SPAN 1A', '5.000', 'David G Perez', '1-27', '5-22', 'in-person', 'HU 105', 'Gilroy', 'Midday', 30, 26, '202030'); -- courses in a semester, good for finding sections to merge select c.id, c.course_code, c.sis_source_id, e.role_id, s.start, s.type, u.sortable_name from canvas.courses c join canvas.enrollments e on c.id=e.course_id join canvas.users u on u.id=e.user_id full outer join canvas.schedule s on c.id=s.canvascourse where c.sis_source_id like '202370-%' and e.role_id=4 order by c.course_code, u.sortable_name; -- courses in a semester, good for finding sections to merge, no users select c.id, c.course_code, c.sis_source_id, s.start, s.type from canvas.courses c full outer join canvas.schedule s on c.id=s.canvascourse where c.sis_source_id like '202370-%' order by c.course_code; select c.id, c.course_code, c.sis_source_id, e.role_id, u.sortable_name from canvas.courses c join canvas.enrollments e on c.id=e.course_id join canvas.users u on u.id=e.user_id where c.sis_source_id like '202470-%' order by c.course_code, u.sortable_name; -- all teachers in (2) semester SELECT distinct c.id, c.name, c.course_code, s.type, s.crn, u.name, u.sortable_name, u.id AS user_cid, p.sis_user_id FROM canvas.courses AS c JOIN canvas.enrollments AS e ON e.course_id=c.id JOIN canvas.users AS u ON u.id=e.user_id JOIN canvas.pseudonyms AS p ON p.user_id=u.id JOIN canvas.schedule as s on c.id=s.canvascourse WHERE (c.sis_source_id LIKE '202450-%' or c.sis_source_id LIKE '202470-%') AND NOT c.workflow_state='deleted' AND e.type='TeacherEnrollment' ORDER BY u.sortable_name; -- teachers of online/onlinelive/hybrid in a semester and their emails select distinct u.sortable_name, LOWER(cc.path) as email from canvas.courses c join canvas.enrollments e on c.id=e.course_id join canvas.users u on u.id=e.user_id join canvas.communication_channels cc on u.id=cc.user_id full outer join canvas.schedule s on c.id=s.canvascourse where (s.type='online' or s.type='hybrid' or s.type='online line') and c.sis_source_id like '202450-%' and cc.path_type='email' and not cc.path like '%noemail%' and not cc.path='sstaff@gavilan.edu' order by u.sortable_name; -- for outlook select string_agg(distinct LOWER(cc.path), '; ') from canvas.courses c join canvas.enrollments e on c.id=e.course_id join canvas.users u on u.id=e.user_id join canvas.communication_channels cc on u.id=cc.user_id full outer join canvas.schedule s on c.id=s.canvascourse where (s.type='online' or s.type='hybrid' or s.type='online line') and c.sis_source_id like '202450-%' and cc.path_type='email' and not cc.path like '%noemail%' and not cc.path='sstaff@gavilan.edu'; -- -- -- users in sp24 and number of each type of course taking -- -- -- one student select u.sortable_name, c.course_code, s.units, s.type, s.start from canvas.users u join canvas.enrollments e on u.id=e.user_id join canvas.courses c on e.course_id=c.id join canvas.schedule s on c.id=s.canvascourse where s.sem='202430' and e.workflow_state='active' and e.type='StudentEnrollment' -- and u.sortable_name='Zendejas, Grace' order by u.sortable_name, s.start, c.course_code ; -- num courses select u.sortable_name, sum(CASE WHEN s.type = 'in-person' THEN 1 ELSE 0 end) AS inperson, sum(CASE WHEN s.type = 'hybrid' THEN 1 ELSE 0 end) AS hybrid, sum(CASE WHEN s.type = 'online' THEN 1 ELSE 0 end) AS online, sum(CASE WHEN s.type = 'online live' THEN 1 ELSE 0 end) AS onlinelive, count(*) as total from canvas.users u join canvas.enrollments e on u.id=e.user_id join canvas.courses c on e.course_id=c.id join canvas.schedule s on c.id=s.canvascourse where s.sem='202430' and e.workflow_state='active' and e.type='StudentEnrollment' group by u.sortable_name order by total desc, online desc, onlinelive desc, hybrid desc; -- num units select u.sortable_name, p.sis_user_id, sum(CASE WHEN s.type = 'in-person' THEN s.units::FLOAT ELSE 0 end) AS inperson, sum(CASE WHEN s.type = 'hybrid' THEN s.units::FLOAT ELSE 0 end) AS hybrid, sum(CASE WHEN s.type = 'online' THEN s.units::FLOAT ELSE 0 end) AS online, sum(CASE WHEN s.type = 'online live' THEN s.units::FLOAT ELSE 0 end) AS onlinelive, sum(s.units::FLOAT) as total from canvas.users u join canvas.enrollments e on u.id=e.user_id join canvas.courses c on e.course_id=c.id join canvas.schedule s on c.id=s.canvascourse join canvas.pseudonyms p on u.id=p.user_id where s.sem='202430' and e.workflow_state='active' and e.type='StudentEnrollment' group by u.sortable_name, p.sis_user_id order by total desc, online desc, onlinelive desc, hybrid desc; -- only units select sum(s.units::FLOAT) as total from canvas.users u join canvas.enrollments e on u.id=e.user_id join canvas.courses c on e.course_id=c.id join canvas.schedule s on c.id=s.canvascourse join canvas.pseudonyms p on u.id=p.user_id where s.sem='202430' and e.workflow_state='active' and e.type='StudentEnrollment' group by u.sortable_name order by total desc; -- each class select u.sortable_name, c.course_code, s.type, s.units::FLOAT from canvas.users u join canvas.enrollments e on u.id=e.user_id join canvas.courses c on e.course_id=c.id join canvas.schedule s on c.id=s.canvascourse where s.sem='202430' and e.workflow_state='active' and e.type='StudentEnrollment' order by u.sortable_name, c.course_code; -- users in orientation shell select e.user_id from canvas.enrollments e where e.course_id = 19094 and e.type='StudentEnrollment' and e.workflow_state='active'; -- new users this (single) semester SELECT u.id, u.name, u.sortable_name, string_agg(c.course_code, ','), COUNT(e.id) AS num FROM canvas.enrollments AS e JOIN canvas.users AS u ON e.user_id=u.id JOIN canvas.courses AS c ON e.course_id=c.id WHERE c.sis_source_id LIKE '202450-%%' AND e.workflow_state='active' AND e.type='StudentEnrollment' AND u.id NOT IN ( SELECT u.id FROM canvas.enrollments AS e JOIN canvas.users AS u ON e.user_id=u.id JOIN canvas.courses AS c ON e.course_id=c.id WHERE c.sis_source_id NOT LIKE '202450-%%' AND e.workflow_state='active' AND e.type='StudentEnrollment' GROUP BY u.id ) GROUP BY u.id ORDER BY num DESC, u.sortable_name -- new users this (summer+fall) semester SELECT u.id, u.name, u.sortable_name, string_agg(c.course_code, ','), COUNT(e.id) AS num FROM canvas.enrollments AS e JOIN canvas.users AS u ON e.user_id=u.id JOIN canvas.courses AS c ON e.course_id=c.id WHERE (c.sis_source_id LIKE '202450-%%' or c.sis_source_id LIKE '202470-%%') AND e.workflow_state='active' AND e.type='StudentEnrollment' AND u.id NOT IN ( SELECT u.id FROM canvas.enrollments AS e JOIN canvas.users AS u ON e.user_id=u.id JOIN canvas.courses AS c ON e.course_id=c.id WHERE (c.sis_source_id NOT LIKE '202450-%%' and c.sis_source_id NOT LIKE '202470-%%') AND e.workflow_state='active' AND e.type='StudentEnrollment' GROUP BY u.id ) GROUP BY u.id ORDER BY num DESC, u.sortable_name