-

Note: You are currently viewing documentation for Moodle 3.10. Up-to-date documentation for the latest stable version of Moodle may be available here: ad-hoc contributed reports.

ad-hoc contributed reports: Difference between revisions

From MoodleDocs
(updating syntax highlighting)
 
(169 intermediate revisions by 21 users not shown)
Line 3: Line 3:


===Count number of distinct learners and teachers enrolled per category (including all its sub categories)===
===Count number of distinct learners and teachers enrolled per category (including all its sub categories)===
<code sql>SELECT COUNT(DISTINCT lra.userid) AS learners, COUNT(DISTINCT tra.userid) as teachers
<syntaxhighlight lang="SQL">
SELECT COUNT(DISTINCT lra.userid) AS learners, COUNT(DISTINCT tra.userid) as teachers
FROM prefix_course AS c #, mdl_course_categories AS cats
FROM prefix_course AS c #, mdl_course_categories AS cats
LEFT JOIN prefix_context AS ctx ON c.id = ctx.instanceid
LEFT JOIN prefix_context AS ctx ON c.id = ctx.instanceid
Line 15: Line 16:
)
)
AND lra.roleid=5
AND lra.roleid=5
AND tra.roleid=3</code>
AND tra.roleid=3
</syntaxhighlight>


===Detailed ACTIONs for each ROLE (TEACHER, NON-EDITING TEACHER and STUDENT)===
===Detailed ACTIONs for each ROLE (TEACHER, NON-EDITING TEACHER and STUDENT)===
<code sql>
<syntaxhighlight lang="SQL">
SELECT r.name, l.action, COUNT( l.userid ) AS counter
SELECT r.name, l.action, COUNT( l.userid ) AS counter
FROM prefix_log AS l
FROM prefix_log AS l
Line 26: Line 28:
WHERE ra.roleid IN ( 3, 4, 5 )  
WHERE ra.roleid IN ( 3, 4, 5 )  
GROUP BY roleid, l.action
GROUP BY roleid, l.action
</code>
</syntaxhighlight>


===Student (user) COUNT in each Course===
===Student (user) COUNT in each Course===
Including (optional) filter by: year (if included in course fullname).
Including (optional) filter by: year (if included in course fullname).
<code sql>
<syntaxhighlight lang="SQL">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',course.id,'">',course.fullname,'</a>') AS Course
SELECT CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',course.id,'">',course.fullname,'</a>') AS Course
,concat('<a target="_new" href="%%WWWROOT%%/user/index.php?contextid=',context.id,'">Show users</a>') AS Users
,CONCAT('<a target="_new" href="%%WWWROOT%%/user/index.php?contextid=',context.id,'">Show users</a>') AS Users
, COUNT(course.id) AS Students
, COUNT(course.id) AS Students
FROM prefix_role_assignments AS asg
FROM prefix_role_assignments AS asg
Line 42: Line 44:
GROUP BY course.id
GROUP BY course.id
ORDER BY COUNT(course.id) DESC
ORDER BY COUNT(course.id) DESC
</code>
</syntaxhighlight>


=== Enrolment count in each Course ===
=== Enrolment count in each Course ===
Line 48: Line 50:
Shows the total number of enroled users of all roles in each course. Sorted by course name.
Shows the total number of enroled users of all roles in each course. Sorted by course name.


<code sql>
<syntaxhighlight lang="SQL">
SELECT c.fullname, COUNT(ue.id) AS Enroled
SELECT c.fullname, COUNT(ue.id) AS Enroled
FROM prefix_course AS c  
FROM prefix_course AS c  
Line 55: Line 57:
GROUP BY c.id
GROUP BY c.id
ORDER BY c.fullname
ORDER BY c.fullname
</code>
</syntaxhighlight>


===LIST of all site USERS by COURSE enrollment (Moodle 2.x)===
===LIST of all site USERS by COURSE enrollment (Moodle 2.x)===


<code sql>
<syntaxhighlight lang="SQL">
SELECT
SELECT
user2.firstname AS Firstname,
user2.firstname AS Firstname,
Line 73: Line 75:
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
JOIN prefix_user AS user2 ON ue.userid = user2.id
JOIN prefix_user AS user2 ON ue.userid = user2.id
</code>
</syntaxhighlight>


===Enrolled users,which did not login into the Course, even once (Moodle 2)===
===Enrolled users,which did not login into the Course, even once (Moodle 2)===
Designed forMoodle 2 table structure and uses special plugin filter : %%FILTER_SEARCHTEXT:table.field%%
Designed forMoodle 2 table structure and uses special plugin filter : %%FILTER_SEARCHTEXT:table.field%%


<code sql>
<syntaxhighlight lang="SQL">
SELECT
SELECT
user2.id as ID,
user2.id as ID,
Line 108: Line 110:
WHERE c.id=16 AND ul.timeaccess IS NULL
WHERE c.id=16 AND ul.timeaccess IS NULL
%%FILTER_SEARCHTEXT:user2.firstname%%
%%FILTER_SEARCHTEXT:user2.firstname%%
</code>
</syntaxhighlight>
 
===Enrolled users who have never accessed a given course (simpler version)===
 
<syntaxhighlight lang="SQL">
SELECT username, firstname, lastname, idnumber
FROM prefix_user_enrolments ue
JOIN prefix_enrol en ON ue.enrolid = en.id
JOIN prefix_user uu ON uu.id = ue.userid
WHERE en.courseid = 123456
AND NOT EXISTS (
    SELECT * FROM prefix_user_lastaccess la
    WHERE la.userid = ue.userid
    AND la.courseid = en.courseid
)
</syntaxhighlight>
 
(Replace 123456 near the middle with your courseid)


===Role assignments on categories===
===Role assignments on categories===
<code sql>
<syntaxhighlight lang="SQL">
SELECT  
SELECT  
concat('<a target="_new" href="%%WWWROOT%%/course/category.php?id=',cc.id,'">',cc.id,'</a>') AS id,
concat('<a target="_new" href="%%WWWROOT%%/course/category.php?id=',cc.id,'">',cc.id,'</a>') AS id,
Line 125: Line 144:
INNER JOIN prefix_user usr ON ra.userid = usr.id
INNER JOIN prefix_user usr ON ra.userid = usr.id
ORDER BY cc.depth, cc.path, usr.lastname, usr.firstname, r.name, cc.name
ORDER BY cc.depth, cc.path, usr.lastname, usr.firstname, r.name, cc.name
</code>
</syntaxhighlight>


===Permissions Overides on Categories===
===Permissions Overides on Categories===
(By: [http://moodle.org/mod/forum/discuss.php?d=153059#p712834 Séverin Terrier] )
(By: [http://moodle.org/mod/forum/discuss.php?d=153059#p712834 Séverin Terrier] )
<code sql>
<syntaxhighlight lang="SQL">
SELECT rc.id, ct.instanceid, ccat.name, rc.roleid, rc.capability, rc.permission,  
SELECT rc.id, ct.instanceid, ccat.name, rc.roleid, rc.capability, rc.permission,  
DATE_FORMAT( FROM_UNIXTIME( rc.timemodified ) , '%Y-%m-%d' ) AS timemodified, rc.modifierid, ct.instanceid, ct.path, ct.depth
DATE_FORMAT( FROM_UNIXTIME( rc.timemodified ) , '%Y-%m-%d' ) AS timemodified, rc.modifierid, ct.instanceid, ct.path, ct.depth
Line 136: Line 155:
INNER JOIN `prefix_course_categories` AS ccat ON ccat.id = ct.instanceid
INNER JOIN `prefix_course_categories` AS ccat ON ccat.id = ct.instanceid
AND `contextlevel` =40
AND `contextlevel` =40
</code>
</syntaxhighlight>


===Lists "Totally Opened Courses" (visible, opened to guests, with no password)===
===Lists "Totally Opened Courses" (visible, opened to guests, with no password)===
(By: [http://moodle.org/mod/forum/discuss.php?d=153059#p712837 Séverin Terrier] )
(By: [http://moodle.org/mod/forum/discuss.php?d=153059#p712837 Séverin Terrier] )
<code sql>
<syntaxhighlight lang="SQL">
SELECT
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS id,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS id,
Line 148: Line 167:
FROM prefix_enrol AS e, prefix_course AS c
FROM prefix_enrol AS e, prefix_course AS c
WHERE e.enrol='guest' AND e.status=0 AND e.password='' AND c.id=e.courseid AND c.visible=1
WHERE e.enrol='guest' AND e.status=0 AND e.password='' AND c.id=e.courseid AND c.visible=1
</code>
</syntaxhighlight>


===Lists "loggedin users" from the last 120 days===
===Lists "loggedin users" from the last 120 days===
<code sql>
<syntaxhighlight lang="SQL">
SELECT id,username,FROM_UNIXTIME(`lastlogin`) as days  
SELECT id,username,FROM_UNIXTIME(`lastlogin`) as days  
FROM `prefix_user`  
FROM `prefix_user`  
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120
</code>
</syntaxhighlight>


''and user count for that same population:''
''and user count for that same population:''
<code sql>
<syntaxhighlight lang="SQL">
SELECT COUNT(id) as Users  FROM `prefix_user`  
SELECT COUNT(id) as Users  FROM `prefix_user`  
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120
</code>
</syntaxhighlight>
 
==== Users loggedin within the last 7 days ====
<syntaxhighlight lang="SQL">
SELECT
    l.* FROM mdl_logstore_standard_log l
WHERE
  l.eventname = '\\core\\event\\user_loggedin'
  AND FROM_UNIXTIME(l.timecreated, '%Y-%m-%d') >= DATE_SUB(NOW(), INTERVAL 7 DAY)
 
SELECT l.eventname FROM mdl_logstore_standard_log l
GROUP BY l.eventname
</syntaxhighlight>


===Lists the users who have only logged into the site once===
===Lists the users who have only logged into the site once===
<code sql>
<syntaxhighlight lang="SQL">
SELECT id, username, firstname, lastname, idnumber
SELECT id, username, firstname, lastname, idnumber
FROM prefix_user
FROM prefix_user
Line 170: Line 201:
AND prefix_user.lastlogin = 0  
AND prefix_user.lastlogin = 0  
AND prefix_user.lastaccess > 0
AND prefix_user.lastaccess > 0
</code>
</syntaxhighlight>


===Students in all courses of some institute===
===Students in all courses of some institute===
What is the status (deleted or not) of all Students (roleid = 5) in all courses of some Institute
What is the status (deleted or not) of all Students (roleid = 5) in all courses of some Institute
<code sql>
<syntaxhighlight lang="SQL">
SELECT c.id, c.fullname, u.firstname, u.lastname, u.deleted
SELECT c.id, c.fullname, u.firstname, u.lastname, u.deleted
FROM prefix_course AS c
FROM prefix_course AS c
Line 183: Line 214:
AND ctx.instanceid = c.id
AND ctx.instanceid = c.id
AND u.institution = 'please enter school name here'
AND u.institution = 'please enter school name here'
</code>
</syntaxhighlight>


===Full User info (for deleted users)===
===Full User info (for deleted users)===
Including extra custom profile fields (from prefix_user_info_data)
Including extra custom profile fields (from prefix_user_info_data)
<code sql>
<syntaxhighlight lang="SQL">
SELECT *  
SELECT *  
FROM prefix_user as u  
FROM prefix_user as u  
Line 193: Line 224:
JOIN prefix_user_info_field as uif ON (uid.fieldid = uif.id AND uif.shortname = 'class')
JOIN prefix_user_info_field as uif ON (uid.fieldid = uif.id AND uif.shortname = 'class')
WHERE `deleted` = "1" and `institution`="your school name" and `department` = "your department" and `data` = "class level and number"
WHERE `deleted` = "1" and `institution`="your school name" and `department` = "your department" and `data` = "class level and number"
</code>
</syntaxhighlight>


===User's courses===
===User's courses===
change "u.id = 2" with a new user id
change "u.id = 2" with a new user id
<code sql>
<syntaxhighlight lang="SQL">
SELECT u.firstname, u.lastname, c.id, c.fullname
SELECT u.firstname, u.lastname, c.id, c.fullname
FROM prefix_course AS c
FROM prefix_course AS c
Line 204: Line 235:
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_user AS u ON u.id = ra.userid
WHERE u.id = 2
WHERE u.id = 2
</code>
</syntaxhighlight>


===List Users with extra info (email) in current course===
===List Users with extra info (email) in current course===
blocks/configurable_reports replaces %%COURSEID%% with course id.
blocks/configurable_reports replaces %%COURSEID%% with course id.
<code sql>
<syntaxhighlight lang="SQL">
SELECT u.firstname, u.lastname, u.email
SELECT u.firstname, u.lastname, u.email
FROM prefix_role_assignments AS ra
FROM prefix_role_assignments AS ra
Line 214: Line 245:
JOIN prefix_course AS c ON c.id = context.instanceid AND c.id = %%COURSEID%%
JOIN prefix_course AS c ON c.id = context.instanceid AND c.id = %%COURSEID%%
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_user AS u ON u.id = ra.userid
</code>
</syntaxhighlight>
 
===List Students with enrollment and completion dates in current course===
This is meant to be a "global" report in Configurable Reports containing the following:
firstname, lastname, idnumber, institution, department, email, student enrolment date, student completion date
Note: for PGSQL, use to_timestamp() instead of FROM_UNIXTIME()
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
u.firstname
, u.lastname
, u.idnumber
, u.institution
, u.department
, u.email
, FROM_UNIXTIME(cc.timeenrolled)
, FROM_UNIXTIME(cc.timecompleted)
 
FROM prefix_role_assignments AS ra
JOIN prefix_context AS context ON context.id = ra.contextid AND context.contextlevel = 50
JOIN prefix_course AS c ON c.id = context.instanceid AND c.id = %%COURSEID%%
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_course_completions AS cc ON cc.course = c.id AND cc.userid = u.id
</syntaxhighlight>


===Special Roles===
===Special Roles===
<code sql>
<syntaxhighlight lang="SQL">
SELECT ra.roleid,r.name
SELECT ra.roleid,r.name
,concat('<a target="_new" href="%%WWWROOT%%/course/user.php?id=1&user=',ra.userid,'">',u.firstname ,' ',u.lastname,'</a>') AS Username
,concat('<a target="_new" href="%%WWWROOT%%/course/user.php?id=1&user=',ra.userid,'">',u.firstname ,' ',u.lastname,'</a>') AS Username
Line 227: Line 282:
JOIN prefix_course AS c ON ctx.instanceid = c.id
JOIN prefix_course AS c ON ctx.instanceid = c.id
WHERE ra.roleid > 6
WHERE ra.roleid > 6
</code>
</syntaxhighlight>


===Courses without Teachers===
===Courses without Teachers===
Actually, shows the number of Teachers in a course.
Actually, shows the number of Teachers in a course.
<code sql>
<syntaxhighlight lang="SQL">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
Line 238: Line 293:
FROM prefix_course AS c
FROM prefix_course AS c
ORDER BY Teachers ASC
ORDER BY Teachers ASC
</code>
</syntaxhighlight>


===List of users who have been enrolled for more than 4 weeks===
===List of users who have been enrolled for more than 4 weeks===
For Moodle 2.2 , by  Isuru Madushanka Weerarathna  
For Moodle 2.2 , by  Isuru Madushanka Weerarathna  
<code sql>
<syntaxhighlight lang="SQL">
SELECT uenr.userid As User, IF(enr.courseid=uenr.courseid ,'Y','N') As Enrolled,  
SELECT uenr.userid As User, IF(enr.courseid=uenr.courseid ,'Y','N') As Enrolled,  
IF(DATEDIFF(NOW(), FROM_UNIXTIME(uenr.timecreated))>=28,'Y','N') As EnrolledMoreThan4Weeks
IF(DATEDIFF(NOW(), FROM_UNIXTIME(uenr.timecreated))>=28,'Y','N') As EnrolledMoreThan4Weeks
FROM prefix_enrol As enr, prefix_user_enrolments AS uenr
FROM prefix_enrol As enr, prefix_user_enrolments AS uenr
WHERE enr.id = uenr.enrolid AND enr.status = uenr.status
WHERE enr.id = uenr.enrolid AND enr.status = uenr.status
</code>
</syntaxhighlight>


=== List of users with language===
=== List of users with language===


An issue with systems that do not have their default language set up properly is the need to do a mass change for all users to a localization. A common case is changing default English to American English.  
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
An issue with systems that do not have their default language set up properly is the need to do a mass change for all users to a localization. A common case (in the U.S., Canada and the Americas) is changing the default English to United States English.  


This will show you the language setting for all users:
This will show you the language setting for all users:
<code sql>
<syntaxhighlight lang="SQL">
SELECT username, lang from prefix_user  
SELECT username, lang from prefix_user  
</code>
</syntaxhighlight>
 
NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools.


This code will change the setting from 'en' to 'en_us' for all users:
This code will change the setting from 'en' to 'en_us' for all users:


<code sql>
<syntaxhighlight lang="SQL">
UPDATE prefix_user SET lang = 'en_us' WHERE lang = 'en'
UPDATE prefix_user SET lang = 'en_us' WHERE lang = 'en'
</code>
</syntaxhighlight>
 
To do this for only users who have a particular country set, use this as an example:
<syntaxhighlight lang="SQL">
UPDATE prefix_user SET lang = 'en_us' WHERE country = 'US' AND lang = 'en'
</syntaxhighlight>


=== List of users with Authentication ===
=== List of users with Authentication ===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


Sometimes you need to do mass changes of authentication methods. A common case is changing default manual to LDAP.  
Sometimes you need to do mass changes of authentication methods. A common case is changing default manual to LDAP.  


This will show you the Authentication setting for all users:
This will show you the Authentication setting for all users:
<code sql>
<syntaxhighlight lang="SQL">
SELECT username, auth from prefix_user  
SELECT username, auth from prefix_user  
</code>
</syntaxhighlight>
 
NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools.


This code will change the setting from 'manual' to 'ldap' for all users except for the first two accounts which are Guest and Admin. (WARNING: it is bad practice to change you admin account from manual to an external method as failure of that external method will lock you out of Moodle as admin.)
This code will change the setting from 'manual' to 'ldap' for all users except for the first two accounts which are Guest and Admin. (WARNING: it is bad practice to change your admin account from manual to an external method as failure of that external method will lock you out of Moodle as admin.)


<code sql>
<syntaxhighlight lang="SQL">
UPDATE prefix_user SET auth = 'ldap' WHERE auth = 'manual' AND id > 2
UPDATE prefix_user SET auth = 'ldap' WHERE auth = 'manual' AND id > 2
</code>
</syntaxhighlight>


=== Compare role capability and permissions ===
=== Compare role capability and permissions ===
<code sql>
Compatibility: MySQL and PostgreSQL
 
<syntaxhighlight lang="SQL">
SELECT DISTINCT mrc.capability  
SELECT DISTINCT mrc.capability  
,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability  
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '1' AND rc.contextid = '1') AS Manager
  AND rc.roleid = '1' AND rc.contextid = '1') AS Manager
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '2' AND rc.contextid = '1') AS Course_Creator
,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability  
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '3' AND rc.contextid = '1') AS Teacher
  AND rc.roleid = '2' AND rc.contextid = '1') AS CourseCreator
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '4' AND rc.contextid = '1') AS Assistant_Teacher
,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability  
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '5' AND rc.contextid = '1') AS Student
  AND rc.roleid = '3' AND rc.contextid = '1') AS Teacher
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '6' AND rc.contextid = '1') AS Guest
,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability  
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '7' AND rc.contextid = '1') AS Authenticated
  AND rc.roleid = '4' AND rc.contextid = '1') AS AssistantTeacher
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '8' AND rc.contextid = '1') AS Auth_front
,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability  
FROM prefix_role_capabilities AS mrc
  AND rc.roleid = '5' AND rc.contextid = '1') AS Student
</syntaxhighlight>
,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability  
 
  AND rc.roleid = '6' AND rc.contextid = '1') AS Guest
=== User's accumulative time spent in course ===
A sum up of the time delta between logstore_standard_log user's records, considering the a 2 hour session limit.
 
Uses: current user's id %%USERID%% and current course's id %%COURSEID%% 


FROM `mdl_role_capabilities` AS mrc
And also using a date filter (which can be ignored) 
</code>


=== User's accumulative time spent in course ===
Sum up of the time delta between logstore_standard_log user's records, considering the a 2 hour session limit.
Uses: current user's id and current course's id
And also using a date filter (which can be ignored)
The extra "User" field is used as a dummy field for the Line chart Series field, in which I use X=id, Series=Type, Y=delta.
The extra "User" field is used as a dummy field for the Line chart Series field, in which I use X=id, Series=Type, Y=delta.
<code sql>
 
<syntaxhighlight lang="SQL">
SELECT  
SELECT  
l.id,  
l.id,  
Line 319: Line 388:
WHERE l.userid = %%USERID%% AND l.courseid = %%COURSEID%%
WHERE l.userid = %%USERID%% AND l.courseid = %%COURSEID%%
%%FILTER_STARTTIME:l.timecreated:>%% %%FILTER_ENDTIME:l.timecreated:<%%  
%%FILTER_STARTTIME:l.timecreated:>%% %%FILTER_ENDTIME:l.timecreated:<%%  
</code>
</syntaxhighlight>
 
=== Low-Participation Student Report ===
Contributed by Elizabeth Dalton, Granite State College / Moodle HQ
 
This report returns a list of students who are enrolled in courses filtered by a short-name text marker (in this case "OL-") in the specified category, but have very low participation in the course during the specified time period (fewer than 2 "Edits" to Activity Modules, indicating few active contributions to the course). The number of "Edits" is provided for each student for the time period specified.
 
An "Edit" is defined as course activity other than viewing content. Click the "Logs" link to review the student activity. The Logs offer the option to review "View" activity as well as "Edit" activity.
 
Only "visible" courses are included in this report. The report may be downloaded as an Excel spreadsheet.


==Log Activity Reports==
Don't forget to set up Filters: "Start / End date filter" and "Filter categories" on the Filters tab in Configurable reports.
===Count all Active Users by ROLE in a course category (including all of its sub-categories)===
 
<code sql>
<syntaxhighlight lang="SQL">
SELECT COUNT(DISTINCT l.userid) as active
SELECT u.lastname AS Last, u.firstname AS First, u.idnumber AS IDnumber, u.email AS email, c.shortname AS CourseID,  count(l.id) AS Edits, CONCAT('<a target="_new" href="https://learn.granite.edu/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=-view&logformat=showashtml','">','Logs','</a>') AS Link
FROM mdl_course as c
 
JOIN mdl_context AS ctx ON ctx.instanceid=c.id
FROM prefix_user AS u
JOIN mdl_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN mdl_user_lastaccess as l ON ra.userid = l.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN mdl_course_categories AS cats ON c.category = cats.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
WHERE c.category=cats.id AND (
 
cats.path LIKE '%/80/%'
LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id AND l.action NOT LIKE "view%" %%FILTER_STARTTIME:l.TIME:>%% %%FILTER_ENDTIME:l.TIME:<%%
OR cats.path LIKE '%/80'
 
)
WHERE ra.roleid =5
AND ra.roleid=AND ctx.contextlevel=50  #ra.roleid= TEACHER 3, NON-EDITING TEACHER 4, STUDENT 5
AND ctx.instanceid = c.id
AND l.timeaccess > (unix_timestamp() - ((60*60*24)*NO_OF_DAYS)) #NO_OF_DAYS change to number
AND c.visible=1
</code>
# This prefix filter allows the exclusion of non-online courses at the original institution. Alter this to fit your institution, or remove it.
===Detailed "VIEW" ACTION for each ROLE (TEACHER,NONE-EDITING TEACHER and STUDENT)===
AND c.shortname LIKE '%OL-%'
<code sql>
%%FILTER_CATEGORIES:c.category%%
SELECT l.action, count( l.userid ) as counter , r.name
FROM `prefix_log` as l
JOIN `prefix_role_assignments` AS ra on l.userid = ra.userid
JOIN `prefix_role` AS r ON ra.roleid = r.id
WHERE (ra.roleid IN (3,4,5)) AND (l.action LIKE '%view%' )
GROUP BY roleid,l.action
order by r.name,counter desc
</code>


===Total Activity of Roles:"Teacher" and "None-Editing Teacher" by Dates and by Hours===
GROUP BY u.idnumber
The output columns of this report table can be used as base for a Pivot-Table
which will show the amount of '''activity''' per '''hour''' per '''days''' in 3D graph view.


<code sql>
HAVING Edits < 2
SELECT DATE_FORMAT( FROM_UNIXTIME( l.time ) , '%Y-%m-%d' ) AS grptimed ,
</syntaxhighlight>
DATE_FORMAT( FROM_UNIXTIME( l.time ) , '%k' ) AS grptimeh  , count( l.userid ) AS counter
FROM `prefix_log` AS l
JOIN prefix_user AS u ON u.id = l.userid
JOIN prefix_role_assignments AS ra ON l.userid = ra.userid
JOIN prefix_role AS r ON r.id = ra.roleid
WHERE ra.roleid IN (3,4)
GROUP BY grptimed,grptimeh
ORDER BY grptimed,grptimeh
</code>


===How many LOGINs per user and user's Activity===
=== Messages of All Users ===
+ link username to a user activity graph report
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/user.php?id=1&user=',u.id,'&mode=alllogs">',u.firstname ,' ',u.lastname,'</a>') as Username
,count(*) as logins
,(SELECT count(*) FROM prefix_log WHERE userid = l.userid GROUP BY userid) as Activity
FROM prefix_log as l JOIN prefix_user as u ON l.userid = u.id
WHERE `action` LIKE '%login%' group by userid
ORDER BY Activity DESC
</code>


===Total activity per course, per unique user on the last 24h===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]. Updated for Moodle 3.6 and above.
<code sql>
Select
    Count(Distinct userid) As countUsers
  , Count(course) As countVisits
  , concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course


From prefix_log as l
This is a version of this query that has been tested with Moodle 3.10 back to Moodle 3.6 (thank you [https://moodle.org/user/view.php?id=2247767&course=11 Sandy Noe] for testing!)
JOIN prefix_course as c on c.id = l.course
Where course > 0 and FROM_UNIXTIME(time) >= DATE_SUB(NOW(), INTERVAL 1 DAY) and c.fullname LIKE '%תשעג%'
Group By course
ORDER BY countVisits DESC
</code>


===Weekly Instructor Online Participation===
<syntaxhighlight lang="SQL">
Contributed by Elizabeth Dalton, Granite State College
SELECT
cv.id AS "Conversation_id",
DATE_FORMAT(FROM_UNIXTIME(me.timecreated), '%Y-%m-%d %H:%i') AS "At",
(SELECT CONCAT(firstname,' ',lastname,' (',username,')') FROM prefix_user WHERE id = me.useridfrom) AS 'From',


Displays participation of instructors in all courses per week of a term, including pre-term and post-term edits. An edit is defined as a change to the course, such as a discussion post, the grading of an assignment, or the uploading of file attachments, as well as alterations to course content.
(SELECT
GROUP_CONCAT(DISTINCT CONCAT(u.firstname ,' ',lastname,' (',username,')'))
FROM prefix_user u
JOIN prefix_message_conversation_members cvm ON cvm.userid = u.id
WHERE cvm.conversationid = cv.id
AND u.id != me.useridfrom
GROUP BY cvm.conversationid
) AS "To",
IF(me.subject IS NULL, "(reply)", me.subject) AS "Subject",
me.fullmessage AS "Message"


* To specify a subject and/or course number, use % as a wildcard, e.g. ARTS% or ARTS501%
FROM prefix_messages me
* To match part of a last name, use %, e.g. Smi% will match "Smith", "Smile", etc.
JOIN prefix_message_conversations cv ON cv.id = me.conversationid


At our institution, we include filters on the course name or category to constrain by terms. These are very specific to how course names and categories are constructed at our institution, so I've removed those elements from this code. Also, our terms are 12 weeks long. You would want to insert additional "SUM" lines for longer terms, or remove lines for shorter terms.
ORDER BY cv.id, me.timecreated


'''Note''': This report can take a long time to run. While it can be run in Configurable Reports on demand, it may be more appropriate to implement it in the Ad Hoc Queries plugin as a scheduled report.
</syntaxhighlight>


'''Note''': This version uses legacy (pre-2.7) logs. See below for post-2.7 Standard Logs version.
NOTE: This query will return a lot of data, probably too much. In that case, you will probably need to add a WHERE clause or other method to this query to limit or restrict it, for example by date range or usernames, etc. See [https://moodle.org/user/view.php?id=2247767&course=11 this post for an example of date range].  


<code sql>
(If you need the earlier version of this query, for Moodle 3.4 or earlier (please upgrade!), then take a look at the earlier versions of this page for your particular version of Moodle. - RT)
SELECT
c.shortname AS CourseID
, cc.name AS Category
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor


, (SELECT COUNT( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
=== Unread Moodle Messages ===
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
This report will show a list of unread Moodle messages with a direct link to view messages from applicable users.
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students
Contributed by: [https://moodle.org/user/profile.php?id=2682159 Ben Haensel].
This is a version of this query that has been tested with Moodle 3.9


, c.startdate AS Course_Start_Date
<syntaxhighlight lang="SQL">


, c.visible AS Visible
SELECT u.id userid,
concat('<a target="_blank" href="%%WWWROOT%%/message/index.php?id=',u.id,'">',u.lastname, ', ', u.firstname,'</a>') User
from prefix_messages m
join prefix_message_conversations mc ON mc.id = m.conversationid
join prefix_message_conversation_members mcm ON m.conversationid = mcm.conversationid
left join prefix_message_user_actions mua ON mua.messageid = m.id AND mua.userid = %%USERID%%
left join prefix_message_conversation_members mcx on mcx.conversationid = mcm.conversationid
and mcx.userid <> mcm.userid
left join prefix_user u on u.id = mcx.userid
where mcm.userid = %%USERID%%
and m.useridfrom <> %%USERID%%
and mua.id is NULL
order by u.lastname, u.firstname


,  COUNT(l.id) AS Edits
</syntaxhighlight>


, SUM(IF(WEEK(FROM_UNIXTIME(l.time)) - WEEK(FROM_UNIXTIME(c.startdate))<0,1,0)) AS BeforeTerm
===List of attendees/students that were marked present across courses===
This report will pull all Present students across a specific category.
Contributed by: Emma Richardson


, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=0,1,0)) AS Week1
<syntaxhighlight lang="SQL">
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=1,1,0)) AS Week2
SELECT u.firstname AS "First Name", u.lastname AS "Last Name", u.Institution AS "District",c.fullname AS "Training", DATE_FORMAT(FROM_UNIXTIME(att.sessdate),'%d %M %Y')AS Date
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=2,1,0)) AS Week3
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=3,1,0)) AS Week4
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=4,1,0)) AS Week5
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=5,1,0)) AS Week6
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=6,1,0)) AS Week7
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=7,1,0)) AS Week8
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=8,1,0)) AS Week9
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=9,1,0)) AS Week10
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=10,1,0)) AS Week11
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=11,1,0)) AS Week12


, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))>=12,1,0)) AS AfterTerm
FROM prefix_attendance_sessions AS att
JOIN prefix_attendance_log AS attlog ON att.id = attlog.sessionid
JOIN prefix_attendance_statuses AS attst ON attlog.statusid = attst.id
JOIN prefix_attendance AS a ON att.attendanceid = a.id
JOIN prefix_course AS c ON a.course = c.id
JOIN prefix_user AS u ON attlog.studentid = u.id


, CONCAT('<a target="_new" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS Link
WHERE attst.acronym = "P"
 
AND c.category = INSERT YOUR CATEGORY ID HERE
FROM prefix_user AS u
ORDER BY c.fullname
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
</syntaxhighlight>
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id
 
LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id  AND l.action NOT LIKE "view%"


WHERE ra.roleid =3
===List of deactivated users in a course===
AND ctx.instanceid = c.id
List of deactivated users in a specific course
AND c.shortname LIKE :course
AND u.lastname LIKE :last_name


GROUP BY u.idnumber, c.id
<syntaxhighlight lang="SQL">
HAVING students > 0
SELECT username, idnumber,
ORDER BY c.shortname
concat('<a target="_new" href="%%WWWROOT%%/user/profile.php?id=',uu.id,'">',uu.id,'</a>') as userid_and_link,
</code>
firstname, lastname, email, suspended as 'suspended/deactivated: 1'
FROM prefix_user_enrolments ue
JOIN prefix_enrol en ON ue.enrolid = en.id
JOIN prefix_user uu ON uu.id = ue.userid
WHERE en.courseid = 1234567
AND suspended = 1
</syntaxhighlight>


'''Note''': Post-2.7 log version:
===List of users and their private files===
List all users who use private files and list all files in their private repository
<syntaxhighlight lang="SQL">
Select u.firstname, u.lastname, u.username,
concat('<a target="_new" href="%%WWWROOT%%/user/view.php?id=',u.id,'">',u.id,'</a>') as 'ID and Link to User Profilel',
DATE_FORMAT(FROM_UNIXTIME(u.lastlogin), '%e %b %Y') AS 'lastlogin', u.suspended AS 'activated (0) or deactivated (1) User', f.filename, f.filesize
from prefix_files AS f
JOIN prefix_user AS u ON u.id = f.userid
where filearea = "private"
AND f.filename != "."
</syntaxhighlight>


<code sql>
SELECT
c.shortname AS CourseID
, cc.name AS Category
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor


, (SELECT COUNT( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students


, FROM_UNIXTIME(c.startdate) AS Course_Start_Date
===List of all private files of users as alias/shortcut to any activity/course===
Lists all files of users that have been linked as "alias/shortcut" to any activity/course


, c.visible AS Visible
<syntaxhighlight lang="SQL">
select f.contextid, f.component, f.filearea, f.filename,
concat('<a target="_new" href="%%WWWROOT%%/user/view.php?id=',f.userid,'">',f.userid,'</a>') as 'ID and Link to Userprofile',
u.firstname, u.lastname,
f.filesize, f.mimetype, f.source, f.author, f.referencefileid,
c.instanceid as 'ID from prefix_context',
cm.id as 'ID from prefix_course_modules',
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',cm.course,'</a>') as kursid_and_link,
co.fullname,
co.shortname
from prefix_files as f
JOIN prefix_context AS c ON c.id = f.contextid
JOIN prefix_course_modules as cm ON cm.id = c.instanceid
JOIN prefix_user as u ON u.id = f.userid
JOIN prefix_course as co ON co.id = cm.course
where referencefileid IS NOT NULL
</syntaxhighlight>


,  COUNT(DISTINCT l.id) AS Edits


, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'


, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
==Log Activity Reports==
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
===Count all Active Users by ROLE in a course category (including all of its sub-categories)===
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
<syntaxhighlight lang="SQL">
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
SELECT COUNT(DISTINCT l.userid) as active
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
FROM mdl_course as c
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
JOIN mdl_context AS ctx ON  ctx.instanceid=c.id
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
JOIN mdl_role_assignments AS ra ON ra.contextid = ctx.id
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=7,l.id,NULL)) AS 'Week 8'
JOIN mdl_user_lastaccess as l ON ra.userid = l.userid
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=8,l.id,NULL)) AS 'Week 9'
JOIN mdl_course_categories AS cats ON c.category = cats.id
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=9,l.id,NULL)) AS 'Week 10'
WHERE c.category=cats.id AND (
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=10,l.id,NULL)) AS 'Week 11'
cats.path LIKE '%/80/%'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=11,l.id,NULL)) AS 'Week 12'
OR cats.path LIKE '%/80'
)  
AND ra.roleid=3  AND ctx.contextlevel=50  #ra.roleid= TEACHER 3, NON-EDITING TEACHER 4, STUDENT 5
AND  l.timeaccess > (unix_timestamp() - ((60*60*24)*NO_OF_DAYS)) #NO_OF_DAYS change to number
</syntaxhighlight>
===Detailed "VIEW" ACTION for each ROLE (TEACHER,NONE-EDITING TEACHER and STUDENT)===
<syntaxhighlight lang="SQL">
SELECT l.action, count( l.userid ) as counter , r.name
FROM `prefix_log` as l
JOIN `prefix_role_assignments` AS ra on l.userid = ra.userid
JOIN `prefix_role` AS r ON ra.roleid = r.id
WHERE (ra.roleid IN (3,4,5)) AND (l.action LIKE '%view%' )
GROUP BY roleid,l.action
order by r.name,counter desc
</syntaxhighlight>


, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'
===Total Activity of Roles:"Teacher" and "None-Editing Teacher" by Dates and by Hours===
The output columns of this report table can be used as base for a Pivot-Table
which will show the amount of '''activity''' per '''hour''' per '''days''' in 3D graph view.


, CONCAT('<a target="_new" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS Link
<syntaxhighlight lang="SQL">
SELECT DATE_FORMAT( FROM_UNIXTIME( l.time ) , '%Y-%m-%d' ) AS grptimed ,
DATE_FORMAT( FROM_UNIXTIME( l.time ) , '%k' ) AS grptimeh  , count( l.userid ) AS counter
FROM `prefix_log` AS l
JOIN prefix_user AS u ON u.id = l.userid
JOIN prefix_role_assignments AS ra ON l.userid = ra.userid
JOIN prefix_role AS r ON r.id = ra.roleid
WHERE ra.roleid IN (3,4)
GROUP BY grptimed,grptimeh
ORDER BY grptimed,grptimeh
</syntaxhighlight>


FROM prefix_user AS u
===How many LOGINs per user and user's Activity===
LEFT JOIN prefix_role_assignments AS ra ON u.id = ra.userid
+ link username to a user activity graph report
LEFT JOIN prefix_context AS ctx ON ra.contextid = ctx.id
<syntaxhighlight lang="SQL">
LEFT JOIN prefix_course AS c ON c.id = ctx.instanceid
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/user.php?id=1&user=',u.id,'&mode=alllogs">',u.firstname ,' ',u.lastname,'</a>') as Username
LEFT JOIN prefix_course_categories as cc ON c.category = cc.id
,count(*) as logins
,(SELECT count(*) FROM prefix_log WHERE userid = l.userid GROUP BY userid) as Activity
FROM prefix_log as l JOIN prefix_user as u ON l.userid = u.id  
WHERE `action` LIKE '%login%' group by userid
ORDER BY Activity DESC
</syntaxhighlight>
===Distinct user logins per month===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
The following will show you the months of the current calendar year with the total number of distinct, unique user logins per month. Change the year in the WHERE clause to the year you need.


LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id  AND l.crud IN ('c','u')
<syntaxhighlight lang="SQL">
SELECT
COUNT(DISTINCT l.userid) AS 'DistinctUserLogins',
DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%M') AS 'Month'
FROM prefix_logstore_standard_log l
WHERE l.action = 'loggedin' AND YEAR(FROM_UNIXTIME(l.timecreated)) = '2017'  
GROUP BY MONTH(FROM_UNIXTIME(l.timecreated))
</syntaxhighlight>


WHERE ra.roleid =3
===Total activity per course, per unique user on the last 24h===
AND ctx.instanceid = c.id
<syntaxhighlight lang="SQL">
AND c.shortname LIKE '%OL-%'
SELECT
AND cc.idnumber LIKE '%current%'
    COUNT(DISTINCT userid) AS countUsers
  , COUNT(l.courseid) AS countVisits
  , CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">', c.fullname, '</a>') AS Course


GROUP BY u.idnumber, c.id
FROM mdl_logstore_standard_log AS l
#HAVING students > 0
  JOIN mdl_course AS c ON c.id = l.courseid
ORDER BY RIGHT(c.shortname,2), c.shortname
WHERE l.courseid > 0
</code>
      AND FROM_UNIXTIME(l.timecreated) >= DATE_SUB(NOW(), INTERVAL 1 DAY)
      AND c.fullname LIKE '%תשעו%'
GROUP BY l.courseid
ORDER BY countVisits DESC
</syntaxhighlight>


===Weekly Student Online Participation===
===Weekly Instructor Online Participation===
Contributed by Elizabeth Dalton, Granite State College
Contributed by Elizabeth Dalton, Granite State College


Displays participation of students in the current course by week, including pre-term and post-term edits. An edit is defined as a change to the course, such as a discussion post, the submission of an assignment, or the completion of a quiz, as well as alterations to course content such as database entries (if permitted).
Displays participation of instructors in all courses per week of a term, including pre-term and post-term edits. An edit is defined as a change to the course, such as a discussion post, the grading of an assignment, or the uploading of file attachments, as well as alterations to course content.


Links to three other reports are also provided:
* To specify a subject and/or course number, use % as a wildcard, e.g. ARTS% or ARTS501%
* To match part of a last name, use %, e.g. Smi% will match "Smith", "Smile", etc.


* Logs: complete log entries for the student in the course, organized by date
At our institution, we include filters on the course name or category to constrain by terms. These are very specific to how course names and categories are constructed at our institution, so I've removed those elements from this code. Also, our terms are 12 weeks long. You would want to insert additional "SUM" lines for longer terms, or remove lines for shorter terms.
* Activity Outline: the "Outline Report" from the User Activity Reports, summarizing the student's activity in the course, organized by course content
* Consolidated Activity Report: the "Complete Report" from the User Activity Reports, detailing the student's activity in the course, organized by course content (includes text of forum posts)


'''Note''': This should be defined as a "Global" report (visible from within all courses). At our institution, our terms are 12 weeks long. You would want to insert additional "SUM" lines for longer terms, or remove lines for shorter terms. We pull advisor names into student user profiles as part of our configuration. These lines are present in the code below, but are commented out, as they are very specific to your Moodle configuration.
'''Note''': This report can take a long time to run. While it can be run in Configurable Reports on demand, it may be more appropriate to implement it in the Ad Hoc Queries plugin as a scheduled report.


'''Note''': This version of the report uses legacy (pre-2.7) logs. See below for a post-2.7 Standard Logs version.
'''Note''': This version uses legacy (pre-2.7) logs. See below for post-2.7 Standard Logs version.


<code sql>
<syntaxhighlight lang="SQL">
SELECT  
SELECT  
u.lastname AS 'Last Name'
c.shortname AS CourseID
, u.firstname AS 'First Name'
, cc.name AS Category
, COUNT(l.id) AS 'Edits'
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor


, SUM(IF((l.time-c.startdate)/7<0,1,0)) AS 'Before Term'
, (SELECT COUNT( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students


, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=0,1,0)) AS 'Week 1'
, c.startdate AS Course_Start_Date
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=1,1,0)) AS 'Week 2'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=2,1,0)) AS 'Week 3'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=3,1,0)) AS 'Week 4'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=4,1,0)) AS 'Week 5'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=5,1,0)) AS 'Week 6'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=6,1,0)) AS 'Week 7'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=7,1,0)) AS 'Week 8'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=8,1,0)) AS 'Week 9'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=9,1,0)) AS 'Week 10'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=10,1,0)) AS 'Week 11'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=11,1,0)) AS 'Week 12'


, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))>=15,1,0)) AS 'After Term'
, c.visible AS Visible


, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS 'Logs'
, COUNT(l.id) AS Edits


, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=outline">','Outline','</a>') AS 'Activity Outline'
, SUM(IF(WEEK(FROM_UNIXTIME(l.time)) - WEEK(FROM_UNIXTIME(c.startdate))<0,1,0)) AS BeforeTerm


, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=complete">','Activity','</a>') AS 'Consolidated Activity'
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=0,1,0)) AS Week1
 
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=1,1,0)) AS Week2
FROM prefix_user AS u
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=2,1,0)) AS Week3
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=3,1,0)) AS Week4
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=4,1,0)) AS Week5
JOIN prefix_course AS c ON c.id = ctx.instanceid
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=5,1,0)) AS Week6
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=6,1,0)) AS Week7
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=7,1,0)) AS Week8
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=8,1,0)) AS Week9
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=9,1,0)) AS Week10
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=10,1,0)) AS Week11
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=11,1,0)) AS Week12
 
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))>=12,1,0)) AS AfterTerm
 
, CONCAT('<a target="_new" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS Link
 
FROM prefix_user AS u
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id
JOIN prefix_course_categories as cc ON c.category = cc.id


LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id  AND l.action NOT LIKE "view%"
LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id  AND l.action NOT LIKE "view%"


WHERE ra.roleid =5
WHERE ra.roleid =3
AND ctx.instanceid = c.id
AND ctx.instanceid = c.id
AND c.shortname LIKE :course
AND u.lastname LIKE :last_name


AND c.id = %%COURSEID%%
GROUP BY u.idnumber, c.id
HAVING students > 0
ORDER BY c.shortname
</syntaxhighlight>


GROUP BY u.idnumber
'''Note''': Post-2.7 log version:


ORDER BY u.lastname, u.firstname
<syntaxhighlight lang="SQL">
</code>
SELECT
c.shortname AS CourseID
, cc.name AS Category
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor


'''Note''': Post-2.7 (Standard Logs) version
, (SELECT COUNT( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students


<code sql>
, FROM_UNIXTIME(c.startdate) AS Course_Start_Date
SELECT
u.lastname AS 'Last Name'
, u.firstname AS 'First Name'
, COUNT(l.id) AS 'Edits'


, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
, c.visible AS Visible
 
,  COUNT(DISTINCT l.id) AS Edits
 
, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'


, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
Line 598: Line 736:
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'


# Our institution stores academic advisor names and emails in custom profile fields
, CONCAT('<a target="_new" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS Link
#, CONCAT('<a href="mailto:',uce.data,'">',uid.data, '</a>')  AS 'Academic Advisor'
 
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS 'Logs'
 
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=outline">','Outline','</a>') AS 'Activity Outline'
 
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=complete">','Activity','</a>') AS 'Consolidated Activity'
 
, CONCAT('<a target="_blank" href="%%WWWROOT%%/mod/forum/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'">','Posts','</a>') AS 'Posts'


FROM prefix_user AS u
FROM prefix_user AS u
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
LEFT JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
LEFT JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
LEFT JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id
LEFT JOIN prefix_course_categories as cc ON c.category = cc.id
 
# student academic coach - you can include custom profile field data with these methods
# LEFT JOIN prefix_user_info_data as uid ON u.id = uid.userid AND uid.fieldid = '2'
# student academic coach email
# LEFT JOIN prefix_user_info_data as uce on u.id = uce.userid AND uce.fieldid = '6'


LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id  AND l.crud IN ('c','u')
LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id  AND l.crud IN ('c','u')


WHERE ra.roleid =5
WHERE ra.roleid =3
AND ctx.instanceid = c.id
AND ctx.instanceid = c.id
AND c.shortname LIKE '%OL-%'
AND cc.idnumber LIKE '%current%'


AND c.id = %%COURSEID%%
GROUP BY u.idnumber, c.id
#HAVING students > 0
ORDER BY RIGHT(c.shortname,2), c.shortname
</syntaxhighlight>


GROUP BY u.idnumber
===Weekly Student Online Participation===
Contributed by Elizabeth Dalton, Granite State College


ORDER BY u.lastname, u.firstname
Displays participation of students in the current course by week, including pre-term and post-term edits. An edit is defined as a change to the course, such as a discussion post, the submission of an assignment, or the completion of a quiz, as well as alterations to course content such as database entries (if permitted).
</code>
 
Links to three other reports are also provided:


===My Weekly Online Participation===
* Logs: complete log entries for the student in the course, organized by date
Contributed by Elizabeth Dalton, Granite State College
* Activity Outline: the "Outline Report" from the User Activity Reports, summarizing the student's activity in the course, organized by course content
* Consolidated Activity Report: the "Complete Report" from the User Activity Reports, detailing the student's activity in the course, organized by course content (includes text of forum posts)


Displays participation of the '''current user''' in the '''current course''' by week, including pre-term and post-term submissions/edits. A submission/edit is defined as a change to the course, such as a discussion post, the submission of an assignment, or the completion of a quiz, as well as alterations to course content such as database entries or new course activities or resources (if permitted).
'''Note''': This should be defined as a "Global" report (visible from within all courses). At our institution, our terms are 12 weeks long. You would want to insert additional "SUM" lines for longer terms, or remove lines for shorter terms. We pull advisor names into student user profiles as part of our configuration. These lines are present in the code below, but are commented out, as they are very specific to your Moodle configuration.


This report uses Standard Logs (post 2.7).
'''Note''': This version of the report uses legacy (pre-2.7) logs. See below for a post-2.7 Standard Logs version.


<code sql>
<syntaxhighlight lang="SQL">
SELECT  
SELECT  
u.lastname AS 'Last Name'
, u.firstname AS 'First Name'
,  COUNT(l.id) AS 'Edits'
, SUM(IF((l.time-c.startdate)/7<0,1,0)) AS 'Before Term'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=0,1,0)) AS 'Week 1'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=1,1,0)) AS 'Week 2'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=2,1,0)) AS 'Week 3'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=3,1,0)) AS 'Week 4'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=4,1,0)) AS 'Week 5'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=5,1,0)) AS 'Week 6'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=6,1,0)) AS 'Week 7'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=7,1,0)) AS 'Week 8'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=8,1,0)) AS 'Week 9'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=9,1,0)) AS 'Week 10'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=10,1,0)) AS 'Week 11'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=11,1,0)) AS 'Week 12'


l.component AS 'activity'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))>=15,1,0)) AS 'After Term'


, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS 'Logs'


, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=outline">','Outline','</a>') AS 'Activity Outline'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=7,l.id,NULL)) AS 'Week 8'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=8,l.id,NULL)) AS 'Week 9'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=9,l.id,NULL)) AS 'Week 10'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=10,l.id,NULL)) AS 'Week 11'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=11,l.id,NULL)) AS 'Week 12'


, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=complete">','Activity','</a>') AS 'Consolidated Activity'
 
, COUNT(l.id) AS 'Total'


FROM prefix_user AS u
FROM prefix_user AS u
Line 669: Line 806:
JOIN prefix_course_categories as cc ON c.category = cc.id
JOIN prefix_course_categories as cc ON c.category = cc.id


LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id  AND l.crud IN ('c','u')
LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id  AND l.action NOT LIKE "view%"


WHERE 1
WHERE ra.roleid =5
AND ctx.instanceid = c.id
AND ctx.instanceid = c.id


AND c.id = %%COURSEID%%
AND c.id = %%COURSEID%%
AND u.id = %%USERID%%


GROUP BY l.component
GROUP BY u.idnumber


ORDER BY l.component
ORDER BY u.lastname, u.firstname
</code>
</syntaxhighlight>


===Faculty/Student Interactions===
'''Note''': Post-2.7 (Standard Logs) version
Contributed by Elizabeth Dalton, Granite State College
 
Returns a count of instructor and other-student responses to student activity for the specified time period. This report can help indicate whether students' comments are being responded to, as well as summarizing post activity by students during the specified time.
 
'''Note''': This version of the report uses legacy (pre-2.7) logs. See below for the post-2.7 Standard Logs version.
 
'''Note''': This should be defined as a "Global" report (visible from within all courses).
 
'''Note''': This report can take a long time to run.


 
<syntaxhighlight lang="SQL">
<code sql>
SELECT  
SELECT  
u.lastname AS 'Last Name'
, u.firstname AS 'First Name'
,  COUNT(l.id) AS 'Edits'


# Identify student
, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
CONCAT('<a target="_blank" href="%%WWWROOT%%/message/index.php?id=' , allstu.id , '">' , allstu.firstname , ' ' , allstu.lastname , '</a>' ) AS 'Student - click to send message'


, IF((COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP() - (7*24*60*60)),fps.id,NULL) )>0) OR (COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP() - (7*24*60*60)),asb.id,NULL))>0) OR  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id AND mfs.timecreated > (UNIX_TIMESTAMP() - (7*24*60*60))),'YES','NO') AS 'Student Participated This week'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=7,l.id,NULL)) AS 'Week 8'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=8,l.id,NULL)) AS 'Week 9'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=9,l.id,NULL)) AS 'Week 10'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=10,l.id,NULL)) AS 'Week 11'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=11,l.id,NULL)) AS 'Week 12'


, IF((COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP() - (7*24*60*60)),fpi.id,NULL) )>0) OR (COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asg.id,NULL))>0) OR (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id  AND mts.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))),'YES','NO') AS 'Student Contacted This week'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'


## Only posts within last 7 days
# Our institution stores academic advisor names and emails in custom profile fields
#, CONCAT('<a href="mailto:',uce.data,'">',uid.data, '</a>')  AS 'Academic Advisor'


# Count posts by student
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS 'Logs'
, COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP() - (7*24*60*60)),fps.id,NULL)) AS 'Forum Stu Posts - 7 days'


# Count replies to student posts by instructors
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=outline">','Outline','</a>') AS 'Activity Outline'
, COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP() - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Instr Replies - 7 days'


# using link back to student posts on replies, get unique student IDs responded
, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=complete">','Activity','</a>') AS 'Consolidated Activity'
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP() - (7*24*60*60)),fpsr.id,NULL)) - COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Stu Replies - 7 days'


# all replies
, CONCAT('<a target="_blank" href="%%WWWROOT%%/mod/forum/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'">','Posts','</a>') AS 'Posts'
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP() - (7*24*60*60)),fpsr.id,NULL)) AS 'Forum All Replies - 7 days'


# add in count of graded assignments - 7 days
FROM prefix_user AS u
, COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL)) AS 'Assign Submit - 7 days'
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
, COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asg.id,NULL)) AS 'Assign Grades - 7 days'
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id


# Messages between students and instructors - 7 days
# student academic coach - you can include custom profile field data with these methods
,  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id AND mfs.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))) AS 'Msg Stu to Instr - 7 days'
# LEFT JOIN prefix_user_info_data as uid ON u.id = uid.userid AND uid.fieldid = '2'
, (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id  AND mts.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))) AS 'Msg Instr to Stu - 7 days'
# student academic coach email
# LEFT JOIN prefix_user_info_data as uce on u.id = uce.userid AND uce.fieldid = '6'


## All posts in course so far
LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id AND l.crud IN ('c','u')
# Count posts by student
, COUNT(DISTINCT fps.id) AS 'Forum Stu Posts - to date'


# Count replies to student posts by instructors
WHERE ra.roleid =5
, COUNT(DISTINCT fpi.id) AS 'Forum Instr Replies - to date'
AND ctx.instanceid = c.id


# using link back to student posts on replies, get unique student IDs responded
AND c.id = %%COURSEID%%
, COUNT(DISTINCT fpsr.id) - COUNT(DISTINCT fpi.id) AS 'Forum Stu Replies - to date'


# all replies
GROUP BY u.idnumber
, COUNT(DISTINCT fpsr.id) AS 'Forum All Replies - to date'


# add in count of graded assignments - whole course
ORDER BY u.lastname, u.firstname
, COUNT(DISTINCT asb.id) AS 'Assign Submit - to date'
</syntaxhighlight>
, COUNT(DISTINCT asg.id) AS 'Assign Grades - to date'


# Messages between students and instructors - to date
===My Weekly Online Participation===
,  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id ) AS 'Msg Stu to Instr - to date'
Contributed by Elizabeth Dalton, Granite State College
, (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id) AS 'Msg Instr to Stu - to date'


## JOINS
Displays participation of the '''current user''' in the '''current course''' by week, including pre-term and post-term submissions/edits. A submission/edit is defined as a change to the course, such as a discussion post, the submission of an assignment, or the completion of a quiz, as well as alterations to course content such as database entries or new course activities or resources (if permitted).


# Start by getting all the students in the course
This report uses Standard Logs (post 2.7).
FROM prefix_user AS allstu
JOIN prefix_role_assignments AS ras ON allstu.id = ras.userid AND ras.roleid = 5
JOIN prefix_context AS ctx  ON ras.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id


# Now we get the forums and forum discussions from this course only
<syntaxhighlight lang="SQL">
LEFT JOIN prefix_forum AS frm ON frm.course = c.id AND c.id = %%COURSEID%%
SELECT
LEFT JOIN prefix_forum_discussions AS fd ON fd.course = %%COURSEID%% AND fd.forum = frm.id


# These are forum discussion posts just by students within specified time
l.component AS 'activity'
LEFT JOIN prefix_forum_posts AS fps ON fps.userid = allstu.id AND fps.discussion = fd.id


# Separately, we connect the instructors of the courses
, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
# We can use the context we have already gotten for the students
LEFT JOIN prefix_role_assignments AS rai ON rai.contextid = ctx.id
LEFT JOIN prefix_user AS instr ON instr.id = rai.userid AND rai.roleid =3


# Now we will connect to posts by instructors that are replies to student posts
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
# This is a left join, because we don't want to eliminate any students from the list
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
LEFT JOIN prefix_forum_posts AS fpi ON fpi.discussion = fd.id AND fpi.userid = instr.id AND fpi.parent = fps.id
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=7,l.id,NULL)) AS 'Week 8'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=8,l.id,NULL)) AS 'Week 9'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=9,l.id,NULL)) AS 'Week 10'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=10,l.id,NULL)) AS 'Week 11'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=11,l.id,NULL)) AS 'Week 12'


# To get identities of only those students who were replied to:
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'
# Connect from instr replies back up to parent posts by students again
# This has to be a LEFT JOIN, we know these posts exist but don't eliminate non-responded students
LEFT JOIN prefix_forum_posts AS fpir ON fpir.id = fpi.parent


# We also want to know if students are replying to one another
, COUNT(l.id) AS 'Total'
# These are posts that are replies to student posts
# Again, a left join
LEFT JOIN prefix_forum_posts AS fpsr ON fpsr.discussion = fd.id AND fpsr.parent = fps.id


# get the activity modules
FROM prefix_user AS u
LEFT JOIN prefix_course_modules AS cm ON c.id = cm.course
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id


# get the assignments
LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id AND l.crud IN ('c','u')
LEFT JOIN prefix_assign AS a ON cm.instance = a.id
 
LEFT JOIN prefix_assign_submission AS asb ON a.id = asb.assignment AND asb.userid=allstu.id  
WHERE 1
LEFT JOIN prefix_assign_grades AS asg ON asg.assignment = a.id AND asg.userid = allstu.id AND asg.assignment = asb.assignment
AND ctx.instanceid = c.id
 
AND c.id = %%COURSEID%%
AND u.id = %%USERID%%
 
GROUP BY l.component
 
ORDER BY l.component
</syntaxhighlight>
 
===Faculty/Student Interactions===
Contributed by Elizabeth Dalton, Granite State College


# We care about messages that involve both the instructor and students of this course
Returns a count of instructor and other-student responses to student activity for the specified time period. This report can help indicate whether students' comments are being responded to, as well as summarizing post activity by students during the specified time.
# messages from instructor to students:
# LEFT JOIN prefix_message AS mts ON mts.useridfrom = instr.id AND mts.useridto = allstu.id
# LEFT JOIN prefix_message AS mfs ON mfs.useridfrom = instr.id AND mfs.useridto = allstu.id


WHERE 
'''Note''': This version of the report uses legacy (pre-2.7) logs. See below for the post-2.7 Standard Logs version.
c.id = %%COURSEID%%


# GROUP BY c.shortname , allstu.id
'''Note''': This should be defined as a "Global" report (visible from within all courses).  
GROUP BY allstu.id


ORDER BY allstu.lastname
'''Note''': This report can take a long time to run.  
</code>


'''Note''': Post-2.7 Standard Logs version


<code sql>
<syntaxhighlight lang="SQL">
SELECT  
SELECT  


Line 869: Line 1,002:


# Now we get the forums and forum discussions from this course only
# Now we get the forums and forum discussions from this course only
JOIN prefix_forum AS frm ON frm.course = c.id AND c.id = %%COURSEID%%
LEFT JOIN prefix_forum AS frm ON frm.course = c.id AND c.id = %%COURSEID%%
JOIN prefix_forum_discussions AS fd ON fd.course = %%COURSEID%% AND fd.forum = frm.id
LEFT JOIN prefix_forum_discussions AS fd ON fd.course = %%COURSEID%% AND fd.forum = frm.id


# These are forum discussion posts just by students within specified time
# These are forum discussion posts just by students within specified time
Line 877: Line 1,010:
# Separately, we connect the instructors of the courses
# Separately, we connect the instructors of the courses
# We can use the context we have already gotten for the students
# We can use the context we have already gotten for the students
JOIN prefix_role_assignments AS rai ON rai.contextid = ctx.id
LEFT JOIN prefix_role_assignments AS rai ON rai.contextid = ctx.id
JOIN prefix_user AS instr ON instr.id = rai.userid AND rai.roleid =3
LEFT JOIN prefix_user AS instr ON instr.id = rai.userid AND rai.roleid =3


# Now we will connect to posts by instructors that are replies to student posts
# Now we will connect to posts by instructors that are replies to student posts
Line 895: Line 1,028:


# get the activity modules
# get the activity modules
JOIN prefix_course_modules AS cm ON c.id = cm.course
LEFT JOIN prefix_course_modules AS cm ON c.id = cm.course


# get the assignments
# get the assignments
JOIN prefix_assign AS a ON  cm.instance = a.id
LEFT JOIN prefix_assign AS a ON  cm.instance = a.id
  LEFT JOIN prefix_assign_submission AS asb ON a.id = asb.assignment AND asb.userid=allstu.id  
  LEFT JOIN prefix_assign_submission AS asb ON a.id = asb.assignment AND asb.userid=allstu.id  
LEFT JOIN prefix_assign_grades AS asg ON asg.assignment = a.id AND asg.userid = allstu.id AND asg.assignment = asb.assignment  
LEFT JOIN prefix_assign_grades AS asg ON asg.assignment = a.id AND asg.userid = allstu.id AND asg.assignment = asb.assignment  
# We care about messages that involve both the instructor and students of this course
# messages from instructor to students:
# LEFT JOIN prefix_message AS mts ON mts.useridfrom = instr.id AND mts.useridto = allstu.id
# LEFT JOIN prefix_message AS mfs ON mfs.useridfrom = instr.id AND mfs.useridto = allstu.id


WHERE   
WHERE   
Line 909: Line 1,047:


ORDER BY allstu.lastname
ORDER BY allstu.lastname
</code>
</syntaxhighlight>
 
'''Note''': Post-2.7 Standard Logs version
 
<syntaxhighlight lang="SQL">
SELECT
 
# Identify student
CONCAT('<a target="_blank" href="%%WWWROOT%%/message/index.php?id=' , allstu.id , '">' , allstu.firstname , ' ' , allstu.lastname , '</a>' ) AS 'Student - click to send message'


===Student Resource Usage===
, IF((COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL) )>0) OR (COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL))>0) OR  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id AND mfs.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))),'YES','NO') AS 'Student Participated This week'
Contributed by Elizabeth Dalton, Granite State College


Displays usage by students of all activities and resources in the current course by activity. Only activities and sections which are visible in the course are included. This version requires the new "Standard Logs" from Moodle 2.7+.
, IF((COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) )>0) OR (COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asg.id,NULL))>0) OR (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id  AND mts.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))),'YES','NO') AS 'Student Contacted This week'


'''Note''': This should be defined as a "Global" report (visible from within all courses).
## Only posts within last 7 days


<code sql>
# Count posts by student
SELECT
, COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL)) AS 'Forum Stu Posts - 7 days'
cs.section AS 'Week'
, cs.name AS 'Section Name'
, m.name AS 'item type'


, CONCAT(
# Count replies to student posts by instructors
COALESCE(a.name, ''),
, COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP() - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Instr Replies - 7 days'
COALESCE(b.name,''),
COALESCE(cert.name,''),
COALESCE(chat.name,''),
COALESCE(choice.name,''),
COALESCE(data.name,''),
COALESCE(feedback.name,''),
COALESCE(folder.name,''),
COALESCE(forum.name,''),
COALESCE(glossary.name,''),  
COALESCE(imscp.name,''),
COALESCE(lesson.name,''),
COALESCE(p.name,''),
COALESCE(questionnaire.name,''),
COALESCE(quiz.name,''),
COALESCE(cr.name,''),  
COALESCE(scorm.name,''),
COALESCE(survey.name,''),
COALESCE(url.name,''),
COALESCE(wiki.name,''),
COALESCE(workshop.name,''),
COALESCE(kalvidassign.name,''),
COALESCE(attendance.name,''),
COALESCE(checklist.name,''),
COALESCE(flashcard.name,''),
COALESCE(lti.name,''),
COALESCE(oublog.name,''),
COALESCE(ouwiki.name,''),
COALESCE(subpage.name,''),
COALESCE(journal.name,''),
COALESCE(lightboxgallery.name,''),
COALESCE(elluminate.name,''),
COALESCE(adaptivequiz.name,''),
COALESCE(hotpot.name,''),
COALESCE(wiziq.name,''),
COALESCE(turnitintooltwo.name,''),
COALESCE(kvr.name,'')
) AS 'item name'


# using link back to student posts on replies, get unique student IDs responded
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpsr.id,NULL)) - COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Stu Replies - 7 days'


, SUM(IF(l.crud IN ('r'),1,0)) AS 'total views'
# all replies
, SUM(IF(l.crud IN ('c','u'),1,0)) AS 'total submissions'
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP() - (7*24*60*60)),fpsr.id,NULL)) AS 'Forum All Replies - 7 days'
, COUNT(DISTINCT IF(l.crud IN ('r'),u.id,NULL)) AS 'count of students who viewed'
, COUNT(DISTINCT IF(l.crud IN ('c','u'),u.id,NULL)) AS 'count of students who submitted'


FROM prefix_user AS u
# add in count of graded assignments - 7 days
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
, COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL)) AS 'Assign Submit - 7 days'
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
, COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asg.id,NULL)) AS 'Assign Grades - 7 days'
 
# Messages between students and instructors - 7 days
,  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id AND mfs.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))) AS 'Msg Stu to Instr - 7 days'
, (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id  AND mts.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))) AS 'Msg Instr to Stu - 7 days'
 
## All posts in course so far
# Count posts by student
, COUNT(DISTINCT fps.id) AS 'Forum Stu Posts - to date'
 
# Count replies to student posts by instructors
, COUNT(DISTINCT fpi.id) AS 'Forum Instr Replies - to date'
 
# using link back to student posts on replies, get unique student IDs responded
, COUNT(DISTINCT fpsr.id) - COUNT(DISTINCT fpi.id) AS 'Forum Stu Replies - to date'
 
# all replies
, COUNT(DISTINCT fpsr.id) AS 'Forum All Replies - to date'
 
# add in count of graded assignments - whole course
, COUNT(DISTINCT asb.id) AS 'Assign Submit - to date'
, COUNT(DISTINCT asg.id) AS 'Assign Grades - to date'
 
# Messages between students and instructors - to date
,  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id ) AS 'Msg Stu to Instr - to date'
, (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id) AS 'Msg Instr to Stu - to date'
 
## JOINS
 
# Start by getting all the students in the course
FROM prefix_user AS allstu
JOIN prefix_role_assignments AS ras ON allstu.id = ras.userid AND ras.roleid = 5
JOIN prefix_context AS ctx ON ras.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id
JOIN prefix_course_categories as cc ON c.category = cc.id


JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section <= 14 #AND cs.section > 0
# Now we get the forums and forum discussions from this course only
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
JOIN prefix_forum AS frm ON frm.course = c.id AND c.id = %%COURSEID%%
JOIN prefix_modules AS m ON m.id = cm.module AND m.name NOT LIKE 'label'
JOIN prefix_forum_discussions AS fd ON fd.course = %%COURSEID%% AND fd.forum = frm.id
 
# These are forum discussion posts just by students within specified time
LEFT JOIN prefix_forum_posts AS fps ON fps.userid = allstu.id AND fps.discussion = fd.id
 
# Separately, we connect the instructors of the courses
# We can use the context we have already gotten for the students
JOIN prefix_role_assignments AS rai ON rai.contextid = ctx.id
JOIN prefix_user AS instr ON instr.id = rai.userid AND rai.roleid =3
 
# Now we will connect to posts by instructors that are replies to student posts
# This is a left join, because we don't want to eliminate any students from the list
LEFT JOIN prefix_forum_posts AS fpi ON fpi.discussion = fd.id AND fpi.userid = instr.id AND fpi.parent = fps.id
 
# To get identities of only those students who were replied to:
# Connect from instr replies back up to parent posts by students again
# This has to be a LEFT JOIN, we know these posts exist but don't eliminate non-responded students
LEFT JOIN prefix_forum_posts AS fpir ON fpir.id = fpi.parent


LEFT JOIN prefix_assign AS a ON a.id = cm.instance AND m.name = 'assign'
# We also want to know if students are replying to one another
LEFT JOIN prefix_book AS b ON b.id = cm.instance AND m.name = 'book'
# These are posts that are replies to student posts
LEFT JOIN prefix_certificate AS cert ON cert.id = cm.instance AND m.name = 'certificate'
# Again, a left join
LEFT JOIN prefix_chat AS chat ON chat.id = cm.instance AND m.name = 'chat'
LEFT JOIN prefix_forum_posts AS fpsr ON fpsr.discussion = fd.id AND fpsr.parent = fps.id
LEFT JOIN prefix_choice AS choice ON choice.id = cm.instance AND m.name = 'choice'
LEFT JOIN prefix_data AS data ON data.id = cm.instance AND m.name = 'data'
LEFT JOIN prefix_feedback AS feedback ON feedback.id = cm.instance AND m.name = 'feedback'
LEFT JOIN prefix_folder AS folder ON folder.id = cm.instance AND m.name = 'folder'
LEFT JOIN prefix_forum AS forum ON forum.id = cm.instance AND m.name = 'forum'
LEFT JOIN prefix_glossary AS glossary ON glossary.id = cm.instance AND m.name = 'glossary'
LEFT JOIN prefix_imscp AS imscp ON imscp.id = cm.instance AND m.name = 'imscp'
LEFT JOIN prefix_lesson AS lesson ON lesson.id = cm.instance AND m.name = 'lesson'
LEFT JOIN prefix_page AS p ON p.id = cm.instance AND m.name = 'page'
LEFT JOIN prefix_questionnaire AS questionnaire ON questionnaire.id = cm.instance AND m.name = 'questionnaire'
LEFT JOIN prefix_quiz AS quiz ON quiz.id = cm.instance AND m.name = 'quiz'
LEFT JOIN prefix_resource AS cr ON cr.id = cm.instance AND m.name = 'resource'
LEFT JOIN prefix_scorm AS scorm ON scorm.id = cm.instance AND m.name = 'scorm'
LEFT JOIN prefix_survey AS survey ON survey.id = cm.instance AND m.name = 'survey'
LEFT JOIN prefix_url AS url ON url.id = cm.instance AND m.name = 'url'
LEFT JOIN prefix_wiki AS wiki ON wiki.id = cm.instance AND m.name = 'wiki'
LEFT JOIN prefix_workshop AS workshop ON workshop.id = cm.instance AND m.name = 'workshop'
LEFT JOIN prefix_kalvidassign AS kalvidassign ON kalvidassign.id = cm.instance AND m.name = 'kalvidassign'
LEFT JOIN prefix_kalvidres AS kvr ON kvr.id = cm.instance AND m.name = 'kalvidres'
LEFT JOIN prefix_attendance AS attendance ON attendance.id = cm.instance AND m.name = 'attendance'
LEFT JOIN prefix_checklist AS checklist ON checklist.id = cm.instance AND m.name = 'checklist'
LEFT JOIN prefix_flashcard AS flashcard ON flashcard.id = cm.instance AND m.name = 'flashcard'
LEFT JOIN prefix_lti AS lti ON lti.id = cm.instance AND m.name = 'lti'
LEFT JOIN prefix_oublog AS oublog ON oublog.id = cm.instance AND m.name = 'oublog'
LEFT JOIN prefix_ouwiki AS ouwiki ON ouwiki.id = cm.instance AND m.name = 'ouwiki'
LEFT JOIN prefix_subpage AS subpage ON subpage.id = cm.instance AND m.name = 'subpage'
LEFT JOIN prefix_journal AS journal ON journal.id = cm.instance AND m.name = 'journal'
LEFT JOIN prefix_lightboxgallery AS lightboxgallery ON lightboxgallery.id = cm.instance AND m.name = 'lightboxgallery'
LEFT JOIN prefix_elluminate AS elluminate ON elluminate.id = cm.instance AND m.name = 'elluminate'
LEFT JOIN prefix_adaptivequiz AS adaptivequiz ON adaptivequiz.id = cm.instance AND m.name = 'adaptivequiz'
LEFT JOIN prefix_hotpot AS hotpot ON hotpot.id = cm.instance AND m.name = 'hotpot'
LEFT JOIN prefix_wiziq AS wiziq ON wiziq.id = cm.instance AND m.name = 'wiziq'
LEFT JOIN prefix_turnitintooltwo AS turnitintooltwo ON turnitintooltwo.id = cm.instance AND m.name = 'turnitintooltwo'


LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id
# get the activity modules
JOIN prefix_course_modules AS cm ON c.id = cm.course


# get the assignments
JOIN prefix_assign AS a ON  cm.instance = a.id
LEFT JOIN prefix_assign_submission AS asb ON a.id = asb.assignment AND asb.userid=allstu.id
LEFT JOIN prefix_assign_grades AS asg ON asg.assignment = a.id AND asg.userid = allstu.id AND asg.assignment = asb.assignment


WHERE ra.roleid =5
WHERE
AND ctx.instanceid = c.id
c.id = %%COURSEID%%
AND cs.visible = 1
AND cm.visible = 1


AND c.id = %%COURSEID%%
# GROUP BY c.shortname , allstu.id
GROUP BY allstu.id


GROUP BY cm.id
ORDER BY allstu.lastname
</syntaxhighlight>


ORDER BY cs.section
===Student Resource Usage===
</code>
Contributed by Elizabeth Dalton, Granite State College


===Module activity (Hits) between dates===
Displays usage by students of all activities and resources in the current course by activity. Only activities and sections which are visible in the course are included. This version requires the new "Standard Logs" from Moodle 2.7+.
<code sql>
SELECT module, COUNT( * )
FROM prefix_log AS l
WHERE (FROM_UNIXTIME( l.`time` ) BETWEEN  '2012-10-01 00:00:00' AND  '2013-09-31 00:00:00')
GROUP BY module
</code>


===Module activity (Instances and Hits) for each academic year===
'''Note''': This should be defined as a "Global" report (visible from within all courses).
<code sql>
SELECT name


,(SELECT COUNT(*)
<syntaxhighlight lang="SQL">
FROM mdl_log AS l
SELECT  
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2010-10-01 00:00:00' AND '2011-09-31 00:00:00')
cs.section AS 'Week'
AND l.module = m.name AND l.action = 'add'
, cs.name AS 'Section Name'
) AS "Added 2010"
, m.name AS 'item type'
 
,(SELECT COUNT(*)
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2010-10-01 00:00:00' AND '2011-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2010"
 
,(SELECT COUNT(*)
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2011-10-01 00:00:00' AND '2012-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2011"
 
,(SELECT COUNT(*)
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2011-10-01 00:00:00' AND '2012-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2011"


, CONCAT(
COALESCE(a.name, ''),
COALESCE(b.name,''),
COALESCE(cert.name,''),
COALESCE(chat.name,''),
COALESCE(choice.name,''),
COALESCE(data.name,''),
COALESCE(feedback.name,''),
COALESCE(folder.name,''),
COALESCE(forum.name,''),
COALESCE(glossary.name,''),
COALESCE(imscp.name,''),
COALESCE(lesson.name,''),
COALESCE(p.name,''),
COALESCE(questionnaire.name,''),
COALESCE(quiz.name,''),
COALESCE(cr.name,''),
COALESCE(scorm.name,''),
COALESCE(survey.name,''),
COALESCE(url.name,''),
COALESCE(wiki.name,''),
COALESCE(workshop.name,''),
COALESCE(kalvidassign.name,''),
COALESCE(attendance.name,''),
COALESCE(checklist.name,''),
COALESCE(flashcard.name,''),
COALESCE(lti.name,''),
COALESCE(oublog.name,''),
COALESCE(ouwiki.name,''),
COALESCE(subpage.name,''),
COALESCE(journal.name,''),
COALESCE(lightboxgallery.name,''),
COALESCE(elluminate.name,''),
COALESCE(adaptivequiz.name,''),
COALESCE(hotpot.name,''),
COALESCE(wiziq.name,''),
COALESCE(turnitintooltwo.name,''),
COALESCE(kvr.name,'')
) AS 'item name'


,(SELECT COUNT(*)
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2012-10-01 00:00:00' AND '2013-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2012"


,(SELECT COUNT(*)  
, SUM(IF(l.crud IN ('r'),1,0)) AS 'total views'
FROM mdl_log AS l
, SUM(IF(l.crud IN ('c','u'),1,0)) AS 'total submissions'
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2012-10-01 00:00:00' AND '2013-09-31 00:00:00')
, COUNT(DISTINCT IF(l.crud IN ('r'),u.id,NULL)) AS 'count of students who viewed'
AND l.module = m.name
, COUNT(DISTINCT IF(l.crud IN ('c','u'),u.id,NULL)) AS 'count of students who submitted'
) AS "Used 2012"


FROM mdl_modules AS m
FROM prefix_user AS u
</code>
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id


===Unique user sessions per day and month + graph===
JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section <= 14 #AND cs.section > 0
The "graph" column is used when displaying a graph (which needs at least three columns to pick from)
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
<code sql>
JOIN prefix_modules AS m ON m.id = cm.module AND m.name NOT LIKE 'label'
SELECT COUNT(DISTINCT userid) AS "Unique User Logins"
,DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y /%m / %d") AS "Year / Month / Day", "Graph"
FROM `mdl_logstore_standard_log`
WHERE action LIKE 'loggedin'
#AND timecreated >  UNIX_TIMESTAMP('2015-01-01 00:00:00') # optional start date
#AND timecreated <= UNIX_TIMESTAMP('2015-01-31 23:59:00') # optional end date
GROUP BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
ORDER BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
</code>


And...
LEFT JOIN prefix_assign AS a ON a.id = cm.instance AND m.name = 'assign'
 
LEFT JOIN prefix_book AS b ON b.id = cm.instance AND m.name = 'book'
Counting user's global and unique hits per day + counting individual usage of specific activities and resources (on that day),
LEFT JOIN prefix_certificate AS cert ON cert.id = cm.instance AND m.name = 'certificate'
 
LEFT JOIN prefix_chat AS chat ON chat.id = cm.instance AND m.name = 'chat'
And since I am using phpMyAdmin's "Display Graph" feature (at the bottom of the query's output page), I have scaled down the "User Hits" by 10 to fit the graph. that's it.
LEFT JOIN prefix_choice AS choice ON choice.id = cm.instance AND m.name = 'choice'
<code sql>
LEFT JOIN prefix_data AS data ON data.id = cm.instance AND m.name = 'data'
SELECT DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y-%m-%d") AS "Datez"
LEFT JOIN prefix_feedback AS feedback ON feedback.id = cm.instance AND m.name = 'feedback'
,COUNT(DISTINCT userid) AS "Unique Users"
LEFT JOIN prefix_folder AS folder ON folder.id = cm.instance AND m.name = 'folder'
,ROUND(COUNT(*)/10) "User Hits (K)"
LEFT JOIN prefix_forum AS forum ON forum.id = cm.instance AND m.name = 'forum'
,SUM(IF(component='mod_quiz',1,0)) "Quizzes"
LEFT JOIN prefix_glossary AS glossary ON glossary.id = cm.instance AND m.name = 'glossary'
,SUM(IF(component='mod_forum' or component='mod_forumng',1,0)) "Forums"
LEFT JOIN prefix_imscp AS imscp ON imscp.id = cm.instance AND m.name = 'imscp'
,SUM(IF(component='mod_assign',1,0)) "Assignments"
LEFT JOIN prefix_lesson AS lesson ON lesson.id = cm.instance AND m.name = 'lesson'
,SUM(IF(component='mod_oublog',1,0)) "Blogs"
LEFT JOIN prefix_page AS p ON p.id = cm.instance AND m.name = 'page'
,SUM(IF(component='mod_resource',1,0)) "Files (Resource)"
LEFT JOIN prefix_questionnaire AS questionnaire ON questionnaire.id = cm.instance AND m.name = 'questionnaire'
,SUM(IF(component='mod_url',1,0)) "Links (Resource)"
LEFT JOIN prefix_quiz AS quiz ON quiz.id = cm.instance AND m.name = 'quiz'
,SUM(IF(component='mod_page',1,0)) "Pages (Resource)"
LEFT JOIN prefix_resource AS cr ON cr.id = cm.instance AND m.name = 'resource'
LEFT JOIN prefix_scorm AS scorm ON scorm.id = cm.instance AND m.name = 'scorm'
LEFT JOIN prefix_survey AS survey ON survey.id = cm.instance AND m.name = 'survey'
LEFT JOIN prefix_url AS url ON url.id = cm.instance AND m.name = 'url'
LEFT JOIN prefix_wiki AS wiki ON wiki.id = cm.instance AND m.name = 'wiki'
LEFT JOIN prefix_workshop AS workshop ON workshop.id = cm.instance AND m.name = 'workshop'
LEFT JOIN prefix_kalvidassign AS kalvidassign ON kalvidassign.id = cm.instance AND m.name = 'kalvidassign'
LEFT JOIN prefix_kalvidres AS kvr ON kvr.id = cm.instance AND m.name = 'kalvidres'
LEFT JOIN prefix_attendance AS attendance ON attendance.id = cm.instance AND m.name = 'attendance'
LEFT JOIN prefix_checklist AS checklist ON checklist.id = cm.instance AND m.name = 'checklist'
LEFT JOIN prefix_flashcard AS flashcard ON flashcard.id = cm.instance AND m.name = 'flashcard'
LEFT JOIN prefix_lti AS lti ON lti.id = cm.instance AND m.name = 'lti'
LEFT JOIN prefix_oublog AS oublog ON oublog.id = cm.instance AND m.name = 'oublog'
LEFT JOIN prefix_ouwiki AS ouwiki ON ouwiki.id = cm.instance AND m.name = 'ouwiki'
LEFT JOIN prefix_subpage AS subpage ON subpage.id = cm.instance AND m.name = 'subpage'
LEFT JOIN prefix_journal AS journal ON journal.id = cm.instance AND m.name = 'journal'
LEFT JOIN prefix_lightboxgallery AS lightboxgallery ON lightboxgallery.id = cm.instance AND m.name = 'lightboxgallery'
LEFT JOIN prefix_elluminate AS elluminate ON elluminate.id = cm.instance AND m.name = 'elluminate'
LEFT JOIN prefix_adaptivequiz AS adaptivequiz ON adaptivequiz.id = cm.instance AND m.name = 'adaptivequiz'
LEFT JOIN prefix_hotpot AS hotpot ON hotpot.id = cm.instance AND m.name = 'hotpot'
LEFT JOIN prefix_wiziq AS wiziq ON wiziq.id = cm.instance AND m.name = 'wiziq'
LEFT JOIN prefix_turnitintooltwo AS turnitintooltwo ON turnitintooltwo.id = cm.instance AND m.name = 'turnitintooltwo'


FROM `mdl_logstore_standard_log`
LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id
WHERE 1=1
AND timecreated >  UNIX_TIMESTAMP('2015-03-01 00:00:00') # optional START DATE
AND timecreated <= UNIX_TIMESTAMP('2015-05-31 23:59:00') # optional END DATE
GROUP BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
ORDER BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
</code>




===User detailed activity in course modules===
WHERE ra.roleid =5
Considering only several modules: url, resource, forum, quiz, questionnaire.
AND ctx.instanceid = c.id
AND cs.visible = 1
AND cm.visible = 1


<code sql>
AND c.id = %%COURSEID%%
SELECT u.id, ra.roleid,
CONCAT(u.lastname, ' ', u.firstname) AS 'Student'
,COUNT(l.id) AS 'Actions'
,l.component "Module type"
,l.objectid "Module ID"
,CASE
  WHEN l.component = 'mod_url' THEN (SELECT u.name FROM mdl_url AS u WHERE u.id = l.objectid )
  WHEN l.component = 'mod_resource' THEN (SELECT r.name FROM mdl_resource AS r WHERE r.id = l.objectid )
  WHEN l.component = 'mod_forum' THEN (SELECT f.name FROM mdl_forum AS f WHERE f.id = l.objectid )
  WHEN l.component = 'mod_quiz' THEN (SELECT q.name FROM mdl_quiz AS q WHERE q.id = l.objectid )
  WHEN l.component = 'mod_questionnaire' THEN (SELECT q.name FROM mdl_questionnaire AS q WHERE q.id = l.objectid )
END AS 'Module name'


,(SELECT GROUP_CONCAT(g.name) FROM mdl_groups AS g
GROUP BY cm.id
JOIN mdl_groups_members AS m ON g.id = m.groupid WHERE g.courseid = l.courseid AND m.userid = u.id) "user_groups"


,(SELECT s.name
ORDER BY cs.section
  FROM mdl_course_modules AS cm
</syntaxhighlight>
  JOIN mdl_course_sections AS s ON s.course = cm.course AND s.id = cm.section  
  WHERE cm.id = l.contextinstanceid) AS "Section name"


FROM mdl_logstore_standard_log AS l 
===Module activity (Hits) between dates===
JOIN mdl_user AS u ON u.id = l.userid
<syntaxhighlight lang="SQL">
JOIN mdl_role_assignments AS ra ON ra.userid = l.userid
SELECT module, COUNT( * )  
  AND ra.contextid = (SELECT id FROM mdl_context WHERE instanceid = l.courseid AND contextlevel = 50)
FROM prefix_logstore_standard_log AS l
WHERE l.courseid = %%COURSEID%%
WHERE (FROM_UNIXTIME( l.`timecreated` ) BETWEEN  '2018-10-01 00:00:00' AND  '2019-09-31 00:00:00')
  AND l.component IN ('mod_url', 'mod_resource', 'mod_forum', 'mod_quiz', 'mod_questionnaire')  
GROUP BY module
  %%FILTER_STARTTIME:l.timecreated:>%% %%FILTER_ENDTIME:l.timecreated:<%%
</syntaxhighlight>
GROUP BY u.id, l.component
ORDER BY u.lastname, u.firstname
</code>


===What teachers and courses considered active?===
===Module activity (Instances and Hits) for each academic year===
This report display several calculations and parameters that help the Online academic training team find teachers that might need more support getting their courses more supporting of online learning pedagogical methodologies. 
<syntaxhighlight lang="SQL">
<code sql>
SELECT name
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',
  course.id,'">',course.fullname,'</a>') AS Course


#,course.shortname
,(SELECT COUNT(*)
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2017-10-01 00:00:00' AND '2018-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2017"


,CASE
,(SELECT COUNT(*)
  WHEN course.fullname LIKE '%2012%' THEN '2012'
FROM prefix_logstore_standard_log AS l
  WHEN course.fullname LIKE '%2013%' THEN '2013'  
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2017-10-01 00:00:00' AND '2018-09-31 00:00:00')
  WHEN course.fullname LIKE '%2014%' THEN '2014'
AND l.module = m.name
  WHEN course.fullname LIKE '%2015%' THEN '2015'
) AS "Used 2017"
END AS Year


,CASE
,(SELECT COUNT(*)
  WHEN course.fullname LIKE '%semester a%' THEN 'Spring semester'
FROM prefix_logstore_standard_log AS l
  WHEN course.fullname LIKE '%semester b%' THEN 'Fall semester'
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2018-10-01 00:00:00' AND '2019-09-31 00:00:00')
  WHEN course.fullname LIKE '%semester s%' THEN 'Summer semester'
AND l.module = m.name AND l.action = 'add'
END AS Semester
) AS "Added 2018"


,IF(course.startdate>0, DATE_FORMAT(FROM_UNIXTIME(startdate), '%d-%m-%Y'), 'no date') AS "Course Start Date"  
,(SELECT COUNT(*)
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2018-10-01 00:00:00' AND '2019-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2018"


,(SELECT COUNT( ra.userid ) AS Users
,(SELECT COUNT(*)  
FROM prefix_role_assignments AS ra
FROM prefix_logstore_standard_log AS l
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2019-10-01 00:00:00' AND '2020-09-31 00:00:00')
WHERE ra.roleid = 5 AND ctx.instanceid = course.id
AND l.module = m.name AND l.action = 'add'
) AS Students
) AS "Added 2019"


,(SELECT COUNT( ra.userid ) AS Users
,(SELECT COUNT(*)  
FROM prefix_role_assignments AS ra
FROM prefix_logstore_standard_log AS l
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2019-10-01 00:00:00' AND '2020-09-31 00:00:00')
WHERE ra.roleid = 4 AND ctx.instanceid = course.id
AND l.module = m.name
) AS "Assistant teacher"
) AS "Used 2019"


,(SELECT COUNT( ra.userid ) AS Users
FROM mdl_modules AS m
FROM prefix_role_assignments AS ra
</syntaxhighlight>
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 3 AND ctx.instanceid = course.id
) AS Teachers


# Uncomment to use the new Moodle 2.8+ logstore
===Unique user sessions per day and month + graph===
#,(SELECT COUNT(*) FROM mdl_logstore_standard_log AS l WHERE l.courseid = course.id) AS Hits
The "graph" column is used when displaying a graph (which needs at least three columns to pick from)
 
<syntaxhighlight lang="SQL">
#,(SELECT COUNT(*)
SELECT COUNT(DISTINCT userid) AS "Unique User Logins"
#FROM mdl_logstore_standard_log AS l
,DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y /%m / %d") AS "Year / Month / Day", "Graph"
#JOIN mdl_role_assignments AS ra ON ra.userid= l.userid AND ra.roleid = 5 AND ra.contextid = (SELECT id FROM mdl_context WHERE instanceid = l.courseid AND contextlevel = 50)  
FROM `mdl_logstore_standard_log`
#WHERE l.courseid = course.id ) AS "Student HITs"
WHERE action LIKE 'loggedin'
#AND timecreated >  UNIX_TIMESTAMP('2015-01-01 00:00:00') # optional start date
#AND timecreated <= UNIX_TIMESTAMP('2015-01-31 23:59:00') # optional end date
GROUP BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
ORDER BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
</syntaxhighlight>


#,(SELECT COUNT(*)
And...
#FROM mdl_logstore_standard_log AS l
#JOIN mdl_role_assignments AS ra ON ra.userid= l.userid AND ra.roleid = 3 AND ra.contextid = (SELECT id FROM mdl_context WHERE instanceid = l.courseid AND contextlevel = 50)
#WHERE l.courseid = course.id ) AS "Teacher HITs"


,(SELECT COUNT(*) FROM mdl_log AS l WHERE l.course = course.id) AS Hits
Counting user's global and unique hits per day + counting individual usage of specific activities and resources (on that day),


,(SELECT COUNT(*)
And since I am using phpMyAdmin's "Display Graph" feature (at the bottom of the query's output page), I have scaled down the "User Hits" by 10 to fit the graph. that's it.
FROM mdl_log AS l
<syntaxhighlight lang="SQL">
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
SELECT DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y-%m-%d") AS "Datez"
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 5
,COUNT(DISTINCT userid) AS "Unique Users"
WHERE l.course = course.id) AS "Students HITs"
,ROUND(COUNT(*)/10) "User Hits (K)"
,SUM(IF(component='mod_quiz',1,0)) "Quizzes"
,(SELECT COUNT(*)
,SUM(IF(component='mod_forum' or component='mod_forumng',1,0)) "Forums"
FROM mdl_log AS l
,SUM(IF(component='mod_assign',1,0)) "Assignments"
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
,SUM(IF(component='mod_oublog',1,0)) "Blogs"
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3
,SUM(IF(component='mod_resource',1,0)) "Files (Resource)"
WHERE l.course = course.id) AS "Teachers HITs"
,SUM(IF(component='mod_url',1,0)) "Links (Resource)"
,SUM(IF(component='mod_page',1,0)) "Pages (Resource)"


,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) )
FROM `mdl_logstore_standard_log`
FROM prefix_course c
WHERE 1=1
JOIN prefix_context con ON con.instanceid = c.id
AND timecreated >  UNIX_TIMESTAMP('2015-03-01 00:00:00') # optional START DATE
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
AND timecreated <= UNIX_TIMESTAMP('2015-05-31 23:59:00') # optional END DATE
JOIN prefix_role r ON ra.roleid = r.id
GROUP BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
JOIN prefix_user u ON u.id = ra.userid
ORDER BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
WHERE r.id = 3 AND c.id = course.id
</syntaxhighlight>
GROUP BY c.id
) AS Teachers
 
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = course.id) Modules


,(SELECT COUNT(DISTINCT cm.module) FROM prefix_course_modules cm
===System wide, daily unique user hits for the last 7 days===
   WHERE cm.course = course.id) UniqueModules
<syntaxhighlight lang="SQL">
SELECT
  DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%m%d') 'Day'
  ,COUNT(DISTINCT l.userid) AS 'Distinct Users Hits'
   ,COUNT( l.userid) AS 'Users Hits'


,(SELECT GROUP_CONCAT(DISTINCT m.name)
FROM prefix_logstore_standard_log AS l
  FROM prefix_course_modules cm
WHERE l.courseid > 1
  JOIN mdl_modules as m ON m.id = cm.module
      AND FROM_UNIXTIME(l.timecreated) >= DATE_SUB(NOW(), INTERVAL 7 DAY)
  WHERE cm.course = course.id) UniqueModuleNames
GROUP BY DAY(FROM_UNIXTIME(timecreated))
</syntaxhighlight>


,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
===User detailed activity in course modules===
  WHERE cm.course = course.id AND m.name IN ( 'ouwiki', 'wiki') ) "Num Wikis"
Considering only several modules: url, resource, forum, quiz, questionnaire.


,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
<syntaxhighlight lang="SQL">
   WHERE cm.course = course.id AND m.name IN ( 'oublog') ) "Num Blogs"
SELECT u.id, ra.roleid,
CONCAT(u.lastname, ' ', u.firstname) AS 'Student'
,COUNT(l.id) AS 'Actions'
,l.component "Module type"
,l.objectid "Module ID"
,CASE
  WHEN l.component = 'mod_url' THEN (SELECT u.name FROM prefix_url AS u WHERE u.id = l.objectid )
   WHEN l.component = 'mod_resource' THEN (SELECT r.name FROM prefix_resource AS r WHERE r.id = l.objectid )
  WHEN l.component = 'mod_forum' THEN (SELECT f.name FROM prefix_forum AS f WHERE f.id = l.objectid )
  WHEN l.component = 'mod_quiz' THEN (SELECT q.name FROM prefix_quiz AS q WHERE q.id = l.objectid )
  WHEN l.component = 'mod_questionnaire' THEN (SELECT q.name FROM prefix_questionnaire AS q WHERE q.id = l.objectid )
END AS 'Module name'


,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
,(SELECT GROUP_CONCAT(g.name) FROM prefix_groups AS g
  WHERE cm.course = course.id AND m.name IN ( 'forum', 'forumng') ) "Num Forums"
JOIN prefix_groups_members AS m ON g.id = m.groupid WHERE g.courseid = l.courseid AND m.userid = u.id) "user_groups"


,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
,(SELECT s.name
   WHERE cm.course = course.id AND m.name IN ('resource', 'folder', 'url', 'tab', 'file', 'book', 'page') ) Resources
  FROM prefix_course_modules AS cm  
  JOIN prefix_course_sections AS s ON s.course = cm.course AND s.id = cm.section
   WHERE cm.id = l.contextinstanceid) AS "Section name"


,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
FROM prefix_logstore_standard_log AS l 
   WHERE cm.course = course.id AND m.name IN ('forum', 'forumng', 'oublog', 'page', 'file', 'url', 'wiki' , 'ouwiki') ) "Basic Activities"
JOIN prefix_user AS u ON u.id = l.userid
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid
   AND ra.contextid = (SELECT id FROM prefix_context WHERE instanceid = l.courseid AND contextlevel = 50)
WHERE l.courseid = %%COURSEID%%
  AND l.component IN ('mod_url', 'mod_resource', 'mod_forum', 'mod_quiz', 'mod_questionnaire')
  %%FILTER_STARTTIME:l.timecreated:>%% %%FILTER_ENDTIME:l.timecreated:<%%
GROUP BY u.id, l.component
ORDER BY u.lastname, u.firstname
</syntaxhighlight>


,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
===What teachers and courses considered active?===
  WHERE cm.course = course.id AND m.name IN ('advmindmap', 'assign', 'attendance', 'book', 'choice', 'folder', 'tab', 'glossary', 'questionnaire', 'quiz', 'label' ) ) "Avarage Activities"
This report display several calculations and parameters that help the Online academic training team find teachers that might need more support getting their courses more supporting of online learning pedagogical methodologies. 
<syntaxhighlight lang="SQL">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',
  course.id,'">',course.fullname,'</a>') AS Course


,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
#,course.shortname
  WHERE cm.course = course.id AND m.name IN ('elluminate', 'game', 'workshop') ) "Advanced Activities"


FROM prefix_course AS course
,CASE
  WHEN course.fullname LIKE '%2012%' THEN '2012'
  WHEN course.fullname LIKE '%2013%' THEN '2013'
  WHEN course.fullname LIKE '%2014%' THEN '2014'
  WHEN course.fullname LIKE '%2015%' THEN '2015'
END AS Year


#WHERE course.shortname LIKE '%2015%'
,CASE
#WHERE 1=1
  WHEN course.fullname LIKE '%semester a%' THEN 'Spring semester'
#%%FILTER_SEARCHTEXT:course.shortname:~%%
  WHEN course.fullname LIKE '%semester b%' THEN 'Fall semester'
  WHEN course.fullname LIKE '%semester s%' THEN 'Summer semester'
END AS Semester


WHERE course.fullname LIKE '%2015%'  
,IF(course.startdate>0, DATE_FORMAT(FROM_UNIXTIME(startdate), '%d-%m-%Y'), 'no date') AS "Course Start Date"


HAVING Modules > 2
,(SELECT COUNT( ra.userid ) AS Users
ORDER BY UniqueModules DESC
FROM prefix_role_assignments AS ra
</code>
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
 
WHERE ra.roleid = 5 AND ctx.instanceid = course.id
==Course Reports==
) AS Students
===Most Active courses===
<code sql>
SELECT count(l.userid) AS Views
FROM `mdl_logstore_standard_log` l, `mdl_user` u, `mdl_role_assignments` r
WHERE l.courseid=35
AND l.userid = u.id
AND (l.timecreated > UNIX_TIMESTAMP('2015-01-01 00:00:00') AND l.timecreated <= UNIX_TIMESTAMP('2015-01-31 23:59:59'))AND r.contextid= (
SELECT id
FROM mdl_context
WHERE contextlevel=50 AND instanceid=l.courseid
)
AND r.roleid=5
AND r.userid = u.id
</code>


===Active courses, advanced===
,(SELECT COUNT( ra.userid ) AS Users
Including: Teacher's name, link to the course, All types of log activities, special YEAR generated field, Activities and Resource count, enrolled Student count
FROM prefix_role_assignments AS ra
<code sql>
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
SELECT COUNT(l.id) hits, concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
WHERE ra.roleid = 4 AND ctx.instanceid = course.id
) AS "Assistant teacher"


,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
,(SELECT COUNT( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = course.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
) AS Teachers


,CASE
# Uncomment to use the new Moodle 2.8+ logstore
  WHEN c.fullname LIKE '%תשע' THEN 'תשע'
#,(SELECT COUNT(*) FROM mdl_logstore_standard_log AS l WHERE l.courseid = course.id) AS Hits
  WHEN c.fullname LIKE '%תשעא' THEN 'תשעא'
  WHEN c.fullname LIKE '%תשעב' THEN 'תשעב'
END AS Year


,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = l.course) Modules
#,(SELECT COUNT(*)
 
#FROM mdl_logstore_standard_log AS l
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
#JOIN mdl_role_assignments AS ra ON ra.userid= l.userid AND ra.roleid = 5 AND ra.contextid = (SELECT id FROM mdl_context WHERE instanceid = l.courseid AND contextlevel = 50)
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
#WHERE l.courseid = course.id ) AS "Student HITs"
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students


FROM prefix_log l  
#,(SELECT COUNT(*)
INNER JOIN prefix_course c ON l.course = c.id
#FROM mdl_logstore_standard_log AS l
GROUP BY c.id
#JOIN mdl_role_assignments AS ra ON ra.userid= l.userid AND ra.roleid = 3 AND ra.contextid = (SELECT id FROM mdl_context WHERE instanceid = l.courseid AND contextlevel = 50)
#The following line restricts the courses returned to those having more than 2 modules. Adjust based on your needs.
#WHERE l.courseid = course.id ) AS "Teacher HITs"
HAVING Modules > 2
ORDER BY Year DESC, hits DESC
</code>


===Count unique teachers with courses that use at least X module (Moodle19)===
,(SELECT COUNT(*) FROM mdl_log AS l WHERE l.course = course.id) AS Hits
You can remove the outer "SELECT COUNT(*) FROM (...) AS ActiveTeachers" SQL query and get the list of the Teachers and Courses.
<code sql>
SELECT COUNT(*)
FROM (SELECT c.id AS CourseID, c.fullname AS Course, ra.roleid AS RoleID, CONCAT(u.firstname, ' ', u.lastname) AS Teacher
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = c.id) AS Modules
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid AND ctx.contextlevel = 50
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE  ra.roleid = 3
GROUP BY u.id
HAVING Modules > 5) AS ActiveTeachers
</code>


===RESOURCE count for each COURSE===
,(SELECT COUNT(*)
<code sql>
FROM mdl_log AS l
SELECT COUNT(l.id) count, l.course, c.fullname coursename
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
FROM prefix_resource l INNER JOIN prefix_course c on l.course = c.id
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 5
GROUP BY course
WHERE l.course = course.id) AS "Students HITs"
ORDER BY count DESC
</code>
,(SELECT COUNT(*)
FROM mdl_log AS l
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3
WHERE l.course = course.id) AS "Teachers HITs"
 
,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) )
FROM prefix_course c
JOIN prefix_context con ON con.instanceid = c.id
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
JOIN prefix_role r ON ra.roleid = r.id
JOIN prefix_user u ON u.id = ra.userid
WHERE r.id = 3 AND c.id = course.id
GROUP BY c.id
) AS Teachers
 
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = course.id) Modules
 
,(SELECT COUNT(DISTINCT cm.module) FROM prefix_course_modules cm
  WHERE cm.course = course.id) UniqueModules


===Common resource types count for each Category (Moodle19)===
,(SELECT GROUP_CONCAT(DISTINCT m.name)  
Including sub-categories in total count.
  FROM prefix_course_modules cm
<code sql>
  JOIN mdl_modules as m ON m.id = cm.module
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category
  WHERE cm.course = course.id) UniqueModuleNames
,(SELECT COUNT( * )  
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference LIKE 'http://%'
) AS Links
,(SELECT COUNT( * )
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference NOT LIKE 'http://%'
) AS Files
,(SELECT COUNT( * )
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'directory'
) AS Folders
,(SELECT COUNT( * )
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'html'
) AS Pages
,(SELECT COUNT(*)
FROM stats_log_context_role_course
WHERE roleid = 5 AND module = 'resource' AND category = mcc.id
) AS Hits


FROM prefix_course_categories AS mcc
,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
ORDER BY mcc.path
  WHERE cm.course = course.id AND m.name IN ( 'ouwiki', 'wiki') ) "Num Wikis"
</code>
Where "stats_log_context_role_course" (in the above SQL query) is a VIEW generated by:
<code sql>
CREATE VIEW stats_log_context_role_course AS
SELECT l.course, c.category, cc.path, l.module, l.action, ra.userid, ra.roleid
FROM prefix_log AS l
JOIN prefix_context AS context ON context.instanceid = l.course AND context.contextlevel = 50
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid AND ra.contextid = context.id
JOIN prefix_course AS c ON c.id = l.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
</code>


Same query but for Moodle2+
,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
<code sql>
  WHERE cm.course = course.id AND m.name IN ( 'oublog') ) "Num Blogs"
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category,
mcc.path,


(SELECT COUNT(*)  
,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
FROM prefix_url AS u
  WHERE cm.course = course.id AND m.name IN ( 'forum', 'forumng') ) "Num Forums"
JOIN prefix_course AS c ON c.id = u.course
 
JOIN prefix_course_categories AS cc ON cc.id = c.category
,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
  WHERE cm.course = course.id AND m.name IN ('resource', 'folder', 'url', 'tab', 'file', 'book', 'page') ) Resources
) AS URLs,


(SELECT COUNT(*)  
,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
FROM prefix_folder AS f
  WHERE cm.course = course.id AND m.name IN ('forum', 'forumng', 'oublog', 'page', 'file', 'url', 'wiki' , 'ouwiki') ) "Basic Activities"
JOIN prefix_course AS c ON c.id = f.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS FOLDERs,


(SELECT COUNT(*)  
,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
FROM prefix_page AS p
  WHERE cm.course = course.id AND m.name IN ('advmindmap', 'assign', 'attendance', 'book', 'choice', 'folder', 'tab', 'glossary', 'questionnaire', 'quiz', 'label' ) ) "Avarage Activities"
JOIN prefix_course AS c ON c.id = p.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS PAGEs,


(SELECT COUNT(*)  
,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
FROM prefix_book AS b
  WHERE cm.course = course.id AND m.name IN ('elluminate', 'game', 'workshop') ) "Advanced Activities"
JOIN prefix_course AS c ON c.id = b.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS BOOKs,


(SELECT COUNT(*)
FROM prefix_course AS course
FROM prefix_label AS l
JOIN prefix_course AS c ON c.id = l.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS LABELs,


(SELECT COUNT(*)
#WHERE course.shortname LIKE '%2015%'
FROM prefix_tab AS t
#WHERE 1=1
JOIN prefix_course AS c ON c.id = t.course
#%%FILTER_SEARCHTEXT:course.shortname:~%%
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS TABs


FROM prefix_course_categories AS mcc
WHERE course.fullname LIKE '%2015%'
ORDER BY mcc.path
</code>


===Detailed Resource COUNT by Teacher in each course===
HAVING Modules > 2
ORDER BY UniqueModules DESC
</syntaxhighlight>


Including (optional) filter by: year, semester and course id.
===Weekly attendance report===
This report display weekly report in format HH:M:SS This MySQL query works together with AttendaceRegister module, and gather Log information from Attendanceregister_log table.
<syntaxhighlight lang="SQL">
SELECT u.username, SEC_TO_TIME (SUM(arsess.duration)) AS weekly_online_attendance, FROM_UNIXTIME (arsess.logout) AS Last_Logout
FROM prefix_attendanceregister_session AS arsess
JOIN prefix_user AS u ON arsess.userid = u.id


<code sql>
WHERE (((arsess.logout) BETWEEN UNIX_TIMESTAMP(DATE_SUB(CURDATE(), INTERVAL 7 DAY)) AND UNIX_TIMESTAMP(CURDATE())))
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS CourseID
, c.id
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher


, (CASE
GROUP BY arsess.userid
WHEN c.fullname LIKE '%תשעב%' THEN '2012'
</syntaxhighlight>
WHEN c.fullname LIKE '%תשעא%' THEN '2011'
END ) as Year
, (CASE
WHEN c.fullname LIKE '%סמסטר א%' THEN 'Semester A'
WHEN c.fullname LIKE '%סמסטר ב%' THEN 'Semester B'
WHEN c.fullname LIKE '%סמסטר ק%' THEN 'Semester C'
END ) as Semester
,COUNT(c.id) AS Total
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 20) AS TABs
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 33) AS BOOKs


FROM `prefix_resource` as r
===How many distinct users connected to Moodle using the app by month===
JOIN `prefix_course` AS c on c.id = r.course
https://moodle.org/mod/forum/discuss.php?d=336086#p1354194 by
#WHERE type= 'file' and reference NOT LIKE 'http://%'  
Iñigo Zendegi Urzelai
<syntaxhighlight lang="SQL">
SELECT
  to_char(to_timestamp("timecreated"),'YYYY') as year,
  to_char(to_timestamp("timecreated"),'MM') as month,
  count(distinct userid) as distinct_users


#WHERE 1=1
FROM prefix_logstore_standard_log l
#%%FILTER_YEARS:c.fullname%%
WHERE l.origin='ws'
#AND c.fullname LIKE '%2013%'
GROUP BY to_char(to_timestamp("timecreated"),'YYYY'), to_char(to_timestamp("timecreated"),'MM')
ORDER BY to_char(to_timestamp("timecreated"),'YYYY'), to_char(to_timestamp("timecreated"),'MM');
</syntaxhighlight>


GROUP BY course
==Course Reports==
ORDER BY COUNT(c.id) DESC
===Most Active courses===
</code>
<syntaxhighlight lang="SQL">
SELECT count(l.userid) AS Views
FROM `mdl_logstore_standard_log` l, `mdl_user` u, `mdl_role_assignments` r
WHERE l.courseid=35
AND l.userid = u.id
AND (l.timecreated > UNIX_TIMESTAMP('2015-01-01 00:00:00') AND l.timecreated <= UNIX_TIMESTAMP('2015-01-31 23:59:59'))AND r.contextid= (
SELECT id
FROM mdl_context
WHERE contextlevel=50 AND instanceid=l.courseid
)
AND r.roleid=5
AND r.userid = u.id
</syntaxhighlight>
 
===Active courses, advanced===
Including: Teacher's name, link to the course, All types of log activities, special YEAR generated field, Activities and Resource count, enrolled Student count
<syntaxhighlight lang="SQL">
SELECT COUNT(l.id) hits, concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course


===Courses that are defined as using GROUPs===
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
<code sql>
FROM prefix_role_assignments AS ra
SELECT concat('<a target="_new" href="%%WWWROOT%%/group/index.php?id=',c.id,'">',c.fullname,'</a>') AS Course
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = c.id) Modules
JOIN prefix_user AS u ON u.id = ra.userid
,(SELECT count(*) FROM prefix_groups g WHERE g.courseid = c.id) Groups
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
FROM `prefix_course` AS c
WHERE groupmode > 0
</code>


===Courses with Groups===
,CASE
  WHEN c.fullname LIKE '%תשע' THEN 'תשע'
  WHEN c.fullname LIKE '%תשעא' THEN 'תשעא'
  WHEN c.fullname LIKE '%תשעב' THEN 'תשעב'
END AS Year


List of all courses with Groups in them (groupmode > 0). You can also use groupmode=1 to list just Separate type groups or groupmode=2 to list Visible type groups.
,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = l.course) Modules


<code sql>
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
SELECT c.shortname, g.name, c.groupmode
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
FROM prefix_course AS c
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
JOIN prefix_groups AS g ON c.id = g.courseid
WHERE c.groupmode > 0
</code>


===Users enrolled in a course with groups but not assigned a group ===
FROM prefix_log l
 
INNER JOIN prefix_course c ON l.course = c.id
Displays by course all enrolled users that have not been assigned a group in courses that have groups. NOTE: This needs to be optimized.
GROUP BY c.id
 
#The following line restricts the courses returned to those having more than 2 modules. Adjust based on your needs.
<code sql>
HAVING Modules > 2
SELECT DISTINCT
ORDER BY Year DESC, hits DESC
user2.firstname AS Firstname,
</syntaxhighlight>
user2.lastname AS Lastname,
user2.email AS Email,
user2.city AS City,
course.fullname AS Course
,(SELECT shortname FROM prefix_role WHERE id=en.roleid) AS ROLE
,(SELECT name FROM prefix_role WHERE id=en.roleid) AS RoleName


FROM prefix_course AS course
=== Least active or probably empty courses===
JOIN prefix_enrol AS en ON en.courseid = course.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
JOIN prefix_user AS user2 ON ue.userid = user2.id
JOIN prefix_groups AS g ON g.courseid = course.id


WHERE ue.enrolid NOT IN (select userid from prefix_groups_members WHERE g.id=groupid)
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


ORDER BY Course, Lastname
It is difficult to know sometimes when a course is actually empty or was never really in use. Other than the simple case where the course was created and never touched again, in which case the course timecreated and timemodified will be the same, many courses created as shells for teachers or other users may be used once or a few times and have few or no test users enrollments in them. This query helps you see the range of such courses, showing you how many days if any it was used after initial creation, and how many user are enrolled. It denotes a course never ever modified by "-1" instead of "0" so you can sort those to the top. By default it limits this to courses used within 60 days of creation, and to courses with 3 or less enrollments (for example, teacher and assistant and test student account only.) You can easily adjust these numbers. The query includes a link to the course as well.
</code>


===Groups in course with member list===
<syntaxhighlight lang="SQL">
SELECT
c.fullname,
CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'CourseLink',
DATE_FORMAT(FROM_UNIXTIME(c.timecreated), '%Y-%m-%d %H:%i') AS 'Timecreated',
DATE_FORMAT(FROM_UNIXTIME(c.timemodified), '%Y-%m-%d %H:%i') AS 'Timemodified',
CASE
WHEN c.timecreated = c.timemodified THEN '-1'
ELSE DATEDIFF(FROM_UNIXTIME(c.timemodified),FROM_UNIXTIME(c.timecreated))
END AS 'DateDifference',
COUNT(ue.id) AS Enroled
FROM prefix_course AS c
JOIN prefix_enrol AS en ON en.courseid = c.id
LEFT JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
WHERE DATEDIFF(FROM_UNIXTIME(c.timemodified),FROM_UNIXTIME(c.timecreated) ) < 60
GROUP BY c.id
HAVING COUNT(ue.id) <= 3
ORDER BY c.fullname
</syntaxhighlight>


List the groups in a course (replace the # by the course id number) with the members of each group.
===Count unique teachers with courses that use at least X module (Moodle19)===
 
You can remove the outer "SELECT COUNT(*) FROM (...) AS ActiveTeachers" SQL query and get the list of the Teachers and Courses.
<code sql>
<syntaxhighlight lang="SQL">
SELECT c.shortname, g.name AS Groupname, u.username
SELECT COUNT(*)
FROM (SELECT c.id AS CourseID, c.fullname AS Course, ra.roleid AS RoleID, CONCAT(u.firstname, ' ', u.lastname) AS Teacher
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = c.id) AS Modules
FROM prefix_course AS c
FROM prefix_course AS c
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_context AS ctx ON c.id = ctx.instanceid AND ctx.contextlevel = 50
JOIN prefix_groups_members AS m ON g.id = m.groupid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON m.userid = u.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE c.id = #
JOIN prefix_course_categories AS cc ON cc.id = c.category
</code>
WHERE ra.roleid = 3
GROUP BY u.id
HAVING Modules > 5) AS ActiveTeachers
</syntaxhighlight>


===Group Export===
===RESOURCE count for each COURSE===
<syntaxhighlight lang="SQL">
SELECT COUNT(l.id) count, l.course, c.fullname coursename
FROM prefix_resource l INNER JOIN prefix_course c on l.course = c.id
GROUP BY course
ORDER BY count DESC
</syntaxhighlight>


There's a [[Import_groups|group import]] function, but no export. Use this to give you a report with the proper column order and headings to export to a csv file you can then import into another course to replicate the groups. This is a simple version with just the main fields: groupname, description, enrolment key.
===Common resource types count for each Category (Moodle19)===
 
Including sub-categories in total count.
<code sql>
<syntaxhighlight lang="SQL">
SELECT g.name AS groupname, g.description, g.enrolmentkey
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category
FROM prefix_groups AS g
,(SELECT COUNT( * )
JOIN prefix_course as c ON g.courseid = c.id
FROM prefix_resource AS r
WHERE c.id = #
JOIN prefix_course AS c ON c.id = r.course
</code>
JOIN prefix_course_categories AS cc ON cc.id = c.category
 
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference LIKE 'http://%'
===List all Courses in and below a certain category===
) AS Links
Use this SQL code to retrieve all courses that exist in or under a set category.
,(SELECT COUNT( * )
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference NOT LIKE 'http://%'
) AS Files
,(SELECT COUNT( * )
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'directory'
) AS Folders
,(SELECT COUNT( * )
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'html'
) AS Pages
,(SELECT COUNT(*)
FROM stats_log_context_role_course
WHERE roleid = 5 AND module = 'resource' AND category = mcc.id
) AS Hits


$s should be the id of the category you want to know about...
FROM prefix_course_categories AS mcc
<code sql>
ORDER BY mcc.path
SELECT prefix_course. * , prefix_course_categories. *
</syntaxhighlight>
FROM prefix_course, prefix_course_categories
Where "stats_log_context_role_course" (in the above SQL query) is a VIEW generated by:
WHERE prefix_course.category = prefix_course_categories.id
<syntaxhighlight lang="SQL">
AND (
CREATE VIEW stats_log_context_role_course AS
prefix_course_categories.path LIKE '/$s/%'
SELECT l.course, c.category, cc.path, l.module, l.action, ra.userid, ra.roleid
OR prefix_course_categories.path LIKE '/$s'
FROM prefix_log AS l
)
JOIN prefix_context AS context ON context.instanceid = l.course AND context.contextlevel = 50
</code>
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid AND ra.contextid = context.id
 
JOIN prefix_course AS c ON c.id = l.course
===List all Categories in one level below a certain category===
JOIN prefix_course_categories AS cc ON cc.id = c.category
Use this PHP code to retrieve a list of all categories below a certain category.
</syntaxhighlight>


$s should be the id of the top level category you are interested in.
Same query but for Moodle2+
<code php>
<syntaxhighlight lang="SQL">
<?php
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category,
mcc.path,


require_once('./config.php');
(SELECT COUNT(*)
FROM prefix_url AS u
JOIN prefix_course AS c ON c.id = u.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS URLs,


$parent_id = $s;
(SELECT COUNT(*)
FROM prefix_folder AS f
JOIN prefix_course AS c ON c.id = f.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS FOLDERs,


$categories= array();
(SELECT COUNT(*)
FROM prefix_page AS p
JOIN prefix_course AS c ON c.id = p.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS PAGEs,


$categories = get_categories($parent_id);
(SELECT COUNT(*)
FROM prefix_book AS b
JOIN prefix_course AS c ON c.id = b.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS BOOKs,


echo '<ol>';
(SELECT COUNT(*)  
foreach ($categories as $category)
FROM prefix_label AS l
        {
JOIN prefix_course AS c ON c.id = l.course
        echo '<li><a href="'.$CFG->wwwroot.'/course/category.php?id='.$category->id.'">'.$category->name.'</a></li>';
JOIN prefix_course_categories AS cc ON cc.id = c.category
        }
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
echo '</ol>';
) AS LABELs,
 
(SELECT COUNT(*)
FROM prefix_tab AS t
JOIN prefix_course AS c ON c.id = t.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS TABs


?>
FROM prefix_course_categories AS mcc
</code>
ORDER BY mcc.path
</syntaxhighlight>


===Blog activity per Course (not including VIEW)===
===Detailed Resource COUNT by Teacher in each course===
Filter activity logging to some specific Course Categories!
+ link course name to actual course (for quick reference)
(you can change %blog% to %wiki% to filter down all wiki activity or any other module you wish)
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID
,m.name ,count(cm.id) as counter
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5
AND ctx.instanceid = c.id
) AS Students
, ( SELECT count(id) FROM prefix_log WHERE `module` LIKE '%blog%' AND course = c.id AND action NOT LIKE '%view%' ) as BlogActivity
FROM `prefix_course_modules` as cm JOIN prefix_modules as m ON cm.module=m.id JOIN prefix_course as c ON cm.course = c.id
WHERE m.name LIKE '%blog%' AND c.category IN ( 8,13,15)
GROUP BY cm.course,cm.module order by counter desc
</code>


===Student's posts content in all course blogs (oublog)===
Including (optional) filter by: year, semester and course id.
<code sql>
 
SELECT  
<syntaxhighlight lang="SQL">
b.name
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS CourseID
,op.title
, c.id
,op.message
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
,( SELECT CONCAT(u.firstname, ' ',u.lastname) FROM prefix_user AS u WHERE u.id = oi.userid) AS "Username"
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher


FROM prefix_oublog_posts AS op
, (CASE
JOIN prefix_oublog_instances AS oi ON oi.id = op.oubloginstancesid
WHEN c.fullname LIKE '%תשעב%' THEN '2012'
JOIN prefix_oublog as b ON b.id = oi.oublogid
WHEN c.fullname LIKE '%תשעא%' THEN '2011'
JOIN prefix_course AS c ON b.course = c.id
END ) as Year
, (CASE
WHEN c.fullname LIKE '%סמסטר א%' THEN 'Semester A'
WHEN c.fullname LIKE '%סמסטר ב%' THEN 'Semester B'
WHEN c.fullname LIKE '%סמסטר ק%' THEN 'Semester C'
END ) as Semester
,COUNT(c.id) AS Total
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 20) AS TABs
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 33) AS BOOKs


WHERE c.id = %%COURSEID%%
FROM `prefix_resource` as r
</code>
JOIN `prefix_course` AS c on c.id = r.course
#WHERE type= 'file' and reference NOT LIKE 'http://%'


===All Courses which uploaded a Syllabus file===
#WHERE 1=1
+ under specific Category
#%%FILTER_YEARS:c.fullname%%
+ show first Teacher in that course
#AND c.fullname LIKE '%2013%'
+ link Course's fullname to actual course
<code sql>
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
,c.shortname,r.name
,(SELECT CONCAT(u.firstname,' ', u.lastname) as Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user as u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) as Teacher
FROM prefix_resource as r
JOIN prefix_course as c ON r.course = c.id
WHERE ( r.name LIKE '%סילבוס%' OR r.name LIKE '%סילאבוס%' OR r.name LIKE '%syllabus%' OR r.name LIKE '%תכנית הקורס%' )
AND c.category IN (10,18,26,13,28)
</code>
===Site-wide completed SCORM activities by Course name===
This report will list all completed attempts for all SCORM activities. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. Please note: the FROM_UNIXTIME command is for MySQL.
<code sql>
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
FROM prefix_scorm_scoes_track AS st
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
WHERE st.value='completed'
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt
</code>
===All users enrolled in a course without a role===
Identifies All users that are enrolled in a course but are not assigned a role.
<code sql>
SELECT
user.firstname AS Firstname,
user.lastname AS Lastname,
user.idnumber Employee_ID,
course.fullname AS Course


FROM prefix_course AS course  
GROUP BY course
JOIN prefix_enrol AS en ON en.courseid = course.id
ORDER BY COUNT(c.id) DESC
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
</syntaxhighlight>
JOIN prefix_user as user ON user.id = ue.userid


WHERE user.id NOT IN (
===Courses that are defined as using GROUPs===
SELECT u.id
<syntaxhighlight lang="SQL">
FROM prefix_course AS c
SELECT concat('<a target="_new" href="%%WWWROOT%%/group/index.php?id=',c.id,'">',c.fullname,'</a>') AS Course
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = c.id) Modules
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
,(SELECT count(*) FROM prefix_groups g WHERE g.courseid = c.id) Groups
JOIN prefix_role AS r ON r.id = ra.roleid
FROM `prefix_course` AS c
JOIN prefix_user AS u ON u.id = ra.userid
WHERE groupmode > 0
WHERE c.id=course.id
</syntaxhighlight>
)
 
ORDER BY Course, Lastname, Firstname
===Courses with Groups===


</code>
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


===List course resources accumulative file size and count===
List of all courses with Groups in them (groupmode > 0). You can also use groupmode=1 to list just Separate type groups or groupmode=2 to list Visible type groups.
This is the main (first) report, which has a link (alias) to a second report (the following on this page) which list each file in the course.
<code sql>
SELECT c.id "CourseID", context.id "ContextID"
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=', c.id, '">', c.fullname ,'</a>') AS "Course Name"
, COUNT(*) "Course Files" , ROUND( SUM( f.filesize ) /1048576 ) AS file_size_MB
,CONCAT('<a target="_new" href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?alias=coursefiles&courseid=1&filter_courses=', c.id, '">List files</a>') AS "List Files"


FROM mdl_files AS f
<syntaxhighlight lang="SQL">
JOIN mdl_context AS context ON context.id = f.contextid
SELECT c.shortname, g.name, c.groupmode
JOIN mdl_course AS c ON c.id = (
FROM prefix_course AS c
  SELECT instanceid
JOIN prefix_groups AS g ON c.id = g.courseid
  FROM mdl_context
WHERE c.groupmode > 0
  WHERE id = SUBSTRING_INDEX( SUBSTRING_INDEX( context.path, '/' , -2 ) , '/', 1 ) )
</syntaxhighlight>
WHERE filesize >0
GROUP BY c.id
</code>


With this report, you will have to define "alias" report property to "coursefiles" for it to be able to be called from the above report.
===Users enrolled in a course with groups but not assigned a group ===
And also setup (add) a FILTER_COURSES filter.
<code sql>
SELECT
id ,CONCAT('<a target="_new" href="%%WWWROOT%%/pluginfile.php/', contextid, '/', component, '/', filearea, '/', itemid, '/', filename, '">', filename,'</a>') AS "File"
,filesize, mimetype ,author, license, timecreated, component, filearea, filepath


FROM mdl_files AS f
Displays by course all enrolled users that have not been assigned a group in courses that have groups. NOTE: This needs to be optimized.
WHERE filesize >0
            AND f.contextid
            IN (  SELECT id
                    FROM mdl_context
                    WHERE path
                    LIKE (  SELECT CONCAT('%/',id,'/%')
                                  AS contextquery
                                FROM mdl_context
                              WHERE 1=1
        %%FILTER_COURSES:instanceid%%
                                AND contextlevel = 50
                          )
                )
</code>


===Which courses has redundant topics===
<syntaxhighlight lang="SQL">
This report list several "active topics" calculations, per course. which should give an administrator some indications for which topics/sections/weeks are filled with resources and activities and which ones are empty and not used (usually, at the end of the course).
SELECT DISTINCT
user2.firstname AS Firstname,
user2.lastname AS Lastname,
user2.email AS Email,
user2.city AS City,
course.fullname AS Course
,(SELECT shortname FROM prefix_role WHERE id=en.roleid) AS ROLE
,(SELECT name FROM prefix_role WHERE id=en.roleid) AS RoleName


The following, second SQL query, could be used to "trim" down those redundant course topics/sections/weeks by updating the course format's numsection (Number of sections) setting. (It's a per course format setting!)
FROM prefix_course AS course  
JOIN prefix_enrol AS en ON en.courseid = course.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
JOIN prefix_user AS user2 ON ue.userid = user2.id
JOIN prefix_groups AS g ON g.courseid = course.id


<code sql>
WHERE ue.enrolid NOT IN (select userid from prefix_groups_members WHERE g.id=groupid)
SELECT id, format,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">', c.fullname,'</a>') AS Course


,(SELECT value  FROM  `mdl_course_format_options` WHERE  `courseid` = c.id AND `format` = c.format AND `name` = 'numsections' ) AS "numsections"
ORDER BY Course, Lastname
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND `sequence` !=  '' ) AS "Non empty sections count"
</syntaxhighlight>
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id ) AS "Total section count"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND sequence IS NOT NULL) AS "Non NULL sections count"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND name != '') AS "Non empty section Name count"
,(SELECT COUNT(*) FROM mdl_course_modules cm WHERE cm.course = c.id) "Modules count"


FROM mdl_course AS c
===Groups in course with member list===
</code>


The following SQL REPLACE query is used for "fixing" (updating) the "numsections" of a specific course format "onetopics" (you can always change it, or discard it to use this SQL REPLACE on all course formats)
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
<code sql>
REPLACE INTO `mdl_course_format_options` (`id`, `courseid`, `format`, `sectionid`, `name`, `value`)
SELECT NULL, c.id, 'onetopic', '0', 'numsections', (SELECT COUNT(*) FROM `mdl_course_sections` WHERE `course` = c.id AND name != '')
FROM `mdl_course` c where format = 'onetopic'
</code>


===Hidden Courses with Students Enrolled===
List the groups in a course (replace the # by the course id number) with the members of each group.
Contributed by Eric Strom


This query identifies courses with student enrollment that are currently hidden from students. Includes the defined course start date, count of students and instructors, and a clickable email link of instructor (first found record if more than one).
<syntaxhighlight lang="SQL">
SELECT c.shortname, g.name AS Groupname, u.username
FROM prefix_course AS c
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_groups_members AS m ON g.id = m.groupid
JOIN prefix_user AS u ON m.userid = u.id
WHERE c.id = #
</syntaxhighlight>


<code sql>
Note: if you are using Configurable Reports block and want to perform this query on the current course you are in, then you can use a WHERE clause like this:
SELECT c.visible AS Visible,
<syntaxhighlight lang="SQL">
DATE(FROM_UNIXTIME(c.startdate)) AS StartDate,  
WHERE c.id = %%COURSEID%%
concat('<a target="_new" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',
</syntaxhighlight>
c.id,'">',c.idnumber,'</a>') AS Course_ID,


(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
===Group Export===
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students,


(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Instructors,


(SELECT DISTINCT concat('<a href="mailto:',u.email,'">',u.email,'</a>')
There's a [[Import_groups|group import]] function, but no export. Use this to give you a report with the proper column order and headings to export to a csv file you can then import into another course to replicate the groups. This is a simple version with just the main fields: groupname, description, enrolment key.
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS 'Instructor_Email',


now() AS Report_Timestamp
<syntaxhighlight lang="SQL">
SELECT g.name AS groupname, g.description, g.enrolmentkey
FROM prefix_groups AS g
JOIN prefix_course as c ON g.courseid = c.id
WHERE c.id = #
</syntaxhighlight>
Note: if you are using Configurable Reports block and want to perform this query on the current course you are in, then you can use a WHERE clause like this:
<syntaxhighlight lang="SQL">
WHERE c.id = %%COURSEID%%
</syntaxhighlight>


FROM prefix_course AS c
===List all Courses in and below a certain category===
WHERE c.visible = 0 AND (SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id WHERE ra.roleid = 5 AND ctx.instanceid = c.id) > 0
Use this SQL code to retrieve all courses that exist in or under a set category.
ORDER BY StartDate, Instructor_Email, Course_ID
</code>


$s should be the id of the category you want to know about...
<syntaxhighlight lang="SQL">
SELECT prefix_course. * , prefix_course_categories. *
FROM prefix_course, prefix_course_categories
WHERE prefix_course.category = prefix_course_categories.id
AND (
prefix_course_categories.path LIKE '%/$s/%'
OR prefix_course_categories.path LIKE '%/$s'
)
</syntaxhighlight>


==Course Design Reports==
===List all Categories in one level below a certain category===
Use this PHP code to retrieve a list of all categories below a certain category.


These are reports which summarize course design aspects, such as activity and resource modules per section, types of activities used, etc.
$s should be the id of the top level category you are interested in.
<syntaxhighlight lang="php">
<?php


===Course Content/Week===
require_once('./config.php');
Contributed by Elizabeth Dalton, Granite State College


This report assumes that the first 14 sections in a course, not including the "0" or "Welcome" section, correspond to weeks (with "Subsections" given numbers much higher in the sequence). Of those sections, each is checked to count the number of:
$parent_id = $s;


    Forums
$categories= array();
    Graded Activities (may include Forums)
    Resources (not including a Label)


Totals of each of these types of content elements per section are provided.
$categories = get_categories($parent_id);


'''Note''': Only visible resources and activities are counted.
echo '<ol>';
'''Note''': this is a "Global" report.
foreach ($categories as $category)
        {
        echo '<li><a href="'.$CFG->wwwroot.'/course/category.php?id='.$category->id.'">'.$category->name.'</a></li>';
        }
echo '</ol>';


<code sql>
?>
SELECT
</syntaxhighlight>
cs.section AS 'Week'
, cs.name AS 'Section Name'


, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT LIKE 'label'),cm.id,NULL)) AS 'Ungraded Resources'
===Blog activity per Course (not including VIEW)===
Filter activity logging to some specific Course Categories!
+ link course name to actual course (for quick reference)
(you can change %blog% to %wiki% to filter down all wiki activity or any other module you wish)
<syntaxhighlight lang="SQL">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID
,m.name ,count(cm.id) as counter
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5
AND ctx.instanceid = c.id
) AS Students
, ( SELECT count(id) FROM prefix_log WHERE `module` LIKE '%blog%' AND course = c.id AND action NOT LIKE '%view%' ) as BlogActivity
FROM `prefix_course_modules` as cm JOIN prefix_modules as m ON cm.module=m.id JOIN prefix_course as c ON cm.course = c.id  
WHERE m.name LIKE '%blog%' AND c.category IN ( 8,13,15)
GROUP BY cm.course,cm.module order by counter desc
</syntaxhighlight>


, COUNT(DISTINCT IF(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'
===Student's posts content in all course blogs (oublog)===
<syntaxhighlight lang="SQL">
SELECT
b.name
,op.title
,op.message
,( SELECT CONCAT(u.firstname, ' ',u.lastname) FROM prefix_user AS u WHERE u.id = oi.userid) AS "Username"


, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Graded Activities'
FROM prefix_oublog_posts AS op
JOIN prefix_oublog_instances AS oi ON oi.id = op.oubloginstancesid
JOIN prefix_oublog as b ON b.id = oi.oublogid
JOIN prefix_course AS c ON b.course = c.id


FROM prefix_course AS c
WHERE c.id = %%COURSEID%%
JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section <= 14 AND cs.section > 0
</syntaxhighlight>
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
JOIN prefix_modules AS m ON m.id = cm.module
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.itemmodule = m.name AND gi.iteminstance = cm.instance


WHERE
===All Courses which uploaded a Syllabus file===
cs.visible = 1
+ under specific Category
AND cm.visible = 1
+ show first Teacher in that course
AND c.id = %%COURSEID%%
+ link Course's fullname to actual course
<syntaxhighlight lang="SQL">
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
,c.shortname,r.name
,(SELECT CONCAT(u.firstname,' ', u.lastname) as Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user as u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) as Teacher
FROM prefix_resource as r
JOIN prefix_course as c ON r.course = c.id
WHERE ( r.name LIKE '%סילבוס%' OR r.name LIKE '%סילאבוס%' OR r.name LIKE '%syllabus%' OR r.name LIKE '%תכנית הקורס%' )
AND c.category IN (10,18,26,13,28)
</syntaxhighlight>
===Site-wide completed SCORM activities by Course name===
This report will list all completed attempts for all SCORM activities. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. Please note: the FROM_UNIXTIME command is for MySQL.
<syntaxhighlight lang="SQL">
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
FROM prefix_scorm_scoes_track AS st
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
WHERE st.value='completed'
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt
</syntaxhighlight>
===All users enrolled in a course without a role===
Identifies All users that are enrolled in a course but are not assigned a role.
<syntaxhighlight lang="SQL">
SELECT
user.firstname AS Firstname,
user.lastname AS Lastname,
user.idnumber Employee_ID,
course.fullname AS Course


GROUP BY cs.section
FROM prefix_course AS course
ORDER BY cs.section
JOIN prefix_enrol AS en ON en.courseid = course.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
JOIN prefix_user as user ON user.id = ue.userid


</code>
WHERE user.id NOT IN (
 
SELECT u.id
===Assignments and Weights===
FROM prefix_course AS c
Contributed by Elizabeth Dalton, Granite State College
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_role AS r ON r.id = ra.roleid
JOIN prefix_user AS u ON u.id = ra.userid
WHERE c.id=course.id
)
ORDER BY Course, Lastname, Firstname


Returns a list of grade book categories for the current course, grade book weightings, the first type of assignment included in the category, a count of different assignment types for each category, and a count of assignments for each category.
</syntaxhighlight>


Categories with weights of 0 are not included in this report.
===List course resources accumulative file size and count===
This is the main (first) report, which has a link (alias) to a second report (the following on this page) which list each file in the course.
<syntaxhighlight lang="SQL">
SELECT c.id "CourseID", context.id "ContextID"
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=', c.id, '">', c.fullname ,'</a>') AS "Course Name"
, COUNT(*) "Course Files" , ROUND( SUM( f.filesize ) /1048576 ) AS file_size_MB
,CONCAT('<a target="_new" href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?alias=coursefiles&courseid=1&filter_courses=', c.id, '">List files</a>') AS "List Files"


Only visible activities are included in this report.
FROM mdl_files AS f
JOIN mdl_context AS context ON context.id = f.contextid
JOIN mdl_course AS c ON c.id = (
  SELECT instanceid
  FROM mdl_context
  WHERE id = SUBSTRING_INDEX( SUBSTRING_INDEX( context.path, '/' , -2 ) , '/', 1 ) )
WHERE filesize >0
GROUP BY c.id
</syntaxhighlight>


'''Note''': This is designed to be a "Global" report in Configurable Reports.
With this report, you will have to define "alias" report property to "coursefiles" for it to be able to be called from the above report.
<code sql>
And also setup (add) a FILTER_COURSES filter.
SELECT
<syntaxhighlight lang="SQL">
SELECT
id ,CONCAT('<a target="_new" href="%%WWWROOT%%/pluginfile.php/', contextid, '/', component, '/', filearea, '/', itemid, '/', filename, '">', filename,'</a>') AS "File"
,filesize, mimetype ,author, license, timecreated, component, filearea, filepath


IF(gc.parent IS NOT NULL, gc.fullname, 'None') AS 'Grade Book Category'
FROM mdl_files AS f
, IF(gc.parent IS NOT NULL, ROUND(gic.aggregationcoef, 2), ROUND(SUM(DISTINCT gi.aggregationcoef), 2)+ROUND(SUM(DISTINCT mgi.aggregationcoef), 2)) AS 'Category weight'
WHERE filesize >0
 
            AND f.contextid
, CONCAT_WS(', ',GROUP_CONCAT(DISTINCT gi.itemmodule SEPARATOR ', '), IF(mgi.id, 'manual',NULL)) AS 'Activity Types'
            IN (   SELECT id
, COUNT(DISTINCT gi.itemmodule) + IF(mgi.id,1,0) AS 'Different Activity Types'
                    FROM mdl_context
, CONCAT_WS('<br>', GROUP_CONCAT(DISTINCT gi.itemname ORDER BY gi.itemname SEPARATOR '<br>'), GROUP_CONCAT(DISTINCT mgi.itemname ORDER BY mgi.itemname SEPARATOR '<br>')) AS 'Activity Names'
                    WHERE path
, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) + COUNT(DISTINCT mgi.id) AS 'Activity Count'
                    LIKE (   SELECT CONCAT('%/',id,'/%')
                                  AS contextquery
                                FROM mdl_context
                              WHERE 1=1
        %%FILTER_COURSES:instanceid%%
                                AND contextlevel = 50
                          )
                )
</syntaxhighlight>


FROM prefix_course AS c
===Which courses has redundant topics===
This report list several "active topics" calculations, per course. which should give an administrator some indications for which topics/sections/weeks are filled with resources and activities and which ones are empty and not used (usually, at the end of the course).


#get grade categories
The following, second SQL query, could be used to "trim" down those redundant course topics/sections/weeks by updating the course format's numsection (Number of sections) setting. (It's a per course format setting!)
LEFT JOIN prefix_grade_categories AS gc ON gc.courseid = c.id
# back from categories to grade items to get aggregations and weights
JOIN prefix_grade_items AS gic ON gic.courseid = c.id AND gic.itemtype = 'category' AND gic.aggregationcoef != 0 AND (LOCATE(gic.iteminstance, gc.path) OR (gc.parent IS NULL))


# attach activities to course
<syntaxhighlight lang="SQL">
JOIN prefix_course_modules AS cm ON cm.course = c.id  
SELECT id, format,
# attach grade items to activities
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">', c.fullname,'</a>') AS Course
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.iteminstance = cm.instance AND gi.itemtype = 'mod' AND gi.categoryid = gc.id AND gi.hidden != 1


# attach manual grade items to course-- they don't have modules
,(SELECT value  FROM  `mdl_course_format_options` WHERE  `courseid` = c.id AND `format` = c.format AND `name` = 'numsections' ) AS "numsections"
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual' AND mgi.categoryid = gc.id
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND `sequence` !=  '' ) AS "Non empty sections count"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id ) AS "Total section count"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND sequence IS NOT NULL) AS "Non NULL sections count"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND name != '') AS "Non empty section Name count"
,(SELECT COUNT(*) FROM mdl_course_modules cm WHERE cm.course = c.id) "Modules count"


WHERE
FROM mdl_course AS c
cm.visible = 1
</syntaxhighlight>
AND c.id = %%COURSEID%%


GROUP BY gc.id
The following SQL REPLACE query is used for "fixing" (updating) the "numsections" of a specific course format "onetopics" (you can always change it, or discard it to use this SQL REPLACE on all course formats)
ORDER BY gc.id
<syntaxhighlight lang="SQL">
REPLACE INTO `mdl_course_format_options` (`id`, `courseid`, `format`, `sectionid`, `name`, `value`)
SELECT NULL, c.id, 'onetopic', '0', 'numsections', (SELECT COUNT(*) FROM `mdl_course_sections` WHERE `course` = c.id AND name != '')
FROM `mdl_course` c where format = 'onetopic'
</syntaxhighlight>


</code>
===Hidden Courses with Students Enrolled===
Contributed by Eric Strom


===Pre-Term Course Review===
This query identifies courses with student enrollment that are currently hidden from students. Includes the defined course start date, count of students and instructors, and a clickable email link of instructor (first found record if more than one).
Contributed by Elizabeth Dalton, Granite State College


Provides an overview of the readiness of ONLINE, HYBRID, and BLENDED courses in the Staging category and all subcategories. Links to each course are provided. Other details:
<syntaxhighlight lang="SQL">
SELECT c.visible AS Visible,
DATE(FROM_UNIXTIME(c.startdate)) AS StartDate,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',
c.id,'">',c.idnumber,'</a>') AS Course_ID,


#  "Required blocks" include Instructor Block (mooprofile), Activities, and the Research block.
(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
#    "Instructor Details" block is not the "Instructor" block (mooprofile) automatically provided by the system. It is an optional block that can be edited by the instructor. If not edited to remove boilerplate text, it should be hidden.
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
#    All courses should be in the "Collapsed Topics" format with the "Weeks" structure.
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students,
#    "Weeks defined in course settings" is taken from our SIS when the course shells are created, but can be edited by faculty. "# of weeks named and visible" should usually match or exceed this value.
#    We recommend that each week contain at least one forum, at least one graded activity, and at least one ungraded resource.
#    "Syllabus updated" date is for the first attached file found with the text "syllabus" in the name. The "Days ago" calculation is included for convenience.


'''Note''': At our institution, we construct categories each term, and insert a text string "staging" in the Category ID for pre-term courses during the preparation or "staging" phase of course development. We remove this text string (and change it to "production") when courses go live at the start of the new term.
(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Instructors,


<code sql>
(SELECT DISTINCT concat('<a href="mailto:',u.email,'">',u.email,'</a>')
SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS Course
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS 'Instructor_Email',


#,RIGHT(c.idnumber,2) AS Type # Specific to GSC "Instructional Method" storage
now() AS Report_Timestamp


#, substring_index(substr(c.shortname FROM locate('.',c.shortname)+1),'-',1) AS Section # Specific to GSC
FROM prefix_course AS c  
WHERE c.visible = 0 AND (SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id WHERE ra.roleid = 5 AND ctx.instanceid = c.id) > 0
,(SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/user/view.php',CHAR(63),'id=',u.id,'">',u.lastname,', ', u.firstname,'</a>')
ORDER BY StartDate, Instructor_Email, Course_ID
FROM prefix_role_assignments AS ra
</syntaxhighlight>
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Instructor'


,(SELECT IF((u2.description IS NULL) OR (u2.description LIKE ''),'NO', 'YES')
=== Course formats used on my system ===
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u2 ON u2.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Profile Has Bio'


,(SELECT IF(u3.picture > 0,'YES','NO')
<syntaxhighlight lang="SQL">
FROM prefix_role_assignments AS ra
SELECT COUNT(*) 'Count', c.format 'Format'
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
FROM prefix_course AS c
JOIN prefix_user AS u3 ON u3.id = ra.userid
GROUP BY c.format
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Profile Has Picture'
</syntaxhighlight>


, IF(((bpi.visible IS NULL) OR (bpi.visible !=0)) AND ((bpm.visible IS NULL) OR (bpm.visible !=0)) AND ((bpa.visible IS NULL) OR (bpa.visible !=0)) AND ((bpr.visible IS NULL) OR (bpr.visible !=0)),'YES','NO') AS 'Required blocks visible'
=== Course catalogue with future courses  ===
#, IF((bpm.visible IS NULL) OR (bpm.visible !=0),'YES','NO') AS 'Messages block visible'
#, IF((bpa.visible IS NULL) OR (bpa.visible !=0),'YES','NO') AS 'activities block visible'
#, IF((bpr.visible IS NULL) OR (bpr.visible !=0),'YES','NO') AS 'research block visible'


#, IF(SUM(IF(bi.configdata LIKE 'Tzo4OiJzdGRDbGFzcyI6Mzp7czo1OiJ0aXRsZSI7czoxODoiSW5zdHJ1Y3RvciBEZXRhaWxzI%',1,0)) AND (bip.visible !=0),'YES','') AS 'Instructor Details Block visible' # This is a hack based on UUencoded string data from the title of HTML "Instructor Details" block
<syntaxhighlight lang="SQL">
SELECT CONCAT('<a href="%%WWWROOT%%/course/info.php?id=',course.id,'">',course.fullname,'</a>') AS Kurs, FROM_UNIXTIME(startdate, '%Y/%m/%d') AS Beginn
FROM prefix_course AS course
WHERE DATEDIFF(NOW(),FROM_UNIXTIME(startdate)) < 0
ORDER BY startdate
</syntaxhighlight>


#, IF(bi.configdata LIKE '%ZGl0IHRoaXMgYmxvY2s%','NO','') AS 'Instructor Details Block Updated' # HTML block has string 'dit this block'
==Course Design Reports==


#, IF(COUNT(bi.id) -  SUM(IF(bi.configdata LIKE 'Tzo4OiJzdGRDbGFzcyI6Mzp7czo1OiJ0aXRsZSI7czoxODoiSW5zdHJ1Y3RvciBEZXRhaWxzI%',1,0)),'YES','') AS 'possible extra instructor blocks' #looking for any HTML block with "instructor" in the title
These are reports which summarize course design aspects, such as activity and resource modules per section, types of activities used, etc.


, IF(c.format='topcoll','YES', c.format) AS 'Collapsed Topics course format' # change this if you want to test for a different format
===Course Content/Week===
, IF(cfo.value = 2, 'YES','NO') AS 'weeks structure'
Contributed by Elizabeth Dalton, Granite State College


, cfw.value AS 'weeks defined in course settings'
This report assumes that the first 14 sections in a course, not including the "0" or "Welcome" section, correspond to weeks (with "Subsections" given numbers much higher in the sequence). Of those sections, each is checked to count the number of:


, COUNT(DISTINCT IF(((cs.name IS NOT NULL) AND (cs.visible = 1) AND (cs.section != '0') AND (cs.sequence IS NOT NULL)),cs.id,NULL)) AS '# of weeks named & visible (includes orphans)'
    Forums
    Graded Activities (may include Forums)
    Resources (not including a Label)


, COUNT(DISTINCT IF(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'
Totals of each of these types of content elements per section are provided.
, COUNT(DISTINCT IF(m.name LIKE 'forum' ,cs.id , NULL)) AS 'Weeks with Forum'


, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Activities'
'''Note''': Only visible resources and activities are counted.
, COUNT(DISTINCT IF(gi.id, cs.id, NULL)) AS 'Weeks with Activities'
'''Note''': this is a "Global" report. Run it within a course to see a summary of the contents of that course.
, COUNT(DISTINCT mgi.id) AS 'Manual Grade Items'


, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT IN ('forum','label')),cm.id,NULL)) AS 'Resources'
<syntaxhighlight lang="SQL">
, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT IN ('forum','label')), cs.id, NULL)) AS 'Weeks with Resources'
SELECT
 
# Here are some other things you could check for per course
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%forum%') AS Forums
   
   
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%quiz%') AS Quizzes
cs.section AS 'Week'
, cs.name AS 'Section Name'
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%assign%') AS Assignments


#,(SELECT COUNT(prefix_resource.id) FROM prefix_resource JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course) AS Files
, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT LIKE 'label'),cm.id,NULL)) AS 'Ungraded Resources'


#,(SELECT COUNT(prefix_url.id) FROM prefix_url JOIN prefix_course ON prefix_course.id = prefix_url.course WHERE c.id = prefix_url.course) AS Links
, COUNT(DISTINCT IF(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'


,(SELECT FROM_UNIXTIME(MAX(prefix_resource.timemodified))
, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Graded Activities'
FROM prefix_resource
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS SyllabusDate


,(SELECT TO_DAYS(NOW())-TO_DAYS(FROM_UNIXTIME(MAX(prefix_resource.timemodified)))
FROM prefix_course AS c
FROM prefix_resource
JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section <= 14 AND cs.section > 0
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS DaysAgo
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
JOIN prefix_modules AS m ON m.id = cm.module
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.itemmodule = m.name AND gi.iteminstance = cm.instance


, IF(COUNT(DISTINCT IF(f.type LIKE 'news', f.id,NULL)),'YES','NO' ) AS 'Announcement Forum Visible'
WHERE
cs.visible = 1
AND cm.visible = 1
AND c.id = %%COURSEID%%


, IF(COUNT(DISTINCT IF(f.type LIKE 'news', fd.id,NULL)),'YES','NO' ) AS 'Announcement posted'
GROUP BY cs.section
ORDER BY cs.section


FROM prefix_course AS c
</syntaxhighlight>
LEFT JOIN prefix_course_categories as cc ON c.category = cc.id
LEFT JOIN prefix_context AS ctxx ON c.id = ctxx.instanceid


LEFT JOIN prefix_block_positions AS bpi ON bpi.contextid = ctxx.id AND bpi.blockinstanceid = '43692' # mooprofile
===Assignments and Weights===
LEFT JOIN prefix_block_positions AS bpm ON bpm.contextid = ctxx.id AND bpm.blockinstanceid = '43962' # messages
Contributed by Elizabeth Dalton, Granite State College
LEFT JOIN prefix_block_positions AS bpa ON bpa.contextid = ctxx.id AND bpa.blockinstanceid = '43963' # activities
LEFT JOIN prefix_block_positions AS bpr ON bpr.contextid = ctxx.id AND bpr.blockinstanceid = '38368' # html research help


LEFT JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.visible = 1 AND cs.sequence IS NOT NULL
Returns a list of grade book categories for the current course, grade book weightings, the first type of assignment included in the category, a count of different assignment types for each category, and a count of assignments for each category.
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
LEFT JOIN prefix_modules AS m ON m.id = cm.module
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.itemmodule = m.name AND gi.iteminstance = cm.instance


LEFT JOIN prefix_forum AS f ON f.course = c.id AND cm.instance = f.id AND cm.visible = 1
Categories with weights of 0 are not included in this report.
LEFT JOIN prefix_forum_discussions AS fd ON fd.forum = f.id


# attach manual grade items to course-- they don't have modules
Only visible activities are included in this report.
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual'


LEFT JOIN prefix_course_format_options AS cfo ON cfo.courseid = c.id AND cfo.name = 'layoutstructure'
'''Note''': This is designed to be a "Global" report in Configurable Reports.
LEFT JOIN prefix_course_format_options AS cfw ON cfw.courseid = c.id AND cfw.name = 'numsections'
<syntaxhighlight lang="SQL">
SELECT


LEFT JOIN prefix_block_instances AS bi ON bi.parentcontextid = ctxx.id AND bi.blockname = 'html' AND (bi.configdata LIKE '%SW5zdHJ1Y3Rvc%' or bi.configdata LIKE '%bnN0cnVjdG9y%')
IF(gc.parent IS NOT NULL, gc.fullname, 'None') AS 'Grade Book Category'
LEFT JOIN prefix_block_positions AS bip ON bip.blockinstanceid = bi.id
, IF(gc.parent IS NOT NULL, ROUND(gic.aggregationcoef, 2), ROUND(SUM(DISTINCT gi.aggregationcoef), 2)+ROUND(SUM(DISTINCT mgi.aggregationcoef), 2)) AS 'Category weight'


WHERE RIGHT(c.idnumber,2) IN ('OL', 'BL', 'HY')
, CONCAT_WS(', ',GROUP_CONCAT(DISTINCT gi.itemmodule SEPARATOR ', '), IF(mgi.id, 'manual',NULL)) AS 'Activity Types'
# AND substring(cc.path,2,2) IN ('26') # Staging
, COUNT(DISTINCT gi.itemmodule) + IF(mgi.id,1,0) AS 'Different Activity Types'
#AND substring(cc.path,2,3) IN ('158') # UG
, CONCAT_WS('<br>', GROUP_CONCAT(DISTINCT gi.itemname ORDER BY gi.itemname SEPARATOR '<br>'), GROUP_CONCAT(DISTINCT mgi.itemname ORDER BY mgi.itemname SEPARATOR '<br>')) AS 'Activity Names'
AND cc.idnumber LIKE '%staging%'
, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) + COUNT(DISTINCT mgi.id) AS 'Activity Count'
AND ctxx.contextlevel = 50


GROUP BY c.shortname
FROM prefix_course AS c
</code>


==Module instances + Module HITs by role teacher and student in course==
#get grade categories
<code sql>
LEFT JOIN prefix_grade_categories AS gc ON gc.courseid = c.id
SELECT
# back from categories to grade items to get aggregations and weights
m.name AS "Module name"
JOIN prefix_grade_items AS gic ON gic.courseid = c.id AND gic.itemtype = 'category' AND gic.aggregationcoef != 0 AND (LOCATE(gic.iteminstance, gc.path) OR (gc.parent IS NULL))
, COUNT(*) AS "Module count"


,(SELECT COUNT(*)
# attach activities to course
FROM prefix_log AS l
JOIN prefix_course_modules AS cm ON cm.course = c.id
WHERE l.course = cm.course AND l.module = m.name ) AS "Hits"
# attach grade items to activities
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.iteminstance = cm.instance AND gi.itemtype = 'mod' AND gi.categoryid = gc.id AND gi.hidden != 1


,(SELECT COUNT(*)
# attach manual grade items to course-- they don't have modules
FROM prefix_log AS l
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual' AND mgi.categoryid = gc.id
JOIN prefix_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN prefix_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 5
WHERE l.course = cm.course AND l.module = m.name) AS "Students HITs"


,(SELECT COUNT(*)
WHERE
FROM prefix_log AS l
cm.visible = 1
JOIN prefix_context AS con ON con.instanceid= l.course AND con.contextlevel=50
AND c.id = %%COURSEID%%
JOIN prefix_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3
WHERE l.course = cm.course AND l.module = m.name) AS "Teachers HITs"


FROM mdl_course_modules AS cm
GROUP BY gc.id
JOIN mdl_modules AS m on m.id = cm.module
ORDER BY gc.id
WHERE cm.course = '%%COURSEID%%'
GROUP BY cm.module
</code>


==Grade and Course Completion Reports==
</syntaxhighlight>
===Site-Wide Grade Report with All Items===
Shows grades for all course items along with course totals for each student. Works with ad-hoc reports or Configurable Reports
<code sql>
SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name',
c.fullname AS 'Course',
cc.name AS 'Category',


CASE
===Pre-Term Course Review===
  WHEN gi.itemtype = 'course'
Contributed by Elizabeth Dalton, Granite State College
  THEN c.fullname + ' Course Total'
  ELSE gi.itemname
END AS 'Item Name',


ROUND(gg.finalgrade,2) AS Grade,
Provides an overview of the readiness of ONLINE, HYBRID, and BLENDED courses in the Staging category and all subcategories. Links to each course are provided. Other details:
DATEADD(ss,gi.timemodified,'1970-01-01') AS Time


FROM prefix_course AS c
#  "Required blocks" include Instructor Block (mooprofile), Activities, and the Research block.
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
#    "Instructor Details" block is not the "Instructor" block (mooprofile) automatically provided by the system. It is an optional block that can be edited by the instructor. If not edited to remove boilerplate text, it should be hidden.
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
#    All courses should be in the "Collapsed Topics" format with the "Weeks" structure.
JOIN prefix_user AS u ON u.id = ra.userid
#    "Weeks defined in course settings" is taken from our SIS when the course shells are created, but can be edited by faculty. "# of weeks named and visible" should usually match or exceed this value.
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
#    We recommend that each week contain at least one forum, at least one graded activity, and at least one ungraded resource.
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
#    "Syllabus updated" date is for the first attached file found with the text "syllabus" in the name. The "Days ago" calculation is included for convenience.
JOIN prefix_course_categories as cc ON cc.id = c.category


WHERE  gi.courseid = c.id
'''Note''': At our institution, we construct categories each term, and insert a text string "staging" in the Category ID for pre-term courses during the preparation or "staging" phase of course development. We remove this text string (and change it to "production") when courses go live at the start of the new term.
ORDER BY lastname
</code>
For MySQL users, you'll need to use the MySQL DATE_ADD function instead of DATEADD. Replace the line
<code>
DATEADD(ss,gi.timemodified,'1970-01-01') AS Time
</code>
with
<code>
DATE_ADD('1970-01-01', INTERVAL gi.timemodified SECOND) AS Time
</code>


===Site-Wide Grade Report with Just Course Totals===
<syntaxhighlight lang="SQL">
A second site-wide grade report for all students that just shows course totals. Works with ad-hoc reports or Configurable Reports
SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS Course
<code sql>
SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name',  
cc.name AS 'Category',
CASE
  WHEN gi.itemtype = 'course'
  THEN c.fullname + ' Course Total'
  ELSE gi.itemname
END AS 'Item Name',


ROUND(gg.finalgrade,2) AS Grade,
#,RIGHT(c.idnumber,2) AS Type # Specific to GSC "Instructional Method" storage
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time


FROM prefix_course AS c
#, substring_index(substr(c.shortname FROM locate('.',c.shortname)+1),'-',1) AS Section # Specific to GSC
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
,(SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/user/view.php',CHAR(63),'id=',u.id,'">',u.lastname,', ', u.firstname,'</a>')
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Instructor'
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
 
JOIN prefix_course_categories as cc ON cc.id = c.category
,(SELECT IF((u2.description IS NULL) OR (u2.description LIKE ''),'NO', 'YES')
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u2 ON u2.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Profile Has Bio'


WHERE  gi.courseid = c.id AND gi.itemtype = 'course'
,(SELECT IF(u3.picture > 0,'YES','NO')
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u3 ON u3.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Profile Has Picture'


ORDER BY lastname
, IF(((bpi.visible IS NULL) OR (bpi.visible !=0)) AND ((bpm.visible IS NULL) OR (bpm.visible !=0)) AND ((bpa.visible IS NULL) OR (bpa.visible !=0)) AND ((bpr.visible IS NULL) OR (bpr.visible !=0)),'YES','NO') AS 'Required blocks visible'
</code>
#, IF((bpm.visible IS NULL) OR (bpm.visible !=0),'YES','NO') AS 'Messages block visible'
#, IF((bpa.visible IS NULL) OR (bpa.visible !=0),'YES','NO') AS 'activities block visible'
#, IF((bpr.visible IS NULL) OR (bpr.visible !=0),'YES','NO') AS 'research block visible'


For MySQL users:
#, IF(SUM(IF(bi.configdata LIKE 'Tzo4OiJzdGRDbGFzcyI6Mzp7czo1OiJ0aXRsZSI7czoxODoiSW5zdHJ1Y3RvciBEZXRhaWxzI%',1,0)) AND (bip.visible !=0),'YES','') AS 'Instructor Details Block visible' # This is a hack based on UUencoded string data from the title of HTML "Instructor Details" block
<code sql>
SELECT u.firstname AS 'First' , u.lastname AS 'Last', CONCAT(u.firstname , ' ' , u.lastname) AS 'Display Name',
c.fullname AS 'Course',
cc.name AS 'Category',
CASE
  WHEN gi.itemtype = 'course'  
  THEN CONCAT(c.fullname, ' - Total')
  ELSE gi.itemname
END AS 'Item Name',


ROUND(gg.finalgrade,2) AS Grade,
#, IF(bi.configdata LIKE '%ZGl0IHRoaXMgYmxvY2s%','NO','') AS 'Instructor Details Block Updated' # HTML block has string 'dit this block'
FROM_UNIXTIME(gg.timemodified) AS TIME
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE  gi.courseid = c.id
ORDER BY lastname
</code>


===Learner report by Learner with grades===
#, IF(COUNT(bi.id) -  SUM(IF(bi.configdata LIKE 'Tzo4OiJzdGRDbGFzcyI6Mzp7czo1OiJ0aXRsZSI7czoxODoiSW5zdHJ1Y3RvciBEZXRhaWxzI%',1,0)),'YES','') AS 'possible extra instructor blocks' #looking for any HTML block with "instructor" in the title
Which Learners in which course and what are the grades
<code sql>
SELECT u.firstname AS 'Name' , u.lastname AS 'Surname', c.fullname AS 'Course', cc.name AS 'Category',  
CASE WHEN gi.itemtype = 'Course'  
THEN c.fullname + ' Course Total' 
ELSE gi.itemname
END AS 'Item Name', ROUND(gg.finalgrade,2) AS Score,ROUND(gg.rawgrademax,2) AS Max, ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) as Percentage,


if (ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) > 79,'Yes' , 'No') as Pass
, IF(c.format='topcoll','YES', c.format) AS 'Collapsed Topics course format' # change this if you want to test for a different format
, IF(cfo.value = 2, 'YES','NO') AS 'weeks structure'


FROM prefix_course AS c
, cfw.value AS 'weeks defined in course settings'
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE  gi.courseid = c.id and gi.itemname != 'Attendance'
ORDER BY `Name` ASC
</code>


===User Course Completion===
, COUNT(DISTINCT IF(((cs.name IS NOT NULL) AND (cs.visible = 1) AND (cs.section != '0') AND (cs.sequence IS NOT NULL)),cs.id,NULL)) AS '# of weeks named & visible (includes orphans)'


A very simple report with list of course completion status by username. Completions are noted by date, blank otherwise.  
, COUNT(DISTINCT IF(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'
, COUNT(DISTINCT IF(m.name LIKE 'forum' ,cs.id , NULL)) AS 'Weeks with Forum'


<code sql>
, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Activities'
SELECT u.username, c.shortname,
, COUNT(DISTINCT IF(gi.id, cs.id, NULL)) AS 'Weeks with Activities'
DATE_FORMAT(FROM_UNIXTIME(p.timecompleted
, COUNT(DISTINCT mgi.id) AS 'Manual Grade Items'
),'%Y-%m-%d')  
 
AS completed
, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT IN ('forum','label')),cm.id,NULL)) AS 'Resources'
FROM prefix_course_completions AS p
, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT IN ('forum','label')), cs.id, NULL)) AS 'Weeks with Resources'
JOIN prefix_course AS c ON p.course = c.id
 
JOIN prefix_user AS u ON p.userid = u.id
# Here are some other things you could check for per course
WHERE c.enablecompletion = 1
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%forum%') AS Forums
ORDER BY u.username
</code>
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%quiz%') AS Quizzes
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%assign%') AS Assignments
 
#,(SELECT COUNT(prefix_resource.id) FROM prefix_resource JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course) AS Files
 
#,(SELECT COUNT(prefix_url.id) FROM prefix_url JOIN prefix_course ON prefix_course.id = prefix_url.course WHERE c.id = prefix_url.course) AS Links


===User Course Completion with Criteria===
,(SELECT FROM_UNIXTIME(MAX(prefix_resource.timemodified))
FROM prefix_resource
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS SyllabusDate


A report with course completions by username, with Aggregation method, Criteria types, and Criteria detail where available.
,(SELECT TO_DAYS(NOW())-TO_DAYS(FROM_UNIXTIME(MAX(prefix_resource.timemodified)))
FROM prefix_resource
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS DaysAgo


<code sql>
, IF(COUNT(DISTINCT IF(f.type LIKE 'news', f.id,NULL)),'YES','NO' ) AS 'Announcement Forum Visible'
SELECT u.username AS user,  
 
c.shortname AS course,
, IF(COUNT(DISTINCT IF(f.type LIKE 'news', fd.id,NULL)),'YES','NO' ) AS 'Announcement posted'
DATE_FORMAT(FROM_UNIXTIME(t.timecompleted),'%Y-%m-%d') AS completed,
CASE
WHEN (SELECT a.method FROM prefix_course_completion_aggr_methd AS a  WHERE (a.course = c.id AND a.criteriatype IS NULL) = 1) THEN "Any"
ELSE "All"
END AS aggregation,
CASE
WHEN p.criteriatype = 1 THEN "Self"
WHEN p.criteriatype = 2 THEN "By Date"
WHEN p.criteriatype = 3 THEN "Unenrol Status"
WHEN p.criteriatype = 4 THEN "Activity"
WHEN p.criteriatype = 5 THEN "Duration"
WHEN p.criteriatype = 6 THEN "Course Grade"
WHEN p.criteriatype = 7 THEN "Approve by Role"
WHEN p.criteriatype = 8 THEN "Previous Course"
END AS criteriatype,
CASE
WHEN p.criteriatype = 1 THEN "*"
WHEN p.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(p.timeend),'%Y-%m-%d')
WHEN p.criteriatype = 3 THEN t.unenroled
WHEN p.criteriatype = 4 THEN
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',p.module,'/view.php?id=',p.moduleinstance,'">',p.module,'</a>')
WHEN p.criteriatype = 5 THEN p.enrolperiod
WHEN p.criteriatype = 6 THEN CONCAT('Needed: ',ROUND(p.gradepass,2),' Achieved: ',ROUND(t.gradefinal,2))
WHEN p.criteriatype = 7 THEN p.role
WHEN p.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = p.courseinstance)
END AS criteriadetail
FROM prefix_course_completion_crit_compl AS t
JOIN prefix_user AS u ON t.userid = u.id
JOIN prefix_course AS c ON t.course = c.id
JOIN prefix_course_completion_criteria AS p ON t.criteriaid = p.id


</code>
FROM prefix_course AS c
LEFT JOIN prefix_course_categories as cc ON c.category = cc.id
LEFT JOIN prefix_context AS ctxx ON c.id = ctxx.instanceid


===Courses with Completion Enabled and their settings===
LEFT JOIN prefix_block_positions AS bpi ON bpi.contextid = ctxx.id AND bpi.blockinstanceid = '43692' # mooprofile
LEFT JOIN prefix_block_positions AS bpm ON bpm.contextid = ctxx.id AND bpm.blockinstanceid = '43962' # messages
LEFT JOIN prefix_block_positions AS bpa ON bpa.contextid = ctxx.id AND bpa.blockinstanceid = '43963' # activities
LEFT JOIN prefix_block_positions AS bpr ON bpr.contextid = ctxx.id AND bpr.blockinstanceid = '38368' # html research help


List of all courses with completion enabled and their Aggregation setting, Criteria types, and Criteria details.
LEFT JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.visible = 1 AND cs.sequence IS NOT NULL
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
LEFT JOIN prefix_modules AS m ON m.id = cm.module
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.itemmodule = m.name AND gi.iteminstance = cm.instance


<code sql>
LEFT JOIN prefix_forum AS f ON f.course = c.id AND cm.instance = f.id AND cm.visible = 1
LEFT JOIN prefix_forum_discussions AS fd ON fd.forum = f.id


SELECT c.shortname AS Course,
# attach manual grade items to course-- they don't have modules
CASE
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual'
WHEN (SELECT a.method FROM prefix_course_completion_aggr_methd AS a  WHERE (a.course = t.course AND a.criteriatype IS NULL)) = 2 THEN "All"
ELSE "Any"
END AS Course_Aggregation,
CASE
WHEN t.criteriatype = 1 THEN "Self completion"
WHEN t.criteriatype = 2 THEN "Date done by"
WHEN t.criteriatype = 3 THEN "Unenrolement"
WHEN t.criteriatype = 4 THEN "Activity completion" 
WHEN t.criteriatype = 5 THEN "Duration in days"
WHEN t.criteriatype = 6 THEN "Final grade"   
WHEN t.criteriatype = 7 THEN "Approve by role"
WHEN t.criteriatype = 8 THEN "Previous course"
END AS Criteria_type,
CASE
WHEN t.criteriatype = 1 THEN "On"
WHEN t.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(t.timeend),'%Y-%m-%d')
WHEN t.criteriatype = 3 THEN "On"
WHEN t.criteriatype = 4 THEN
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',t.module,'/view.php?id=',t.moduleinstance,'">',t.module,'</a>')
WHEN t.criteriatype = 5 THEN ROUND(t.enrolperiod/86400)
WHEN t.criteriatype = 6 THEN ROUND(t.gradepass,2)
WHEN t.criteriatype = 7 THEN (SELECT r.shortname FROM prefix_role AS r WHERE r.id = t.role)
WHEN t.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = t.courseinstance)
END AS Criteria_detail
FROM prefix_course_completion_criteria as t
JOIN prefix_course AS c ON t.course = c.id
WHERE c.enablecompletion = 1
ORDER BY course
</code>


===Course Completion Report with custom dates===
LEFT JOIN prefix_course_format_options AS cfo ON cfo.courseid = c.id AND cfo.name = 'layoutstructure'
LEFT JOIN prefix_course_format_options AS cfw ON cfw.courseid = c.id AND cfw.name = 'numsections'


List of users who completed multiple or single course/s from a start date to end date chosen by the user. The output gives username, name, course name, completion date and score
LEFT JOIN prefix_block_instances AS bi ON bi.parentcontextid = ctxx.id AND bi.blockname = 'html' AND (bi.configdata LIKE '%SW5zdHJ1Y3Rvc%' or bi.configdata LIKE '%bnN0cnVjdG9y%')
LEFT JOIN prefix_block_positions AS bip ON bip.blockinstanceid = bi.id


<code sql>
WHERE RIGHT(c.idnumber,2) IN ('OL', 'BL', 'HY')
# AND substring(cc.path,2,2) IN ('26') # Staging
#AND substring(cc.path,2,3) IN ('158') # UG
AND cc.idnumber LIKE '%staging%'
AND ctxx.contextlevel = 50


SELECT u.username AS 'User Name',
GROUP BY c.shortname
CONCAT(u.firstname , ' ' , u.lastname) AS 'Name',
</syntaxhighlight>
c.shortname AS 'Course Name',
DATE_FORMAT(FROM_UNIXTIME(p.timecompleted),'%W %e %M, %Y') AS 'Completed Date',
ROUND(c4.gradefinal,2) AS 'Score'
FROM prefix_course_completions AS p
JOIN prefix_course AS c ON p.course = c.id
JOIN prefix_user AS u ON p.userid = u.id
JOIN prefix_course_completion_crit_compl AS c4 ON u.id = c4.userid
WHERE c.enablecompletion = 1  AND (p.timecompleted IS NOT NULL OR p.timecompleted !='')
AND (p.timecompleted>= :start_date AND p.timecompleted<=:end_date)
GROUP BY u.username
ORDER BY c.shortname


</code>
===Module instances + Module HITs by role teacher and student in course===
<syntaxhighlight lang="SQL">
SELECT
m.name AS "Module name"
, COUNT(*) AS "Module count"


===Scales used in activities===
,(SELECT COUNT(*)  
<code sql>
FROM prefix_log AS l
SELECT scale.name
WHERE l.course = cm.course AND l.module = m.name ) AS "Hits"
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',gi.itemmodule,'/view.php?id=',cm.id,'">',gi.itemname,'</a>') AS "Module View"
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/modedit.php?up','date=',cm.id,'">',gi.itemname,'</a>') AS "Module Settings"


FROM prefix_grade_items AS gi
,(SELECT COUNT(*)
JOIN prefix_course AS c ON c.id = gi.courseid
FROM prefix_log AS l
JOIN prefix_course_modules AS cm ON cm.course = gi.courseid AND cm.instance = gi.iteminstance
JOIN prefix_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN prefix_scale AS scale ON scale.id = gi.scaleid
JOIN prefix_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 5
WHERE gi.scaleid IS NOT NULL
WHERE l.course = cm.course AND l.module = m.name) AS "Students HITs"
</code>


,(SELECT COUNT(*)
FROM prefix_log AS l
JOIN prefix_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN prefix_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3
WHERE l.course = cm.course AND l.module = m.name) AS "Teachers HITs"


===Extra Credit Items by Name Only===
FROM mdl_course_modules AS cm
Contributed by Eric Strom
JOIN mdl_modules AS m on m.id = cm.module
WHERE cm.course = '%%COURSEID%%'
GROUP BY cm.module
</syntaxhighlight>
 
===Course Syllabus===
Contributed by Elizabeth Dalton, Granite State College / Moodle HQ
 
This report requires ELIS. It runs from within a course and constructs a course syllabus based on content in the course and in the ELIS entries related to the course (Class Instance, Course Description, and Program). It is a proof-of-concept of an automated syllabus production tool. Fields such as "Course Policies" and "Teaching Philosophy" are added to the Class Instance records, and instructors enter them there. The Instructor Bio is pulled from the User Profile of all users with the Teacher role in the course.


This query identifies grade items in visible courses with student enrollment that have "extra credit" in the name of the item but set as extra credit in the grade settings. Includes the defined course start date, count of students and instructors, and a clickable email link of instructor (first found record if more than one).
<syntaxhighlight lang="SQL">
SELECT


<code sql>
c.fullname AS 'fullname'
SELECT DATE(FROM_UNIXTIME(c.startdate)) AS StartDate,  
, ec.idnumber AS 'elis-id'
concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php',CHAR(63),'id=',
, DATE_FORMAT(FROM_UNIXTIME(ec.startdate), '%b %e, %Y') AS 'start'
c.id,'">',c.idnumber,'</a>') AS Course_ID, gi.itemname AS Item_Name
, DATE_FORMAT(FROM_UNIXTIME(ec.enddate), '%b %e, %Y') AS 'end'
, ecd.name AS 'longname'
, ecd.code AS 'coursecode'
, ecd.credits AS 'coursecredits'
, ecd.syllabus AS 'description'


,(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
, (SELECT eft.data
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
FROM prefix_local_eliscore_fld_data_text AS eft
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'learning-outcomes'
WHERE ctxecd.id = eft.contextid) AS 'outcomes'


,(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
,(SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/user/view.php',CHAR(63),'id=',u.id,'">',u.firstname,' ', u.lastname,'</a> ', u.email)
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Instructors
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Instructor'


,(SELECT DISTINCT concat('<a href="mailto:',u.email,'">',u.email,'</a>')
, (SELECT efc.data
  FROM prefix_role_assignments AS ra
FROM prefix_local_eliscore_fld_data_char AS efc
  JOIN prefix_user AS u ON ra.userid = u.id
JOIN prefix_local_eliscore_field AS ef ON ef.id = efc.fieldid AND ef.shortname = 'term-code'
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
WHERE ctxci.id = efc.contextid) AS 'termcode'
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS 'Instructor_Email'


,now() AS Report_Timestamp
, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'prerequisites'
WHERE ctxecd.id = eft.contextid) AS 'prerequisites'


FROM prefix_grade_items AS gi
, (SELECT  eft.data
JOIN prefix_course AS c ON gi.courseid = c.id
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'textbooks'
WHERE ctxci.id = eft.contextid) AS 'textbooks'


WHERE gi.itemname LIKE '%extra credit%'
, (SELECT eft.data
AND gi.gradetype = '1'
FROM prefix_local_eliscore_fld_data_text AS eft
AND gi.hidden = '0'
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'other-class-materials'
AND gi.aggregationcoef = '0'
WHERE ctxci.id = eft.contextid) AS 'other-class-materials'
AND c.visible = 1
AND (SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id WHERE ra.roleid = 5 AND ctx.instanceid = c.id) > 0


GROUP BY Course_ID, gi.id
, (SELECT  eft.data
ORDER BY StartDate, Course_ID
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'course-policies'
%%FILTER_SEARCHTEXT:Course_ID:~%%
WHERE ctxci.id = eft.contextid) AS 'course-policies'
</code>


===Site Wide Number of Courses Completed by User===
, (SELECT  eft.data
Contributed by Ken St. John
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'teaching-philosophy'
WHERE ctxci.id = eft.contextid) AS 'teaching-philosophy'


Simple report that shows the number of completed courses for all users site wide
, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'course-methods'
WHERE ctxci.id = eft.contextid) AS 'course-methods'
 
,(SELECT u2.description
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u2 ON u2.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Bio'


<code sql>
,(SELECT
SELECT u.lastname, u.firstname,
COUNT(p.timecompleted) AS TotalCompletions
FROM prefix_course_completions AS p
JOIN prefix_user AS u ON p.userid = u.id
GROUP BY p.userid
ORDER BY u.lastname
</code>


==Activity Module Reports==
GROUP_CONCAT(DISTINCT CONCAT(


===How many SCORM activities are used in each Course===
'<tr><td style="border: solid #000 .5px">',IF(gc.parent IS NOT NULL, gc.fullname, 'None')
<code sql>
, ' </td><td style="border: solid #000 .5px"> '
SELECT cm.course,c.fullname ,m.name
,IF(gc.parent IS NOT NULL, ROUND(gic.aggregationcoef, 2), ROUND( gi.aggregationcoef, 2)+ROUND(mgi.aggregationcoef, 2))
,concat('<a target="_new" href="%%WWWROOT%%/mod/scorm/index.php?id=',c.id,'">',count(cm.id),'</a>') AS Counter
FROM `prefix_course_modules` as cm
  JOIN prefix_modules as m ON cm.module=m.id
  JOIN prefix_course as c ON cm.course = c.id
WHERE m.name LIKE '%scorm%'
GROUP BY cm.course,cm.module
ORDER BY count(cm.id) desc
</code>


===SCORM Usage by Course Start Date===
) SEPARATOR '</td></tr>')
Contributed by Elizabeth Dalton, Granite State College
#get grade categories
FROM prefix_grade_categories AS gc
# back from categories to grade items to get aggregations and weights
LEFT JOIN prefix_grade_items AS gic ON gic.courseid = gc.courseid AND gic.itemtype = 'category' AND gic.aggregationcoef != 0 AND (LOCATE(gic.iteminstance, gc.path) OR (gc.parent IS NULL))
# attach grade items to activities
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = gc.courseid  AND gi.itemtype = 'mod' AND gi.categoryid = gc.id AND gi.hidden != 1
# attach manual grade items to course-- they don't have modules
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = gc.courseid and mgi.itemtype = 'manual' AND mgi.categoryid = gc.id
WHERE gc.courseid = c.id  ) AS 'grade categories'


Report of number of inclusions of SCORM activities in courses, filtered by course start date.
, '<table width = "50%" >' AS 'table start'
, '<table width = "100%" >' AS 'table start 2'
, '</table>' AS 'table end'


<code sql>
, (SELECT  eft.data
SELECT
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'activities-schedule'
WHERE ctxci.id = eft.contextid) AS 'activities'


CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'course'


, cc.name AS 'Category'
, (SELECT  eft.data
, scm.name AS 'Sample Activity Name'
FROM prefix_local_eliscore_fld_data_text AS eft
, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'schedule'
, COUNT(DISTINCT cm.id) AS 'Resources Used'
WHERE ctxci.id = eft.contextid) AS 'schedule'
#, FROM_UNIXTIME(cm.added) AS 'resource added'


, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'grading-scale'
WHERE ctxepm.id = eft.contextid) AS 'gradescale'


FROM prefix_course_modules AS cm
FROM
JOIN prefix_modules AS m ON cm.module = m.id AND m.name LIKE 'SCO%'
prefix_course AS c


JOIN prefix_course AS c ON c.id = cm.course
# connect moodle course to ELIS class instance
JOIN prefix_course_categories AS cc ON cc.id = c.category
LEFT JOIN prefix_local_elisprogram_cls_mdl AS ecm ON ecm.moodlecourseid = c.id
JOIN prefix_scorm AS scm ON scm.id = cm.instance
LEFT JOIN prefix_local_elisprogram_cls AS ec ON ec.id = ecm.classid
# class instance context
LEFT JOIN prefix_context AS ctxci ON ctxci.instanceid = ec.id AND ctxci.contextlevel = '14'
 
# connect ELIS class instance to ELIS course description
LEFT JOIN prefix_local_elisprogram_crs AS ecd ON ecd.id = ec.courseid
# course description context
LEFT JOIN prefix_context AS ctxecd ON ctxecd.instanceid = ecd.id AND ctxecd.contextlevel = '13'
 
#connect ELIS program to ELIS Course Description
LEFT JOIN prefix_local_elisprogram_pgm_crs AS epc ON epc.courseid = ecd.id
LEFT JOIN prefix_local_elisprogram_pgm AS epm ON epm.id = epc.curriculumid
# course program context
LEFT JOIN prefix_context AS ctxepm ON ctxepm.instanceid = epm.id AND ctxepm.contextlevel = '11'


WHERE
WHERE
1


%%FILTER_STARTTIME:c.startdate:>%%
c.id = %%COURSEID%%
%%FILTER_ENDTIME:c.startdate:<%%
</syntaxhighlight>


GROUP BY c.shortname, m.name
===Course Activities Helper===
ORDER BY c.startdate, c.shortname
Contributed by Elizabeth Dalton, Granite State College
</code>


=== LTI (External Tool) Usage by Course Start Date===
This report provides a list of the graded activities in a course.
Contributed by Elizabeth Dalton, Granite State College
* '''Note''': Only graded activities are displayed.
* '''Note''': This is a "Global" report. Run it within a course to see a summary of the contents of that course.
* '''Note''': This report assumes that course sections each last one week.


Report of number of inclusions of  LTI (External Tool) Usage activities in courses, filtered by course start date.
<syntaxhighlight lang="SQL">
# 303 Course Activities Helper


<code sql>
SELECT  
SELECT  


CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'course'
gi.itemmodule AS 'activity type'
# cs.section AS 'section number'
 
# Calculation assumes each section lasts one week
, CONCAT(DATE_FORMAT(FROM_UNIXTIME(c.startdate + (7*24*60*60* (cs.section-1))), '%b %e, %Y'),' - <br>',DATE_FORMAT(FROM_UNIXTIME(c.startdate + (7*24*60*60* (cs.section))), '%b %e, %Y')) AS 'Date'


, cc.name AS 'Category'
, gi.itemname AS 'activity name'
, lti.name AS 'Sample Activity Name'
, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
, COUNT(DISTINCT cm.id) AS 'Resources Used'
#, FROM_UNIXTIME(cm.added) AS 'resource added'


#, (SELECT asg.intro FROM prefix_assign AS asg WHERE asg.id = cm.instance) AS 'intro'


FROM prefix_course_modules AS cm
#, (SELECT f.intro FROM prefix_forum AS f WHERE f.id = cm.instance) AS 'f intro'
JOIN prefix_modules AS m ON cm.module = m.id AND m.name LIKE 'lti'


JOIN prefix_course AS c ON c.id = cm.course
, CASE gi.itemmodule
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHEN 'assign' THEN (SELECT asg.intro FROM prefix_assign AS asg WHERE asg.id = gi.iteminstance)
JOIN prefix_lti AS lti ON lti.id = cm.instance
WHEN 'forum' THEN (SELECT f.intro FROM prefix_forum AS f WHERE f.id = gi.iteminstance)
WHERE
WHEN 'quiz' THEN (SELECT q.intro FROM prefix_quiz AS q WHERE q.id = gi.iteminstance)
1
END AS 'test case'


%%FILTER_STARTTIME:c.startdate:>%%
#, (SELECT GROUP_CONCAT(CONCAT(' - ',gi.itemname) SEPARATOR '<BR>') FROM  prefix_grade_items AS gi  JOIN prefix_course_modules AS cm ON  gi.iteminstance = cm.instance WHERE gi.gradetype = 1 AND gi.hidden != 1 AND gi.courseid = c.id AND cm.course = c.id AND cm.section = cs.id ) AS 'activities'
%%FILTER_ENDTIME:c.startdate:<%%


GROUP BY c.shortname, m.name
ORDER BY c.startdate, c.shortname
</code>


===Detailed ACTIONs for each MODULE===
FROM
<code sql>
prefix_course AS c
SELECT module,action,count(id) as counter
FROM prefix_log
GROUP BY module,action
ORDER BY module,counter desc
</code>


===Most popular ACTIVITY===
#get grade sections
<code sql>
LEFT JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section > 0 AND cs.section <=14
SELECT COUNT(l.id) hits, module
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
FROM prefix_log l
WHERE module != 'login' AND module != 'course' AND module != 'role'
GROUP BY module
ORDER BY hits DESC
</code>


===System wide use of ACTIVITIES and RESOURCES===
#LEFT JOIN prefix_assign AS asg ON asg.id = cm.instance
<code sql>
SELECT count( cm.id ) AS counter, m.name
FROM `prefix_course_modules` AS cm
JOIN prefix_modules AS m ON cm.module = m.id
GROUP BY cm.module
ORDER BY counter DESC
</code>


===LOG file ACTIONS per MODULE per COURSE (IDs)===
JOIN prefix_grade_items AS gi  ON  gi.iteminstance = cm.instance AND gi.gradetype = 1 AND gi.hidden != 1 AND gi.courseid = c.id AND cm.course = c.id AND cm.section = cs.id
<code sql>
select course,module,action,count(action) as summa from prefix_log
where action <> 'new'
group by course,action,module
order by course,module,action
</code>


===System Wide usage count of various course Activities===
WHERE
(Tested and works fine in Moodle 2.x)
c.id = %%COURSEID%%
Like: Forum, Wiki, Blog, Assignment, Database,
AND cs.visible = 1
#Within specific category
#Teacher name in course


<code sql>
ORDER BY gi.itemmodule, cs.section
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
</syntaxhighlight>


,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
==Grade and Course Completion Reports==
FROM prefix_role_assignments AS ra
===Site-Wide Grade Report with All Items===
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
Shows grades for all course items along with course totals for each student. Works with ad-hoc reports or Configurable Reports
JOIN prefix_user AS u ON u.id = ra.userid
<syntaxhighlight lang="SQL">
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
SELECT u.firstname AS 'First' , u.lastname AS 'Last',
u.firstname + ' ' + u.lastname AS 'Display Name',
c.fullname AS 'Course',
cc.name AS 'Category',


,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
CASE
JOIN prefix_modules AS m ON cm.module = m.id
  WHEN gi.itemtype = 'course'
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
  THEN c.fullname + ' Course Total'
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
  ELSE gi.itemname
JOIN prefix_modules AS m ON cm.module = m.id
END AS 'Item Name',
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs


,(SELECT count( m.name ) AS count FROM
ROUND(gg.finalgrade,2) AS Grade,
prefix_course_modules AS cm
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%forum%') AS Forums
 
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%data%') AS Databses
 
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%assignment%') AS Assignments
 
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students


FROM prefix_course AS c
FROM prefix_course AS c
WHERE c.category IN ( 18)
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
ORDER BY Wikis DESC,Blogs DESC, Forums DESC
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
</code>
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories as cc ON cc.id = c.category


===Course wiki usage/activity over the last 6 semesters===
WHERE  gi.courseid = c.id
<code sql>
ORDER BY lastname
SELECT "Courses with Wikis"
</syntaxhighlight>
For MySQL users, you'll need to use the MySQL DATE_ADD function instead of DATEADD. Replace the line:
<syntaxhighlight lang="sql">
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
</syntaxhighlight>
with:
<syntaxhighlight lang="sql">
FROM_UNIXTIME(gg.timemodified) AS Time
</syntaxhighlight>
And:
<syntaxhighlight lang="sql">
u.firstname + ' ' + u.lastname AS 'Display Name',
</syntaxhighlight>
with:
<syntaxhighlight lang="sql">
CONCAT(u.firstname,' ',u.lastname) AS 'Display Name',
</syntaxhighlight>


,(SELECT count( m.name ) AS count FROM
===Site-Wide Grade Report with Just Course Totals===
prefix_course_modules AS cm
A second site-wide grade report for all students that just shows course totals. Works with ad-hoc reports or Configurable Reports
JOIN prefix_modules AS m ON cm.module = m.id
<syntaxhighlight lang="SQL">
JOIN prefix_course AS c ON c.id = cm.course
SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name',  
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
cc.name AS 'Category',
and c.fullname LIKE CONCAT('%','2010','%') and c.fullname LIKE '%Semester A%') AS '2010 <br/> Semester A'
CASE
  WHEN gi.itemtype = 'course'  
  THEN c.fullname + ' Course Total'
  ELSE gi.itemname
END AS 'Item Name',


,(SELECT count( m.name ) AS count FROM
ROUND(gg.finalgrade,2) AS Grade,
prefix_course_modules AS cm
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
and c.fullname LIKE CONCAT('%','2010','%') and c.fullname LIKE '%Semester B%') AS '2010 <br/> Semester B'


,(SELECT count( m.name ) AS count FROM
FROM prefix_course AS c
prefix_course_modules AS cm
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = cm.course
JOIN prefix_user AS u ON u.id = ra.userid
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
and c.fullname LIKE CONCAT('%','תשעא','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעא <br/> סמסטר א'
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories as cc ON cc.id = c.category


,(SELECT count( m.name ) AS count FROM
WHERE gi.courseid = c.id AND gi.itemtype = 'course'
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
and c.fullname LIKE CONCAT('%','תשעא','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעא <br/> סמסטר ב'


,(SELECT count( m.name ) AS count FROM
ORDER BY lastname
prefix_course_modules AS cm
</syntaxhighlight>
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
and c.fullname LIKE CONCAT('%','תשעב','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעב <br/> סמסטר א'


,(SELECT count( m.name ) AS count FROM
For MySQL users:
prefix_course_modules AS cm
<syntaxhighlight lang="SQL">
JOIN prefix_modules AS m ON cm.module = m.id
SELECT u.firstname AS 'First' , u.lastname AS 'Last', CONCAT(u.firstname , ' ' , u.lastname) AS 'Display Name',
JOIN prefix_course AS c ON c.id = cm.course
c.fullname AS 'Course',  
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
cc.name AS 'Category',
and c.fullname LIKE CONCAT('%','תשעב','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעב <br/> סמסטר ב'
CASE
  WHEN gi.itemtype = 'course'  
  THEN CONCAT(c.fullname, ' - Total')
  ELSE gi.itemname
END AS 'Item Name',


,(SELECT count( m.name ) AS count FROM  
ROUND(gg.finalgrade,2) AS Grade,
prefix_course_modules AS cm
FROM_UNIXTIME(gg.timemodified) AS TIME
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
FROM prefix_course AS c
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
  and c.fullname LIKE CONCAT('%','תשעג','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעג <br/> סמסטר א'
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE gi.courseid = c.id AND gi.itemtype = 'course'
ORDER BY lastname
</syntaxhighlight>


,(SELECT count( m.name ) AS count FROM
===Learner report by Learner with grades===
prefix_course_modules AS cm
Which Learners in which course and what are the grades
JOIN prefix_modules AS m ON cm.module = m.id
<syntaxhighlight lang="SQL">
JOIN prefix_course AS c ON c.id = cm.course
SELECT u.firstname AS 'Name' , u.lastname AS 'Surname', c.fullname AS 'Course', cc.name AS 'Category',  
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
CASE WHEN gi.itemtype = 'Course'  
and c.fullname LIKE CONCAT('%','תשעג','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעג <br/> סמסטר ב'
THEN c.fullname + ' Course Total'
</code>
ELSE gi.itemname
END AS 'Item Name', ROUND(gg.finalgrade,2) AS Score,ROUND(gg.rawgrademax,2) AS Max, ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) as Percentage,


===Detailed WIKI activity (per wiki per course)===
if (ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) > 79,'Yes' , 'No') as Pass
Including Number of Students in course (for reference)
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID 
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id ) AS Students
,m.name
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%updat%' ) as 'UPDAT E'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%annotate%' ) as ANNOTATE
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%comment%' ) as COMMENT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%add%' ) as 'A DD'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%edit%' ) as EDIT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action NOT LIKE '%view%' ) as 'All (NO View)'
FROM `prefix_course_modules` as cm
JOIN prefix_modules as m ON cm.module=m.id
JOIN prefix_course as c ON cm.course = c.id
WHERE m.name LIKE '%wiki%'
GROUP BY cm.course,cm.module
ORDER BY 'All (NO View)' DESC
</code>


===Wiki usage, system wide===
FROM prefix_course AS c
(you can filter the output by selecting some specific course categories : "WHERE c.category IN ( 8,13,15)")
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
 
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
<code sql>
JOIN prefix_user AS u ON u.id = ra.userid
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category  
WHERE  gi.courseid = c.id and gi.itemname != 'Attendance'
ORDER BY `Name` ASC
</syntaxhighlight>


,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
===User Course Completion===
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis


,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%') AS 'WikiActivity<br/>ALL'
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%add%' ) AS 'WikiActivity<br/>ADD'
A very simple report with a list of course completion status by username. Completions are noted by date, blank otherwise.  


,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%edit%' ) AS 'WikiActivity<br/>EDIT'
<syntaxhighlight lang="SQL">
SELECT
  u.username,  
  c.shortname, 
DATE_FORMAT(FROM_UNIXTIME(p.timecompleted),'%Y-%m-%d') AS completed
FROM prefix_course_completions AS p
JOIN prefix_course AS c ON p.course = c.id
JOIN prefix_user AS u ON p.userid = u.id
WHERE c.enablecompletion = 1
ORDER BY u.username
</syntaxhighlight>


,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%annotate%' ) AS 'WikiActivity<br/>ANNOTATE'
===User Course Completion with Criteria===


,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%comments%' ) AS 'WikiActivity<br/>Comments'
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
A report with course completions by username, with Aggregation method, Criteria types, and Criteria detail where available.
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students


,(SELECT count(*) FROM prefix_ouwiki_pages as ouwp
<syntaxhighlight lang="SQL">
JOIN prefix_ouwiki as ouw ON ouw.id = ouwp.subwikiid
SELECT u.username AS user,
WHERE ouw.course = c.id GROUP BY ouw.course  ) as OUWikiPages
c.shortname AS course,
 
DATE_FORMAT(FROM_UNIXTIME(t.timecompleted),'%Y-%m-%d') AS completed,
,(SELECT count( DISTINCT nwp.pagename ) FROM prefix_wiki_pages AS nwp
CASE
JOIN prefix_wiki AS nw ON nw.id = nwp.dfwiki WHERE nw.course = c.id ) As NWikiPages
WHEN (SELECT a.method FROM prefix_course_completion_aggr_methd AS a  WHERE (a.course = c.id AND a.criteriatype IS NULL) = 1) THEN "Any"
 
ELSE "All"
FROM prefix_course AS c
END AS aggregation,
WHERE c.category IN ( 8,13,15)
CASE
HAVING Wikis > 0
WHEN p.criteriatype = 1 THEN "Self"
ORDER BY 'WikiActivity<br/>ALL' DESC
WHEN p.criteriatype = 2 THEN "By Date"
</code>
WHEN p.criteriatype = 3 THEN "Unenrol Status"
WHEN p.criteriatype = 4 THEN "Activity"
WHEN p.criteriatype = 5 THEN "Duration"
WHEN p.criteriatype = 6 THEN "Course Grade"
WHEN p.criteriatype = 7 THEN "Approve by Role"
WHEN p.criteriatype = 8 THEN "Previous Course"
END AS criteriatype,
CASE
WHEN p.criteriatype = 1 THEN "*"
WHEN p.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(p.timeend),'%Y-%m-%d')
WHEN p.criteriatype = 3 THEN t.unenroled
WHEN p.criteriatype = 4 THEN
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',p.module,'/view.php?id=',p.moduleinstance,'">',p.module,'</a>')
WHEN p.criteriatype = 5 THEN p.enrolperiod
WHEN p.criteriatype = 6 THEN CONCAT('Needed: ',ROUND(p.gradepass,2),' Achieved: ',ROUND(t.gradefinal,2))
WHEN p.criteriatype = 7 THEN p.role
WHEN p.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = p.courseinstance)
END AS criteriadetail
FROM prefix_course_completion_crit_compl AS t
JOIN prefix_user AS u ON t.userid = u.id
JOIN prefix_course AS c ON t.course = c.id
JOIN prefix_course_completion_criteria AS p ON t.criteriaid = p.id
 
</syntaxhighlight>
 
===Courses with Completion Enabled and their settings===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
List of all courses with completion enabled and their Aggregation setting, Criteria types, and Criteria details.


===Aggregated Teacher activity by "WEB2" Modules===
<syntaxhighlight lang="SQL">
(Tested and works fine in Moodle 2.x)
The NV column shows activity without VIEW log activity
<code sql>
SELECT ra.userid, u.firstname,u.lastname
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%') AS Wiki
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%' AND l.action NOT LIKE '%view%') AS Wiki_NV
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%') AS Forum
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%' AND l.action NOT LIKE '%view%') AS Forum_NV
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%') AS Blog
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%' AND l.action NOT LIKE '%view%') AS Blog_NV
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%') AS Assignment
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%' AND l.action NOT LIKE '%view%') AS Assignment_NV
FROM prefix_role_assignments AS ra
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3
GROUP BY ra.userid
</code>


===List all the certificates issued, sort by variables in the custom profile fields===
SELECT c.shortname AS Course,  
Note: The SQL queries look intimidating at first, but isn't really that difficult to learn. I've seen in the forums that users wanted to do 'site-wide' groups in 1.9x. This is sort of the idea. It pulls all the certificates issued to all users sorted by the custom profile fields, which in my case is the Units or Depts (i.e. my site wide groups). Why certificates? I've explored with both grades and quizzes, the course admins are not really interested in the actual grades but whether the learner received a certificate (i.e. passed the course with x, y, z activities). It also saves me from creating groups and assigning them into the right groups. Even assigning in bulk is not efficient, since I have upward of 25 groups per course and constantly new learners enrolling in courses. The limitation is something to do with the server? as it only pull 5000 rows of data. If anyone figured out how to change this, please let me know. In the meantime, the work around is to pull only a few units/depts at a time to limit the number of rows. This is fine at the moment, since each course admin are only responsible for certain units/depts.
CASE
 
WHEN (SELECT a.method FROM prefix_course_completion_aggr_methd AS a  WHERE (a.course = t.course AND a.criteriatype IS NULL)) = 2 THEN "All"
<code sql>
ELSE "Any"
SELECT
END AS Course_Aggregation,
DATE_FORMAT( FROM_UNIXTIME(prefix_certificate_issues.timecreated), '%Y-%m-%d' ) AS Date,
CASE
prefix_certificate_issues.classname AS Topic,
WHEN t.criteriatype = 1 THEN "Self completion"
prefix_certificate.name AS Certificate,
WHEN t.criteriatype = 2 THEN "Date done by"
prefix_certificate_issues.studentname as Name,
WHEN t.criteriatype = 3 THEN "Unenrolement"
prefix_user_info_data.data AS Units
WHEN t.criteriatype = 4 THEN "Activity completion" 
 
WHEN t.criteriatype = 5 THEN "Duration in days"
FROM
WHEN t.criteriatype = 6 THEN "Final grade"   
prefix_certificate_issues
WHEN t.criteriatype = 7 THEN "Approve by role"
 
WHEN t.criteriatype = 8 THEN "Previous course"
INNER JOIN prefix_user_info_data
END AS Criteria_type,
on prefix_certificate_issues.userid = prefix_user_info_data.userid
CASE
WHEN t.criteriatype = 1 THEN "On"
WHEN t.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(t.timeend),'%Y-%m-%d')
WHEN t.criteriatype = 3 THEN "On"
WHEN t.criteriatype = 4 THEN
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',t.module,'/view.php?id=',t.moduleinstance,'">',t.module,'</a>')
WHEN t.criteriatype = 5 THEN ROUND(t.enrolperiod/86400)
WHEN t.criteriatype = 6 THEN ROUND(t.gradepass,2)
WHEN t.criteriatype = 7 THEN (SELECT r.shortname FROM prefix_role AS r WHERE r.id = t.role)
WHEN t.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = t.courseinstance)
END AS Criteria_detail
FROM prefix_course_completion_criteria as t
JOIN prefix_course AS c ON t.course = c.id
WHERE c.enablecompletion = 1
ORDER BY course
</syntaxhighlight>
 
===Course Completion Report with custom dates===


INNER JOIN prefix_certificate
List of users who completed multiple or single course/s from a start date to end date chosen by the user. The output gives username, name, course name, completion date and score
on prefix_certificate_issues.certificateid = prefix_certificate.id


WHERE prefix_user_info_data.data='Unit 1'
<syntaxhighlight lang="SQL">
OR prefix_user_info_data.data='Unit 2'
OR prefix_user_info_data.data='Unit 3'


ORDER BY Units, Name, Topic ASC
SELECT u.username AS 'User Name',
</code>
CONCAT(u.firstname , ' ' , u.lastname) AS 'Name',
c.shortname AS 'Course Name',  
DATE_FORMAT(FROM_UNIXTIME(p.timecompleted),'%W %e %M, %Y') AS 'Completed Date',
ROUND(c4.gradefinal,2) AS 'Score'
FROM prefix_course_completions AS p
JOIN prefix_course AS c ON p.course = c.id
JOIN prefix_user AS u ON p.userid = u.id
JOIN prefix_course_completion_crit_compl AS c4 ON u.id = c4.userid
WHERE c.enablecompletion = 1  AND (p.timecompleted IS NOT NULL OR p.timecompleted !='')
AND (p.timecompleted>= :start_date AND p.timecompleted<=:end_date)
GROUP BY u.username
ORDER BY c.shortname


===Counter Blog usage in Courses,system wide===
</syntaxhighlight>
What teachers in what courses, uses blogs and how many + student count in that course.
<code sql>


SELECT ( @counter := @counter+1) as counter,  
===Scales used in activities===
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
<syntaxhighlight lang="SQL">
SELECT scale.name
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',gi.itemmodule,'/view.php?id=',cm.id,'">',gi.itemname,'</a>') AS "Module View"
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/modedit.php?up','date=',cm.id,'">',gi.itemname,'</a>') AS "Module Settings"
 
FROM prefix_grade_items AS gi
JOIN prefix_course AS c ON c.id = gi.courseid
JOIN prefix_course_modules AS cm ON cm.course = gi.courseid AND cm.instance = gi.iteminstance
JOIN prefix_scale AS scale ON scale.id = gi.scaleid
WHERE gi.scaleid IS NOT NULL
</syntaxhighlight>
 
 
===Extra Credit Items by Name Only===
Contributed by Eric Strom


,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
This query identifies grade items in visible courses with student enrollment that have "extra credit" in the name of the item but set as extra credit in the grade settings. Includes the defined course start date, count of students and instructors, and a clickable email link of instructor (first found record if more than one).
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher


,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
<syntaxhighlight lang="SQL">
JOIN prefix_modules AS m ON cm.module = m.id
SELECT DATE(FROM_UNIXTIME(c.startdate)) AS StartDate,
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs
concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php',CHAR(63),'id=',
c.id,'">',c.idnumber,'</a>') AS Course_ID, gi.itemname AS Item_Name


,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
,(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students


FROM prefix_course AS c, (SELECT @counter := 0) as s_init
,(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
WHERE c.category IN ( 8,13,15)
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
HAVING Blogs > 0
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Instructors
ORDER BY Blogs DESC
</code>


=== Elluminate (Blackboard Collaborate) - system wide usage===
,(SELECT DISTINCT concat('<a href="mailto:',u.email,'">',u.email,'</a>')
<code sql>
  FROM prefix_role_assignments AS ra
SELECT e.name As Session ,er.recordingsize
  JOIN prefix_user AS u ON ra.userid = u.id
,c.fullname As Course
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
,u.firstname,u.lastname
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS 'Instructor_Email'
,DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%d-%m-%Y') AS dTimeStart
,concat('<a target="_new" href="%%WWWROOT%%/moodle/mod/elluminate/loadrecording.php?id=',er.id,'">Show</a>') AS RecordedSession


FROM prefix_elluminate_recordings AS er
,now() AS Report_Timestamp
JOIN prefix_elluminate AS e ON e.meetingid = er.meetingid
JOIN prefix_course as c ON c.id = e.course
JOIN prefix_user AS u ON u.id = e.creator
ORDER BY er.recordingsize DESC
</code>


FROM prefix_grade_items AS gi
JOIN prefix_course AS c ON gi.courseid = c.id


=== Choice ===
WHERE gi.itemname LIKE '%extra credit%'
AND gi.gradetype = '1'
AND gi.hidden = '0'
AND gi.aggregationcoef = '0'
AND c.visible = 1
AND (SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id WHERE ra.roleid = 5 AND ctx.instanceid = c.id) > 0


Results of the Choice activity. For all courses, shows course shortname, username, the Choice text, and the answer chosen by the user.
GROUP BY Course_ID, gi.id
ORDER BY StartDate, Course_ID
%%FILTER_SEARCHTEXT:Course_ID:~%%
</syntaxhighlight>


<code sql>
===Site Wide Number of Courses Completed by User===
SELECT c.shortname AS course, u.username, h.name as question, o.text AS answer
Contributed by Ken St. John
FROM prefix_choice AS h
JOIN prefix_course AS c ON h.course = c.id
JOIN prefix_choice_answers AS a ON h.id = a.choiceid
JOIN prefix_user AS u ON a.userid = u.id
JOIN prefix_choice_options AS o ON a.optionid = o.id
</code>


=== Assignment type usage in courses ===
Simple report that shows the number of completed courses for all users site wide
<code sql>
SELECT


CONCAT('<a target="_new" href="%%WWWROOT%%/mod/assign/index.php?id=',c.id,'">',c.fullname,'</a>') AS "List assignments"
<syntaxhighlight lang="SQL">
SELECT u.lastname, u.firstname,
COUNT(p.timecompleted) AS TotalCompletions
FROM prefix_course_completions AS p
JOIN prefix_user AS u ON p.userid = u.id
GROUP BY p.userid
ORDER BY u.lastname
</syntaxhighlight>


,(SELECT COUNT(*) FROM prefix_assign WHERE c.id = course) AS Assignments
==Activity Module Reports==


,(SELECT COUNT(*)
=== User activity completions with dates===
FROM prefix_assign_plugin_config AS apc
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'file' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
#GROUP BY apc.plugin
) AS "File Assignments"


,(SELECT COUNT(*)
This report shows the users completion status of activities across all courses. It is intended to be uses with Configurable Reports filters for user, start and end times, and also to be able to search the Module names. It includes the new core H5P module in 3.10. Add any third party activity modules you may have in your site as you need. Also, thanks to Tim Hunt for improvements to this query.  
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'onlinetext' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "Online Assignments"


,(SELECT COUNT(*)
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'pdf' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "PDF Assignments"


,(SELECT COUNT(*)  
<syntaxhighlight lang="SQL">
FROM prefix_assign_plugin_config AS apc
SELECT
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
u.username As 'User',
WHERE iassign.course = c.id AND apc.plugin = 'offline' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
c.shortname AS 'Course',
) AS "Offline Assignments"
m.name AS Activitytype,
CASE
    WHEN m.name = 'assign'  THEN (SELECT name FROM prefix_assign WHERE id = cm.instance)
    WHEN m.name = 'assignment'  THEN (SELECT name FROM prefix_assignment WHERE id = cm.instance)
    WHEN m.name = 'book'  THEN (SELECT name FROM prefix_book WHERE id = cm.instance)
    WHEN m.name = 'chat'  THEN (SELECT name FROM prefix_chat WHERE id = cm.instance)
    WHEN m.name = 'choice'  THEN (SELECT name FROM prefix_choice WHERE id = cm.instance)
    WHEN m.name = 'data'  THEN (SELECT name FROM prefix_data WHERE id = cm.instance)
    WHEN m.name = 'feedback'  THEN (SELECT name FROM prefix_feedback WHERE id = cm.instance)
    WHEN m.name = 'folder'  THEN (SELECT name FROM prefix_folder WHERE id = cm.instance)
    WHEN m.name = 'forum' THEN (SELECT name FROM prefix_forum WHERE id = cm.instance)
    WHEN m.name = 'glossary' THEN (SELECT name FROM prefix_glossary WHERE id = cm.instance)
    WHEN m.name = 'h5pactivity' THEN (SELECT name FROM prefix_h5pactivity WHERE id = cm.instance)
    WHEN m.name = 'imscp' THEN (SELECT name FROM prefix_imscp WHERE id = cm.instance)
    WHEN m.name = 'label'  THEN (SELECT name FROM prefix_label WHERE id = cm.instance)
    WHEN m.name = 'lesson'  THEN (SELECT name FROM prefix_lesson WHERE id = cm.instance)
    WHEN m.name = 'lti'  THEN (SELECT name FROM prefix_lti  WHERE id = cm.instance)
    WHEN m.name = 'page'  THEN (SELECT name FROM prefix_page WHERE id = cm.instance)
    WHEN m.name = 'quiz'  THEN (SELECT name FROM prefix_quiz WHERE id = cm.instance)
    WHEN m.name = 'resource'  THEN (SELECT name FROM prefix_resource WHERE id = cm.instance)
    WHEN m.name = 'scorm'  THEN (SELECT name FROM prefix_scorm WHERE id = cm.instance)
    WHEN m.name = 'survey'  THEN (SELECT name FROM prefix_survey WHERE id = cm.instance)
    WHEN m.name = 'url' THEN (SELECT name FROM prefix_url  WHERE id = cm.instance)
    WHEN m.name = 'wiki' THEN (SELECT name FROM prefix_wiki  WHERE id = cm.instance)
    WHEN m.name = 'workshop' THEN (SELECT name FROM prefix_workshop  WHERE id = cm.instance)
  ELSE "Other activity"
END AS Actvityname,
# cm.section AS Coursesection,
CASE
    WHEN cm.completion = 0 THEN '0 None'
    WHEN cm.completion = 1 THEN '1 Self'
    WHEN cm.completion = 2 THEN '2 Auto'
END AS Activtycompletiontype,
CASE
  WHEN cmc.completionstate = 0 THEN 'In Progress'
  WHEN cmc.completionstate = 1 THEN 'Completed'
  WHEN cmc.completionstate = 2 THEN 'Completed with Pass'
  WHEN cmc.completionstate = 3 THEN 'Completed with Fail'
  ELSE 'Unknown'
END AS 'Progress',
DATE_FORMAT(FROM_UNIXTIME(cmc.timemodified), '%Y-%m-%d %H:%i') AS 'When'
FROM prefix_course_modules_completion cmc
JOIN prefix_user u ON cmc.userid = u.id
JOIN prefix_course_modules cm ON cmc.coursemoduleid = cm.id
JOIN prefix_course c ON cm.course = c.id
JOIN prefix_modules m ON cm.module = m.id
# skip the predefined admin and guest user
WHERE u.id > 2
# config reports filters
%%FILTER_USERS:u.username%%
%%FILTER_SEARCHTEXT:m.name:~%%
%%FILTER_STARTTIME:cmc.timemodified:>%% %%FILTER_ENDTIME:cmc.timemodified:<%%


,(SELECT COUNT(*)
ORDER BY u.username
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'comments' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "Assignments Comments"


FROM prefix_assign AS assign
</syntaxhighlight>
JOIN prefix_course AS c ON c.id = assign.course
 
GROUP BY c.id  
===How many SCORM activities are used in each Course===
</code>
<syntaxhighlight lang="SQL">
SELECT cm.course,c.fullname ,m.name
,concat('<a target="_new" href="%%WWWROOT%%/mod/scorm/index.php?id=',c.id,'">',count(cm.id),'</a>') AS Counter
FROM `prefix_course_modules` as cm
  JOIN prefix_modules as m ON cm.module=m.id
  JOIN prefix_course as c ON cm.course = c.id  
WHERE m.name LIKE '%scorm%'
GROUP BY cm.course,cm.module
ORDER BY count(cm.id) desc
</syntaxhighlight>


==Assignment Module Reports==
===SCORM Usage by Course Start Date===
===All Ungraded Assignments===
Contributed by Elizabeth Dalton, Granite State College
Returns all the submitted assignments that still need grading
<code sql>
select
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment"


from prefix_assignment_submissions as asb
Report of number of inclusions of SCORM activities in courses, filtered by course start date.
join prefix_assignment as a ON a.id = asb.assignment
join prefix_user as u ON u.id = asb.userid
join prefix_course as c ON c.id = a.course
join prefix_course_modules as cm ON c.id = cm.course


where asb.grade < 0 and cm.instance = a.id
<syntaxhighlight lang="SQL">
and cm.module = 1
SELECT


order by c.fullname, a.name, u.lastname
CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'course'
</code>
 
, cc.name AS 'Category'
, scm.name AS 'Sample Activity Name'
, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
, COUNT(DISTINCT cm.id) AS 'Resources Used'
#, FROM_UNIXTIME(cm.added) AS 'resource added'


===All Ungraded Assignments w/ Link===
Returns all the submitted assignments that still need grading, along with a link that goes directly to the submission to grade it. The links work if you view the report within Moodle.
<code sql>
select
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment",


'<a href="http://education.varonis.com/mod/assignment/submissions.php' + char(63) +
FROM prefix_course_modules AS cm
+ 'id=' + cast(cm.id as varchar) + '&userid=' + cast(u.id as varchar)
JOIN prefix_modules AS m ON cm.module = m.id AND m.name LIKE 'SCO%'
+ '&mode=single&filter=0&offset=2">' + a.name + '</a>'
AS "Assignmentlink"


JOIN prefix_course AS c ON c.id = cm.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
JOIN prefix_scorm AS scm ON scm.id = cm.instance


from prefix_assignment_submissions as asb
WHERE
join prefix_assignment as a ON a.id = asb.assignment
1
join prefix_user as u ON u.id = asb.userid
join prefix_course as c ON c.id = a.course
join prefix_course_modules as cm ON c.id = cm.course


where asb.grade < 0 and cm.instance = a.id and cm.module = 1
%%FILTER_STARTTIME:c.startdate:>%%
%%FILTER_ENDTIME:c.startdate:<%%


order by c.fullname, a.name, u.lastname
GROUP BY c.shortname, m.name
</code>
ORDER BY c.startdate, c.shortname
</syntaxhighlight>


===Assignments (and Quizzes) waiting to be graded===
=== LTI (External Tool) Usage by Course Start Date===
This report requires a YEAR filter to be added (Available when using the latest block/configurable_reports)
Contributed by Elizabeth Dalton, Granite State College


Which you can always remove, to make this query work on earlier versions.
Report of number of inclusions of  LTI (External Tool) Usage activities in courses, filtered by course start date.


The report includes:
<syntaxhighlight lang="SQL">
*number of quizzes
SELECT
*unFinished Quiz attempts
*Finished Quiz attempts
*number of students
*number of Assignments
*number of submitted answers by students
*number of unchecked assignments (waiting for the Teacher) in a Course.


<code sql>
CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'course'
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course


,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
, cc.name AS 'Category'
FROM prefix_role_assignments AS ra
, lti.name AS 'Sample Activity Name'
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
JOIN prefix_user AS u ON u.id = ra.userid
, COUNT(DISTINCT cm.id) AS 'Resources Used'
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
#, FROM_UNIXTIME(cm.added) AS 'resource added'
,concat('<a target="_new" href="%%WWWROOT%%/mod/assignment/index.php?id=',c.id,'">מטלות</a>') AS Assignments


,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">בחנים</a>') AS 'Quizzes'


,(SELECT COUNT(*)
FROM prefix_course_modules AS cm
FROM prefix_course_modules cm  
JOIN prefix_modules AS m ON cm.module = m.id AND m.name LIKE 'lti'
JOIN prefix_modules as m ON m.id = cm.module
WHERE m.name LIKE 'quiz' AND cm.course = c.id
GROUP BY cm.course
) AS 'nQuizzes'


,(SELECT COUNT(*)
JOIN prefix_course AS c ON c.id = cm.course
FROM prefix_quiz_attempts AS qa
JOIN prefix_course_categories AS cc ON cc.id = c.category
JOIN prefix_quiz AS q ON q.id = qa.quiz
JOIN prefix_lti AS lti ON lti.id = cm.instance
WHERE q.course = c.id
WHERE
AND qa.timefinish = 0
1
GROUP BY q.course) AS 'unFinished Quiz attempts'


,(SELECT COUNT(*)
%%FILTER_STARTTIME:c.startdate:>%%
FROM prefix_quiz_attempts AS qa
%%FILTER_ENDTIME:c.startdate:<%%
JOIN prefix_quiz AS q ON q.id = qa.quiz
WHERE q.course = c.id
AND qa.timefinish > 0
GROUP BY q.course) AS 'finished quiz attempts'


,(SELECT Count( ra.userid ) AS Users
GROUP BY c.shortname, m.name
FROM prefix_role_assignments AS ra
ORDER BY c.startdate, c.shortname
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
</syntaxhighlight>
WHERE ra.roleid = 5
AND ctx.instanceid = c.id
) AS nStudents


,(
===Detailed ACTIONs for each MODULE===
SELECT count(a.id)
<syntaxhighlight lang="SQL">
FROM prefix_assignment AS a
SELECT module,action,count(id) as counter
JOIN prefix_course_modules AS cm ON a.course = cm.course
FROM prefix_log
WHERE cm.instance = a.id AND cm.module = 1 AND a.course = c.id
GROUP BY module,action
) nAssignments
ORDER BY module,counter desc
</syntaxhighlight>


,(
===Most popular ACTIVITY===
SELECT count(*)
<syntaxhighlight lang="SQL">
FROM prefix_assignment AS a
SELECT COUNT(l.id) hits, module
WHERE a.course = c.id AND FROM_UNIXTIME(a.timedue) > NOW()
FROM prefix_log l
GROUP BY a.course
WHERE module != 'login' AND module != 'course' AND module != 'role'
) 'Open <br/>Assignments'
GROUP BY module
ORDER BY hits DESC
</syntaxhighlight>


, CONCAT(ROUND( (100 / iAssignments ) * iOpenAssignments ) ,'%') 'unFinished <br/>Assignments <br/>(percent)'
===System wide use of ACTIVITIES and RESOURCES===
<syntaxhighlight lang="SQL">
,(
SELECT count( cm.id ) AS counter, m.name
SELECT count(asb.id)
FROM `prefix_course_modules` AS cm
FROM prefix_assignment_submissions AS asb
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_assignment AS a ON a.id = asb.assignment
GROUP BY cm.module
JOIN prefix_course_modules AS cm ON a.course = cm.course
ORDER BY counter DESC
WHERE asb.grade < 0 AND cm.instance = a.id AND cm.module = 1 AND a.course = c.id
</syntaxhighlight>
) 'unChecked  <br/>Submissions'
,(
SELECT count(asb.id)
FROM prefix_assignment_submissions AS asb
JOIN prefix_assignment AS a ON a.id = asb.assignment
JOIN prefix_course_modules AS cm ON a.course = cm.course
WHERE cm.instance = a.id AND cm.module = 1 AND a.course = c.id
) 'Submitted  <br/>Assignments'
FROM prefix_course AS c
LEFT JOIN (
SELECT course, count(*) AS iAssignments
FROM prefix_assignment AS a
GROUP BY a.course
) AS tblAssignmentsCount ON tblAssignmentsCount.course = c.id


LEFT JOIN (
===LOG file ACTIONS per MODULE per COURSE (IDs)===
SELECT course, count(*) AS iOpenAssignments
<syntaxhighlight lang="SQL">
FROM prefix_assignment AS a
select course,module,action,count(action) as summa from prefix_log
WHERE FROM_UNIXTIME(a.timedue) > NOW()
where action <> 'new'
GROUP BY a.course  
group by course,action,module
) AS tblOpenAssignmentsCount ON tblOpenAssignmentsCount.course = c.id
order by course,module,action
</syntaxhighlight>


WHERE 1=
===System Wide usage count of various course Activities===
#AND c.fullname LIKE '%תשעג%'
(Tested and works fine in Moodle 2.x)
%%FILTER_YEARS:c.fullname%%
Like: Forum, Wiki, Blog, Assignment, Database,
## You can enable the SEMESTER filter as well,  
#Within specific category
## by uncommenting the following line:
#Teacher name in course
## %%FILTER_SEMESTERS:c.fullname%%
ORDER BY 'Open <br/>Assignments' DESC
</code>


===Rubrics without zero values in criteria===
<syntaxhighlight lang="SQL">
Contributed by Eric Strom
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course


Rubric calculations in Moodle can fail to align with instructors expectations if they lack a zero value for each criterion used in the assessment. From documentation at https://docs.moodle.org/310/en/Rubrics#Grade_calculation:
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher


"For example, when the teacher in the previous example chose both levels with 1 point, the plain sum would be 2 points. But that is actually the lowest possible score so it maps to the grade 0 in Moodle.
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
TIP: To avoid confusion from this sort of thing, we recommend including a level with 0 points in every rubric criterion."
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs


This report identifies rubrics having criteria without a zero value level and the courses they live in. This also refines to only assignments with active rubrics that are visible to students in the course. Links to the each rubric id is the direct link to edit the rubric. Fix by adding a zero level for each criteria that is missing it. In general, the grading changes that result will be in the students' favor.
,(SELECT count( m.name ) AS count FROM
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%forum%') AS Forums


Includes search filter of course idnumber.
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%data%') AS Databses
 
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%assignment%') AS Assignments
 
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students


<code sql>
SELECT cat.name AS Department, concat('<a target="_new" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',
c.id,'">',c.idnumber,'</a>') AS Course_ID,
c.fullname AS Course_Name,
concat('<a target="_new" href="%%WWWROOT%%/grade/grading/form/rubric/edit.php',CHAR(63),'areaid=',gd.areaid,'">',gd.areaid,'</a>') AS Rubric
FROM prefix_course AS c
FROM prefix_course AS c
JOIN prefix_course_categories AS cat
WHERE c.category IN ( 18)
ON cat.id = c.category
ORDER BY Wikis DESC,Blogs DESC, Forums DESC
JOIN prefix_course_modules AS cm
</syntaxhighlight>
ON c.id=cm.course
JOIN prefix_context AS ctx
ON cm.id = ctx.instanceid
JOIN prefix_grading_areas AS garea
ON ctx.id = garea.contextid
JOIN prefix_grading_definitions AS gd
ON garea.id = gd.areaid
JOIN prefix_gradingform_rubric_criteria AS crit
ON gd.id = crit.definitionid
JOIN prefix_gradingform_rubric_levels AS levels
ON levels.criterionid = crit.id
WHERE cm.visible='1' AND garea.activemethod = 'rubric' AND (crit.id NOT IN
(SELECT crit.id
FROM prefix_gradingform_rubric_criteria AS crit
JOIN prefix_gradingform_rubric_levels AS levels
ON levels.criterionid = crit.id WHERE levels.score = '0'))


GROUP BY Rubric
===Course wiki usage/activity over the last 6 semesters===
ORDER BY Course_ID, Rubric
<syntaxhighlight lang="SQL">
SELECT "Courses with Wikis"


%%FILTER_SEARCHTEXT:c.idnumber:~%%
,(SELECT count( m.name ) AS count FROM
</code>
prefix_course_modules AS cm
 
JOIN prefix_modules AS m ON cm.module = m.id
===Who is using "Single File Upload" assignment===
JOIN prefix_course AS c ON c.id = cm.course
<code sql>
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
SELECT
and c.fullname LIKE CONCAT('%','2010','%') and c.fullname LIKE '%Semester A%') AS '2010 <br/> Semester A'
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher


,ass.name as "Assignment Name"
,(SELECT count( m.name ) AS count FROM
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
and c.fullname LIKE CONCAT('%','2010','%') and c.fullname LIKE '%Semester B%') AS '2010 <br/> Semester B'


FROM  
,(SELECT count( m.name ) AS count FROM  
prefix_assignment as ass
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
and c.fullname LIKE CONCAT('%','תשעא','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעא <br/> סמסטר א'


JOIN  
,(SELECT count( m.name ) AS count FROM
prefix_course as c ON c.id = ass.course
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
and c.fullname LIKE CONCAT('%','תשעא','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעא <br/> סמסטר ב'


WHERE `assignmenttype` LIKE 'uploadsingle'
,(SELECT count( m.name ) AS count FROM
</code>
prefix_course_modules AS cm
 
JOIN prefix_modules AS m ON cm.module = m.id
==Resource Module Reports==
JOIN prefix_course AS c ON c.id = cm.course
===List "Recently uploaded files"===
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
see what users are uploading
and c.fullname LIKE CONCAT('%','תשעב','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעב <br/> סמסטר א'
<code sql>
 
SELECT FROM_UNIXTIME(time,'%Y %M %D %h:%i:%s') as time ,ip,userid,url,info 
,(SELECT count( m.name ) AS count FROM
FROM `prefix_log`
prefix_course_modules AS cm
WHERE `action` LIKE 'upload'  
JOIN prefix_modules AS m ON cm.module = m.id
ORDER BY `prefix_log`.`time`  DESC
JOIN prefix_course AS c ON c.id = cm.course
</code>
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
and c.fullname LIKE CONCAT('%','תשעב','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעב <br/> סמסטר ב'


===List Courses that loaded a specific file: "X"===
,(SELECT count( m.name ) AS count FROM
Did the Teacher (probably) uploaded course's Syllabus ?
prefix_course_modules AS cm
<code sql>
JOIN prefix_modules AS m ON cm.module = m.id
SELECT c.id, c.fullname  FROM `prefix_log` as l
JOIN prefix_course AS c ON c.id = cm.course
JOIN prefix_course as c ON c.id = l.course  
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
WHERE `action` LIKE '%upload%' AND ( info LIKE '%Syllabus%' OR info LIKE '%Sylabus%' ) GROUP BY c.id
and c.fullname LIKE CONCAT('%','תשעג','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעג <br/> סמסטר א'
</code>


===All resources that link to some specific external website===
,(SELECT count( m.name ) AS count FROM
+ link to course
prefix_course_modules AS cm
+ who's the teacher
JOIN prefix_modules AS m ON cm.module = m.id
+ link to external resource
JOIN prefix_course AS c ON c.id = cm.course
<code sql>
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
SELECT
and c.fullname LIKE CONCAT('%','תשעג','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעג <br/> סמסטר ב'
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
</syntaxhighlight>
,c.shortname,r.name
 
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
===Detailed WIKI activity (per wiki per course)===
FROM prefix_role_assignments AS ra
Including Number of Students in course (for reference)
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
<syntaxhighlight lang="SQL">
JOIN prefix_user AS u ON u.id = ra.userid
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID 
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
,(SELECT Count( ra.userid ) AS Users
,concat('<a target="_new" href="%%WWWROOT%%/mod/resource/view.php?id=',r.id,'">',r.name,'</a>') AS Resource
FROM prefix_role_assignments AS ra
FROM prefix_resource AS r
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON r.course = c.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id ) AS Students
WHERE r.reference LIKE 'http://info.oranim.ac.il/home%'  
,m.name
</code>
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%updat%' ) as 'UPDAT E'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%annotate%' ) as ANNOTATE
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%comment%' ) as COMMENT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%add%' ) as 'A DD'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%edit%' ) as EDIT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action NOT LIKE '%view%' ) as 'All (NO View)'
FROM `prefix_course_modules` as cm
JOIN prefix_modules as m ON cm.module=m.id
JOIN prefix_course as c ON cm.course = c.id  
WHERE m.name LIKE '%wiki%'
GROUP BY cm.course,cm.module
ORDER BY 'All (NO View)' DESC
</syntaxhighlight>


==="Compose Web Page" RESOURCE count===
===Wiki usage, system wide===
<code sql>
(you can filter the output by selecting some specific course categories : "WHERE c.category IN ( 8,13,15)")
SELECT course,prefix_course.fullname, COUNT(*) AS Total
FROM `prefix_resource`
JOIN `prefix_course` ON prefix_course.id = prefix_resource.course
WHERE type='html'
GROUP BY course
</code>


===Resource count in courses===
<syntaxhighlight lang="SQL">
+ (First)Teacher name
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
+ Where course is inside some specific Categories
<code sql>
SELECT  
COUNT(*) AS count
,r.course  
,c.shortname shortname
,c.fullname coursename
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user as u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = r.course AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
FROM prefix_resource r
JOIN prefix_course c ON r.course = c.id
WHERE c.category IN (10,13,28,18,26)
GROUP BY r.course
ORDER BY COUNT(*) DESC
</code>


===Delete all the automated backup files===
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
Prepare bash cli script to delete all the automated backup files on the file system. (clean up some disk space)
JOIN prefix_modules AS m ON cm.module = m.id
<code sql>
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
SELECT CONCAT( 'rm -f /var/moodledatanew/filedir/', SUBSTRING( contenthash, 1, 2 ) , '/', SUBSTRING( contenthash, 3, 2 ) , '/', contenthash )  
FROM `mdl_files`
WHERE `filename` LIKE '%mbz%'
AND filearea = 'automated'
</code>


Find out how much disk space is used by all automated backup files:
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%') AS 'WikiActivity<br/>ALL'
<code sql>
SELECT SUM(filesize)/(1024*1024*1024) FROM `mdl_files` WHERE `filename` LIKE '%mbz%' AND filearea =  'automated'
</code>


==Forum Module Reports==
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%add%' ) AS 'WikiActivity<br/>ADD'
===print all User's post in course Forums===
%%COURSEID%% is a variable the is replace by the current CourseID you are running the sql report from. if you are using the latest block/configurable_reports ! (You can always change it to a fixed course or remove it to display all courses.)
<code sql>
SELECT  
concat('<a target="_new" href="%%WWWROOT%%/mod/forum/user.php?course=',c.id,'&id=',u.id,'&mode=posts">',CONCAT(u.firstname,' ', u.lastname),'</a>') As Fullname
,concat('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',fd.forum,'">',f.name,'</a>') AS Forum
,count(*) as Posts
,(SELECT count(*) FROM prefix_forum_discussions AS ifd JOIN prefix_forum as iforum ON iforum.id = ifd.forum  WHERE ifd.userid = fp.userid AND iforum.id = f.id) AS cAllDiscussion


FROM prefix_forum_posts AS fp
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%edit%' ) AS 'WikiActivity<br/>EDIT'
JOIN prefix_user as u ON u.id = fp.userid
JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id
JOIN prefix_forum AS f ON f.id = fd.forum
JOIN prefix_course as c ON c.id = fd.course
WHERE fd.course = %%COURSEID%%  
GROUP BY f.id,u.id
ORDER BY u.id
</code>


===FORUM use Count per COURSE -- not including NEWS Forum!===
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%annotate%' ) AS 'WikiActivity<br/>ANNOTATE'
<code sql>
SELECT prefix_course.fullname, prefix_forum.course, count(*) as total FROM prefix_forum
INNER JOIN prefix_course
ON prefix_course.id = prefix_forum.course
WHERE NOT(prefix_forum.type = 'news')
GROUP BY prefix_forum.course
ORDER BY total desc
</code>


===FORUM use Count per COURSE by type -- not including NEWS Forum!===
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%comments%' ) AS 'WikiActivity<br/>Comments'
<code sql>
SELECT prefix_course.fullname, prefix_forum.course, prefix_forum.type, count(*) as total FROM prefix_forum
INNER JOIN prefix_course
ON prefix_course.id = prefix_forum.course
WHERE NOT(prefix_forum.type = 'news')
GROUP BY prefix_forum.course,prefix_forum.type
ORDER BY total desc
</code>


===Forum activity - system wide===
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS CourseID
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
,c.fullname as Course
,f.type
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
, fd.forum, f.name,count(*) AS cPostAndDisc
,(SELECT count(*) FROM prefix_forum_discussions AS ifd WHERE ifd.forum = f.id) AS cDiscussion
FROM prefix_forum_posts AS fp
JOIN prefix_forum_discussions AS fd ON fd.id = fp.discussion
JOIN prefix_forum AS f ON f.id = fd.forum
JOIN prefix_course AS c ON c.id = f.course
WHERE f.type != 'news' AND c.fullname LIKE '%2013%'
## WHERE 1=1
## %%FILTER_YEARS:c.fullname%%
## You can enable the SEMESTER filter as well,
## by uncommenting the following line:
## %%FILTER_SEMESTERS:c.fullname%%


GROUP BY fd.forum
,(SELECT count(*) FROM prefix_ouwiki_pages as ouwp
ORDER BY count( * ) DESC
JOIN prefix_ouwiki as ouw ON ouw.id = ouwp.subwikiid
</code>
WHERE ouw.course = c.id GROUP BY ouw.course  ) as OUWikiPages
 
,(SELECT count( DISTINCT nwp.pagename ) FROM prefix_wiki_pages AS nwp
JOIN prefix_wiki AS nw ON nw.id = nwp.dfwiki WHERE nw.course = c.id ) As NWikiPages
 
FROM prefix_course AS c
WHERE c.category IN ( 8,13,15)
HAVING Wikis > 0
ORDER BY 'WikiActivity<br/>ALL' DESC
</syntaxhighlight>


===Activity In Forums===
===Aggregated Teacher activity by "WEB2" Modules===
Trying to figure out how much real activity we have in Forums by aggregating:
(Tested and works fine in Moodle 2.x)
Users in Course, Number of Posts, Number of Discussions, Unique student post, Unique student discussions, Number of Teachers , Number of Students, ratio between unique Student posts and the number of students in the Course...
The NV column shows activity without VIEW log activity
<code sql>
<syntaxhighlight lang="SQL">
SELECT c.fullname,f.name,f.type
SELECT ra.userid, u.firstname,u.lastname
,(SELECT count(id) FROM prefix_forum_discussions as fd WHERE f.id = fd.forum) as Discussions
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%') AS Wiki
,(SELECT count(distinct fd.userid) FROM prefix_forum_discussions as fd WHERE fd.forum = f.id) as UniqueUsersDiscussions
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%' AND l.action NOT LIKE '%view%') AS Wiki_NV
,(SELECT count(fp.id) FROM prefix_forum_discussions fd JOIN prefix_forum_posts as fp ON fd.id = fp.discussion WHERE f.id = fd.forum) as Posts
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%') AS Forum
,(SELECT count(distinct fp.userid) FROM prefix_forum_discussions fd JOIN prefix_forum_posts as fp ON fd.id = fp.discussion WHERE f.id = fd.forum) as UniqueUsersPosts
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%' AND l.action NOT LIKE '%view%') AS Forum_NV
,(SELECT Count( ra.userid ) AS Students
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%') AS Blog
FROM prefix_role_assignments AS ra
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%' AND l.action NOT LIKE '%view%') AS Blog_NV
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%') AS Assignment
WHERE ra.roleid =5
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%' AND l.action NOT LIKE '%view%') AS Assignment_NV
AND ctx.instanceid = c.id
FROM prefix_role_assignments AS ra
) AS StudentsCount
JOIN prefix_user AS u ON u.id = ra.userid
,(SELECT Count( ra.userid ) AS Teachers
WHERE ra.roleid = 3
FROM prefix_role_assignments AS ra
GROUP BY ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
</syntaxhighlight>
WHERE ra.roleid =3
AND ctx.instanceid = c.id
) AS 'Teacher<br/>Count'
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid IN (3,5)
AND ctx.instanceid = c.id
) AS UserCount
, (SELECT (UniqueUsersDiscussions / StudentsCount )) as StudentDissUsage
, (SELECT (UniqueUsersPosts /StudentsCount)) as StudentPostUsage
FROM prefix_forum as f
JOIN prefix_course as c ON f.course = c.id
WHERE `type` != 'news'
ORDER BY StudentPostUsage DESC
</code>


===All Forum type:NEWS===
===List all the certificates issued, sort by variables in the custom profile fields===
<code sql>
Note: The SQL queries look intimidating at first, but isn't really that difficult to learn. I've seen in the forums that users wanted to do 'site-wide' groups in 1.9x. This is sort of the idea. It pulls all the certificates issued to all users sorted by the custom profile fields, which in my case is the Units or Depts (i.e. my site wide groups). Why certificates? I've explored with both grades and quizzes, the course admins are not really interested in the actual grades but whether the learner received a certificate (i.e. passed the course with x, y, z activities). It also saves me from creating groups and assigning them into the right groups. Even assigning in bulk is not efficient, since I have upward of 25 groups per course and constantly new learners enrolling in courses. The limitation is something to do with the server? as it only pull 5000 rows of data. If anyone figured out how to change this, please let me know. In the meantime, the work around is to pull only a few units/depts at a time to limit the number of rows. This is fine at the moment, since each course admin are only responsible for certain units/depts.
SELECT f.id, f.name
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_forum AS f ON cm.instance = f.id
WHERE m.name = 'forum'
AND f.type = 'news'
</code>


===All new forum NEWS items (discussions) from all my Courses===
<syntaxhighlight lang="SQL">
change "userid = 26" and "id = 26" to a new user id
SELECT
<code sql>
DATE_FORMAT( FROM_UNIXTIME(prefix_certificate_issues.timecreated), '%Y-%m-%d' ) AS Date,
SELECT c.shortname,f.name,fd.name,FROM_UNIXTIME(fd.timemodified ,"%d %M %Y ") as Date
prefix_certificate_issues.classname AS Topic,
FROM prefix_forum_discussions as fd
prefix_certificate.name AS Certificate,
JOIN prefix_forum as f ON f.id = fd.forum
prefix_certificate_issues.studentname as Name,
JOIN prefix_course as c ON c.id = f.course
prefix_user_info_data.data AS Units
JOIN prefix_user_lastaccess as ul ON (c.id = ul.courseid AND ul.userid = 26)
WHERE fd.timemodified > ul.timeaccess 
AND fd.forum IN (SELECT f.id
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_forum AS f ON cm.instance = f.id
WHERE m.name = 'forum'
AND f.type = 'news')
  AND c.id IN (SELECT c.id
  FROM prefix_course AS c
  JOIN prefix_context AS ctx ON c.id = ctx.instanceid
  JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
  JOIN prefix_user AS u ON u.id = ra.userid
  WHERE u.id = 26) ORDER BY `fd`.`timemodified` DESC
</code>


FROM
prefix_certificate_issues


===News Forum - Discussions COUNT===
INNER JOIN prefix_user_info_data
Which is actually... How much instructions students get from their teachers
on prefix_certificate_issues.userid = prefix_user_info_data.userid
<code sql>
 
SELECT c.shortname ,
INNER JOIN prefix_certificate
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
on prefix_certificate_issues.certificateid = prefix_certificate.id
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
 
  FROM prefix_role_assignments AS ra
WHERE prefix_user_info_data.data='Unit 1'
  JOIN prefix_user AS u ON ra.userid = u.id
OR prefix_user_info_data.data='Unit 2'
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
OR prefix_user_info_data.data='Unit 3'
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
 
,concat('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',fd.forum,'">',count(fd.id),'</a>') AS DiscussionsSum
ORDER BY Units, Name, Topic ASC
FROM prefix_forum_discussions AS fd
</syntaxhighlight>
INNER JOIN prefix_forum AS f ON f.id = fd.forum
INNER JOIN prefix_course AS c ON c.id = f.course
WHERE f.type = 'news' AND c.category IN (10,13,28,18,26)
GROUP BY fd.forum
ORDER BY count(fd.id) DESC
</code>


===Cantidad de foros que han sido posteados por profesor===
Queriamos saber cuales son las acciones del profesor dentro de los foros de cada curso, por ello se hizo este informe.
<code sql>
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS curso,
CONCAT(u.firstname ,' ',u.lastname) AS Facilitador,


(SELECT COUNT( m.name ) AS COUNT FROM
=== All Simple Certificates Earned in the Site===
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%forum%') AS foros,


COUNT(*) AS Posts
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


FROM prefix_forum_posts AS fp
Basic report of all certificates earned with the Simple Certificate plugin module in the whole site, sorted by most recent first. (Note: this uses the MySQL [http://www.mysqltutorial.org/mysql-date_format/ DATE_FORMAT] function.)
JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id
JOIN prefix_forum AS f ON f.id = fd.forum
JOIN prefix_course AS c ON c.id = fd.course
JOIN prefix_user AS u ON u.id = fp.userid


WHERE fp.userid =
<syntaxhighlight lang="SQL">
(
SELECT
select distinct prefix_user.id
CONCAT (u.firstname, ' ',u.lastname) As 'User',
from prefix_user  
c.fullname AS 'Course',
join prefix_role_assignments as ra on ra.userid = prefix_user.id  
sc.name AS 'Certificate',
where ra.roleid = 3
DATE_FORMAT( FROM_UNIXTIME(sci.timecreated), '%Y-%m-%d' ) As 'Date Awarded'
and userid = fp.userid
# sci.code 'CertificateId'
limit 1
FROM prefix_simplecertificate_issues sci
)
JOIN prefix_user u ON sci.userid = u.id
JOIN prefix_simplecertificate sc ON sci.certificateid = sc.id
JOIN prefix_course AS c ON sc.course = c.id
ORDER BY sci.timecreated DESC
</syntaxhighlight>


and c.shortname like '%2014-2-1%'
If you want to limit this to the most recent ones, you can add a condition to limit it to a certain number of days past. For example, adding this WHERE clause (above the ORDER BY) will show only those earned in the last 30 days:
GROUP BY c.id, u.id
<syntaxhighlight lang="SQL">
</code>
WHERE DATEDIFF(NOW(),FROM_UNIXTIME(sci.timecreated) ) < 30
</syntaxhighlight>


==Quiz Module Reports==
===Counter Blog usage in Courses,system wide===
===Generate a list of instructors and their email addresses for those courses that has "essay questions" in their quizzes===
What teachers in what courses, uses blogs and how many + student count in that course.
<code sql>
<syntaxhighlight lang="SQL">
SELECT qu.id AS quiz_id, qu.course AS course_id, qu.questions,
 
                co.fullname AS course_fullname, co.shortname AS course_shortname,
SELECT ( @counter := @counter+1) as counter,  
                qu.name AS quiz_name, FROM_UNIXTIME(qu.timeopen) AS quiz_timeopen, FROM_UNIXTIME(qu.timeclose) AS quiz_timeclose,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
                u.firstname, u.lastname, u.email,
FROM prefix_quiz qu, prefix_course co, prefix_role re, prefix_context ct, prefix_role_assignments ra, prefix_user u
WHERE FROM_UNIXTIME(timeopen) > '2008-05-14' AND
                qu.course = co.id AND
                co.id = ct.instanceid AND
                ra.roleid = re.id AND
                re.name = 'Teacher' AND
                ra.contextid = ct.id AND
                ra.userid = u.id
SELECT Count('x') As NumOfStudents
                                FROM prefix_role_assignments a
                                JOIN prefix_user u ON userid = u.id
                                WHERE roleid = 5 AND contextid = (SELECT id FROM prefix_context WHERE instanceid = 668 AND contextlevel = 50)
</code>


===Number of Quizes per Course===
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
<code sql>
  FROM prefix_role_assignments AS ra
SELECT count(*)
  JOIN prefix_user AS u ON ra.userid = u.id
,concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">Link</a>') AS Quizes
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher


FROM prefix_course_modules cm
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_course c ON c.id = cm.course
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_modules as m ON m.id = cm.module
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs
WHERE m.name LIKE 'quiz'
GROUP BY c.id
</code>


===List all MultiAnswer (Cloze) Questions===
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
<code sql>
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
SELECT concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/attempt.php?q=', quiz.id, '">', quiz.name, '</a>') AS Quiz
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
,question.id question_id, question.questiontext
 
FROM  prefix_question question
FROM prefix_course AS c, (SELECT @counter := 0) as s_init
JOIN prefix_quiz_question_instances qqi ON question.id = qqi.question
WHERE c.category IN ( 8,13,15)
JOIN prefix_quiz quiz ON qqi.quiz = quiz.id
HAVING Blogs > 0
WHERE  `qtype` LIKE  'multianswer'
ORDER BY Blogs DESC
</code>
</syntaxhighlight>
 
=== Elluminate (Blackboard Collaborate) - system wide usage===
<syntaxhighlight lang="SQL">
SELECT e.name As Session ,er.recordingsize
,c.fullname As Course
,u.firstname,u.lastname
,DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%d-%m-%Y') AS dTimeStart
,concat('<a target="_new" href="%%WWWROOT%%/moodle/mod/elluminate/loadrecording.php?id=',er.id,'">Show</a>') AS RecordedSession


===List courses with MANUAL grades===
FROM prefix_elluminate_recordings AS er
Which is basically and indication to teachers using Moodle to hold offline grades inside Moodle's Gradebook,
JOIN prefix_elluminate AS e ON e.meetingid = er.meetingid
So grades could be uploaded into an administrative SIS. Use with Configurable Reports.
JOIN prefix_course as c ON c.id = e.course
<code sql>
JOIN prefix_user AS u ON u.id = e.creator
SELECT COUNT( * )
ORDER BY er.recordingsize DESC
,concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php?showadvanced=1&id=',c.id,'">',c.fullname,'</a>') AS Course
</syntaxhighlight>
FROM  prefix_grade_items AS gi
JOIN prefix_course as c ON c.id = gi.courseid
WHERE  `itemtype` =  'manual'
GROUP BY courseid
</code>
===List the users that did not took the Quiz===
Do not forget to change "c.id = 14" and q.name LIKE '%quiz name goes here%'
<code sql>
SELECT
user2.id AS ID,
ul.timeaccess,
user2.firstname AS Firstname,
user2.lastname AS Lastname,
user2.email AS Email,
user2.username AS IDNumber,
user2.institution AS Institution,
IF (user2.lastaccess = 0,'never',
DATE_FORMAT(FROM_UNIXTIME(user2.lastaccess),'%Y-%m-%d')) AS dLastAccess
,(SELECT DATE_FORMAT(FROM_UNIXTIME(timeaccess),'%Y-%m-%d') FROM prefix_user_lastaccess WHERE userid=user2.id AND courseid=c.id) AS CourseLastAccess
,(SELECT r.name
FROM  prefix_user_enrolments AS uenrol
JOIN prefix_enrol AS e ON e.id = uenrol.enrolid
JOIN prefix_role AS r ON e.id = r.id
WHERE uenrol.userid=user2.id AND e.courseid = c.id) AS RoleName
FROM prefix_user_enrolments AS ue
JOIN prefix_enrol AS e ON e.id = ue.enrolid
JOIN prefix_course AS c ON c.id = e.courseid
JOIN prefix_user AS user2 ON user2 .id = ue.userid
LEFT JOIN prefix_user_lastaccess AS ul ON ul.userid = user2.id
WHERE c.id=14 and ue.userid NOT IN (SELECT qa.userid FROM prefix_quiz_attempts AS qa
JOIN prefix_quiz AS q ON qa.quiz = q.id
JOIN prefix_course AS c ON q.course = c.id
WHERE c.id = 14 AND q.name LIKE '%quiz name goes here%')
</code>




===List Questions in each Quiz===
=== Choice ===


<code sql>
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
SELECT quiz.id,quiz.name, q.id, q.name
FROM mdl_quiz AS quiz
JOIN mdl_question AS q ON FIND_IN_SET(q.id, quiz.questions)
WHERE quiz.course = %%COURSEID%%
ORDER BY quiz.id ASC
</code>


Note: this query does not work in Moodle 2.8. There is no mdl_quiz.questions field. It will need to be rewritten to use the usage/contextid organization.
Results of the Choice activity. For all courses, shows course shortname, username, the Choice text, and the answer chosen by the user.


===Quiz activity research===
<syntaxhighlight lang="SQL">
This report was made to extract student full activity in quizzes for an academic research about adapting instructional design teaching methods in online learning. The students do not use the Quiz module as a standard quiz but more as Study booklets or mini courses with embedded questions and hints to assist students evaluate their progress (Similar to what you expect to find in a SCORM activity)
SELECT c.shortname AS course, u.username, h.name as question, o.text AS answer
FROM prefix_choice AS h
JOIN prefix_course AS c ON h.course = c.id
JOIN prefix_choice_answers AS a ON h.id = a.choiceid
JOIN prefix_user AS u ON a.userid = u.id
JOIN prefix_choice_options AS o ON a.optionid = o.id
</syntaxhighlight>


<code sql>
=== Assignment type usage in courses ===
<syntaxhighlight lang="SQL">
SELECT  
SELECT  
cm.course "course_id", cm.id "moduel_id", q.id "quiz_id", q.name "quiz_name",
CASE q.grademethod
      WHEN 1 THEN "GRADEHIGHEST"
      WHEN 2 THEN "GRADEAVERAGE"
      WHEN 3 THEN "ATTEMPTFIRST"
      WHEN 4 THEN "ATTEMPTLAST"
END "grade method"
 
, q.attempts "quiz_attempts_allowed", cm.groupmode "group_mode"
, qa.id "attempt_id", qa.state "attempt_state", qa.sumgrades "attempt_grade", qg.grade "user_final_grade", q.grade "quiz_max_grade"
,(SELECT GROUP_CONCAT(g.name) FROM mdl_groups AS g
JOIN mdl_groups_members AS m ON g.id = m.groupid WHERE g.courseid = q.course AND m.userid = u.id) "user_groups",
DATE_FORMAT(FROM_UNIXTIME(qa.timestart), '%d-%m-%Y %h:%k') "attempt_start",
DATE_FORMAT(FROM_UNIXTIME(qa.timefinish), '%d-%m-%Y %h:%k') "attempt_finish",
u.id "user_id", u.firstname, u.lastname,
question.id "question_id", question.name "question_name",
qas.state "question_step_state",qas.fraction "question_grade", qh.hint, question.qtype "question_type"


FROM mdl_quiz as q
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/assign/index.php?id=',c.id,'">',c.fullname,'</a>') AS "List assignments"
JOIN mdl_course_modules as cm ON cm.instance = q.id and cm.module = 14
JOIN mdl_quiz_attempts qa ON q.id = qa.quiz
LEFT JOIN mdl_quiz_grades as qg ON qg.quiz = q.id and qg.userid = qa.userid
JOIN mdl_user as u ON u.id = qa.userid
JOIN mdl_question_usages as qu ON qu.id = qa.uniqueid
JOIN mdl_question_attempts as qatt ON qatt.questionusageid = qu.id
JOIN mdl_question as question ON question.id = qatt.questionid
JOIN mdl_question_attempt_steps as qas ON qas.questionattemptid = qatt.id
LEFT JOIN mdl_question_hints as qh ON qh.questionid = q.id
#WHERE q.id = "SOME QUIZ ID"
WHERE cm.course = "SOME COURSE ID"
</code>


===Quiz Usage in Courses by Date===
,(SELECT COUNT(*) FROM prefix_assign WHERE c.id = course) AS Assignments
Contributed by Elizabeth Dalton, Granite State College


This report lists the courses containing quizzes with the course start date between the two values, and provides a summary of the types of questions in the quizzes in each course and whether question randomization and answer randomization functions were used.
,(SELECT COUNT(*)
 
FROM prefix_assign_plugin_config AS apc
"Multiple Choice" questions include true/false and matching question types.
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'file' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
#GROUP BY apc.plugin
) AS "File Assignments"


"Short Answer" are questions that accept a single phrase.
,(SELECT COUNT(*)
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'onlinetext' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "Online Assignments"


"Other" questions include fixed numerical, calculated, essay, and various drag and drop types.
,(SELECT COUNT(*)
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'pdf' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "PDF Assignments"


"Min Quiz Age" and "Max Quiz Age" provide data about the last modified date for the quizzes in the course, compared to the course start date. The values are expressed in units of days. A negative value indicates that a quiz was edited after the start of the course. A value greater than 90 days indicates that the quiz may have been used in an earlier term (cohort) without modification.
,(SELECT COUNT(*)
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'offline' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "Offline Assignments"


'''Note''': In Configurable Reports, the Date Filter is not applied until the "Apply" button is clicked.
,(SELECT COUNT(*)
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE iassign.course = c.id AND apc.plugin = 'comments' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "Assignments Comments"


<code sql>
FROM prefix_assign AS assign
SELECT
JOIN prefix_course AS c ON c.id = assign.course
GROUP BY c.id
</syntaxhighlight>


c.shortname AS 'Course'
==Assignment Module Reports==
#, u.lastname AS 'Instructor'
===All Ungraded Assignments===
, COUNT(DISTINCT q.id) AS 'Quizzes'
, COUNT(DISTINCT qu.id) AS 'Questions'
, SUM(IF (qu.qtype = 'multichoice', 1, 0 )) + SUM(IF (qu.qtype = 'truefalse', 1, 0 )) + SUM(IF (qu.qtype = 'match', 1, 0 ))  AS 'multichoice'


, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'
'''NOTE: This query is for the deprecated old Assignment module from Moodle 2.2, not the new Assignments module. Please update this query if you are the author or it will be removed as the 2.2 Assignment module is no longer supported since release 2.7.
''' See: [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment]


, COUNT( qu.id) - SUM(IF (qu.qtype = 'multichoice', 1, 0 )) - SUM(IF (qu.qtype = 'truefalse', 1, 0 )) - SUM(IF (qu.qtype = 'match', 1, 0 )) - SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'Other'
Returns all the submitted assignments that still need grading
<syntaxhighlight lang="SQL">
select
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment"
 
from prefix_assignment_submissions as asb
join prefix_assignment as a ON a.id = asb.assignment
join prefix_user as u ON u.id = asb.userid
join prefix_course as c ON c.id = a.course
join prefix_course_modules as cm ON c.id = cm.course


, (SUM(IF (qu.qtype = 'multichoice', 1, 0 )) + SUM(IF (qu.qtype = 'truefalse', 1, 0 )) + SUM(IF (qu.qtype = 'match', 1, 0 )))/COUNT( qu.id) AS 'Percent MC'
where asb.grade < 0 and cm.instance = a.id
and cm.module = 1


#, SUM(IF (qu.qtype = 'numerical', 1, 0 )) AS 'numerical'
order by c.fullname, a.name, u.lastname
#, SUM(IF (qu.qtype LIKE 'calc%', 1, 0 )) AS 'calculated'
</syntaxhighlight>
#, SUM(IF (qu.qtype = 'random', 1, 0 )) AS 'random'
#, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'
#, SUM(IF (qu.qtype = 'essay', 1, 0 )) AS 'essay'


===All Ungraded Assignments w/ Link===
Returns all assignments submitted by those with the student role that have the status of 'submitted', along with a link that goes directly to the submission to grade it. The links work if you view the report within Moodle.


, IF(q.shufflequestions > 0,'Yes','No') AS 'Randomized Questions'
'''This query is updated for use with Moodle 2.2 or later.  Contributed by Carly J. Born, Carleton College'''
, IF(q.shuffleanswers > 0,'Yes','No') AS 'Randomized Answers'
<syntaxhighlight lang="SQL">
SELECT
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment",
concat('<a target="_new" href="%%WWWROOT%%/mod/assign/view.php?id=',
cm.id,  
'&rownum=0&action=grader&userid=',  
u.id,
'">Grade</a>')  
AS "Assignment link"
FROM prefix_assign_submission sub
JOIN prefix_assign a ON a.id = sub.assignment
JOIN prefix_user u ON u.id = sub.userid
JOIN prefix_course c ON c.id = a.course AND c.id = %%COURSEID%%
JOIN prefix_course_modules cm ON c.id = cm.course
JOIN prefix_context cxt ON c.id=cxt.instanceid AND cxt.contextlevel=50
JOIN prefix_role_assignments ra ON cxt.id = ra.contextid AND ra.roleid=5 AND ra.userid=u.id
WHERE cm.instance = a.id AND cm.module = 22 AND sub.status='submitted'
   
   
#, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
ORDER BY c.fullname, a.name, u.lastname
#, FROM_UNIXTIME(MIN(q.timemodified)) AS 'Last Modified'
 
</syntaxhighlight>


#, DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(MIN(q.timemodified))) AS 'Quiz age'


, MIN(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Min Quiz Age'
NOTE: This query is for the deprecated old Assignment module from Moodle 2.2, not the new Assignments module. Please update this query if you are the author or it will be removed as the 2.2 Assignment module is no longer supported since release 2.7.
, MAX(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Max Quiz Age'
See: [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment]


#, SUM(IF (DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified)) < 90, 1,0)) AS 'new quizzes'


FROM prefix_quiz AS q
Returns all the submitted assignments that still need grading, along with a link that goes directly to the submission to grade it. The links work if you view the report within Moodle.
JOIN prefix_course AS c on c.id = q.course
 
JOIN prefix_quiz_question_instances AS qqi ON qqi.quiz = q.id
<syntaxhighlight lang="SQL">
LEFT JOIN prefix_question AS qu ON qu.id = qqi.question
select
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment",


WHERE
'<a href="http://education.varonis.com/mod/assignment/submissions.php' + char(63) +
1
+ 'id=' + cast(cm.id as varchar) + '&userid=' + cast(u.id as varchar)
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.startdate:<%%
+ '&mode=single&filter=0&offset=2">' + a.name + '</a>'
AS "Assignmentlink"


GROUP BY c.id


ORDER BY c.shortname
from prefix_assignment_submissions as asb
</code>
join prefix_assignment as a ON a.id = asb.assignment
join prefix_user as u ON u.id = asb.userid
join prefix_course as c ON c.id = a.course
join prefix_course_modules as cm ON c.id = cm.course


==SCORM Activity Reports==
where asb.grade < 0 and cm.instance = a.id and cm.module = 1


===Lists All completed SCORM activites by Course name===
order by c.fullname, a.name, u.lastname
This report will list all completed attempts for all SCORM activities. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. Please note: the FROM_UNIXTIME command is for MySQL.
</syntaxhighlight>
<code sql>
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
FROM prefix_scorm_scoes_track AS st
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
WHERE st.value='completed'
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt
</code>


===Lists SCORM status for all enrolled users by Course name===
===Assignments (and Quizzes) waiting to be graded===
This report will list the SCORM status for all users enrolled in the course. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. This can be limited to individual courses by adding to the where clause the course id to report on. 
<code sql>
SELECT
u.firstname AS First,
u.lastname AS Last,
u.idnumber AS Employee_ID, 
u.city AS City,
uid.data AS State,
u.country AS Country,
g.name AS Group_name,
c.fullname AS Course,
st.attempt AS Attempt,
st.value AS Status,
FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") AS Date


FROM prefix_scorm_scoes_track AS st
'''NOTE: This query is for the deprecated old Assignment module from Moodle 2.2, not the new Assignments module. Please update this query if you are the author or it will be removed as the 2.2 Assignment module is no longer supported since release 2.7.
JOIN prefix_user AS u ON st.userid=u.id
''' See: [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment]
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_groups_members AS m ON g.id = m.groupid


WHERE st.element='cmi.core.lesson_status' AND m.userid=u.id


UNION
This report requires a YEAR filter to be added (Available when using the latest block/configurable_reports)


SELECT
Which you can always remove, to make this query work on earlier versions.
user2.firstname AS First,
user2.lastname AS Last,
user2. idnumber AS Employee_ID,
user2.city AS City,
uid.data AS State,
user2.country AS Country,
g.name AS Group_name,
c.fullname AS Course,
"-" AS Attempt,
"not_started" AS Status,
"-" AS Date


FROM prefix_user_enrolments AS ue
The report includes:
JOIN prefix_enrol AS e ON e.id = ue.enrolid
*number of quizzes
JOIN prefix_course AS c ON c.id = e.courseid
*unFinished Quiz attempts
JOIN prefix_user AS user2 ON user2 .id = ue.userid
*Finished Quiz attempts
JOIN prefix_user_info_data AS uid ON uid.userid = user2.id
*number of students
JOIN prefix_groups AS g ON g.courseid = c.id
*number of Assignments
JOIN prefix_groups_members AS m ON g.id = m.groupid
*number of submitted answers by students
JOIN prefix_scorm AS sc ON sc.course=c.id
*number of unchecked assignments (waiting for the Teacher) in a Course.
Left Join prefix_scorm_scoes_track AS st on st.scormid=sc.id AND st.userid=user2.id


WHERE  st.timemodified IS NULL AND m.userid=user2.id
<syntaxhighlight lang="SQL">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course


ORDER BY Course, Last, First, Attempt
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
   
,concat('<a target="_new" href="%%WWWROOT%%/mod/assignment/index.php?id=',c.id,'">מטלות</a>') AS Assignments


</code>
,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">בחנים</a>') AS 'Quizzes'


== Badges==
,(SELECT COUNT(*)
FROM prefix_course_modules cm
JOIN prefix_modules as m ON m.id = cm.module
WHERE m.name LIKE 'quiz' AND cm.course = c.id
GROUP BY cm.course
) AS 'nQuizzes'


=== All badges issued, by User ===
,(SELECT COUNT(*)
FROM prefix_quiz_attempts AS qa
JOIN prefix_quiz AS q ON q.id = qa.quiz
WHERE q.course = c.id
AND qa.timefinish = 0
GROUP BY q.course) AS 'unFinished Quiz attempts'


This report will show you all the badges on a site that have been issued, both site and all courses, by the username of each user issued a badge. Includes the type of criteria passed (activity, course completion, manual), date issued, date expires, and a direct link to that issued badge page so you can see all the other details for that badge.
,(SELECT COUNT(*)
 
FROM prefix_quiz_attempts AS qa
<code sql>
JOIN prefix_quiz AS q ON q.id = qa.quiz
SELECT u.username, b.name AS badgename,
WHERE q.course = c.id
CASE
AND qa.timefinish > 0
WHEN b.courseid IS NOT NULL THEN
GROUP BY q.course) AS 'finished quiz attempts'
(SELECT c.shortname
    FROM prefix_course AS c
    WHERE c.id = b.courseid)
WHEN b.courseid IS NULL THEN "*"
END AS Context,
CASE
  WHEN t.criteriatype = 1 AND t.method = 1 THEN "Activity Completion (All)"
  WHEN t.criteriatype = 1 AND t.method = 2 THEN "Activity Completion (Any)"
  WHEN t.criteriatype = 2 AND t.method = 2 THEN "Manual Award"
  WHEN t.criteriatype = 4 AND t.method = 1 THEN "Course Completion (All)"
  WHEN t.criteriatype = 4 AND t.method = 2 THEN "Course Completion (Any)"
  ELSE CONCAT ('Other: ', t.criteriatype)
END AS Criteriatype,
DATE_FORMAT( FROM_UNIXTIME( d.dateissued ) , '%Y-%m-%d' ) AS dateissued,
DATE_FORMAT( FROM_UNIXTIME( d.dateexpire ), '%Y-%m-%d' ) AS dateexpires,
CONCAT ('<a target="_new" href="%%WWWROOT%%/badges/badge.php?hash=',d.uniquehash,'">link</a>') AS Details
FROM prefix_badge_issued AS d
JOIN prefix_badge AS b ON d.badgeid = b.id
JOIN prefix_user AS u ON d.userid = u.id
JOIN prefix_badge_criteria AS t on b.id = t.badgeid
WHERE t.criteriatype <> 0
ORDER BY u.username
</code>


Please note: the FROM_UNIXTIME command is for MySQL.
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5
AND ctx.instanceid = c.id
) AS nStudents


=== All badges available in the system, with Earned count ===
,(
SELECT count(a.id)
FROM prefix_assignment AS a
JOIN prefix_course_modules AS cm ON a.course = cm.course
WHERE cm.instance = a.id AND cm.module = 1 AND a.course = c.id
) nAssignments


Report of all badges in the system, with badge name and description, context, course shortname if a course badge, whether it is active and available, and a count of how many users have been issued that badge.
,(
SELECT count(*)
FROM prefix_assignment AS a
WHERE a.course = c.id AND FROM_UNIXTIME(a.timedue) > NOW()
GROUP BY a.course
) 'Open <br/>Assignments'


<code sql>
, CONCAT(ROUND( (100 / iAssignments ) * iOpenAssignments ) ,'%') 'unFinished <br/>Assignments <br/>(percent)'
SELECT b.id, b.name, b.description,
CASE
,(
WHEN b.type = 1 THEN "System"
SELECT count(asb.id)
WHEN b.type = 2 THEN "Course"
FROM prefix_assignment_submissions AS asb
END AS Context,
JOIN prefix_assignment AS a ON a.id = asb.assignment
CASE
JOIN prefix_course_modules AS cm ON a.course = cm.course
WHEN b.courseid IS NOT NULL THEN
WHERE asb.grade < 0 AND cm.instance = a.id AND cm.module = 1 AND a.course = c.id
(SELECT c.shortname
) 'unChecked  <br/>Submissions'
    FROM prefix_course AS c
    WHERE c.id = b.courseid)
,(
WHEN b.courseid IS NULL THEN "*"
SELECT count(asb.id)
END AS Course,
FROM prefix_assignment_submissions AS asb
CASE
JOIN prefix_assignment AS a ON a.id = asb.assignment
WHEN b.status = 0 OR b.status = 2 THEN "No"
JOIN prefix_course_modules AS cm ON a.course = cm.course
WHEN b.status = 1 OR b.status = 3 THEN "Yes"
WHERE cm.instance = a.id AND cm.module = 1 AND a.course = c.id
WHEN b.status = 4 THEN "x"
) 'Submitted  <br/>Assignments'
END AS Available,
CASE
FROM prefix_course AS c
WHEN b.status = 0 OR b.status = 1 THEN "0"
LEFT JOIN (
WHEN b.status = 2 OR b.status = 3 OR b.status = 4 THEN
SELECT course, count(*) AS iAssignments
(SELECT COUNT(*)  
FROM prefix_assignment AS a
  FROM prefix_badge_issued AS d
GROUP BY a.course
  WHERE d.badgeid = b.id
) AS tblAssignmentsCount ON tblAssignmentsCount.course = c.id
)
 
END AS Earned
LEFT JOIN (
FROM prefix_badge AS b
SELECT course, count(*) AS iOpenAssignments
FROM prefix_assignment AS a
WHERE FROM_UNIXTIME(a.timedue) > NOW()
GROUP BY a.course
) AS tblOpenAssignmentsCount ON tblOpenAssignmentsCount.course = c.id


</code>
WHERE 1=1 
#AND c.fullname LIKE '%תשעג%'
%%FILTER_YEARS:c.fullname%%
## You can enable the SEMESTER filter as well,
## by uncommenting the following line:
## %%FILTER_SEMESTERS:c.fullname%%
ORDER BY 'Open <br/>Assignments' DESC
</syntaxhighlight>


=== Badges Leaderboard ===
===Rubrics without zero values in criteria===
Contributed by Eric Strom


A simple list of usernames and how many badges they have earned overall.
Rubric calculations in Moodle can fail to align with instructors expectations if they lack a zero value for each criterion used in the assessment. From documentation at https://docs.moodle.org/32/en/Rubrics#Grade_calculation:


<code sql>
"For example, when the teacher in the previous example chose both levels with 1 point, the plain sum would be 2 points. But that is actually the lowest possible score so it maps to the grade 0 in Moodle.
SELECT u.username, (SELECT COUNT(*) FROM prefix_badge_issued AS d WHERE d.userid = u.id) AS earned
TIP: To avoid confusion from this sort of thing, we recommend including a level with 0 points in every rubric criterion."
FROM prefix_user AS u
ORDER BY earned DESC, u.username ASC
</code>


=== Manage badges (System & Course) ===
This report identifies rubrics having criteria without a zero value level and the courses they live in. This also refines to only assignments with active rubrics that are visible to students in the course. Links to the each rubric id is the direct link to edit the rubric. Fix by adding a zero level for each criteria that is missing it. In general, the grading changes that result will be in the students' favor.


List system wide badges, course and system level badges + a link to relevant "manage badges" page.
Includes search filter of course idnumber.


<code sql>
<syntaxhighlight lang="SQL">
SELECT b.id, b.name, b.description
SELECT cat.name AS Department, concat('<a target="_new" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',
,CASE
c.id,'">',c.idnumber,'</a>') AS Course_ID,
  WHEN b.type = 1 THEN 'System'
c.fullname AS Course_Name,
  WHEN b.type = 2 THEN 'Course'
concat('<a target="_new" href="%%WWWROOT%%/grade/grading/form/rubric/edit.php',CHAR(63),'areaid=',gd.areaid,'">',gd.areaid,'</a>') AS Rubric
END AS Level
FROM prefix_course AS c
,CONCAT('<a target="_new" href="%%WWWROOT%%/badges/index.php?type=', b.type, '&id=',
JOIN prefix_course_categories AS cat
  c.id, '">Manage badges in: ', c.fullname, '</a>') AS Manage
ON cat.id = c.category
FROM prefix_badge AS b
JOIN prefix_course_modules AS cm
JOIN prefix_course AS c ON c.id = b.courseid
ON c.id=cm.course
</code>
JOIN prefix_context AS ctx
 
ON cm.id = ctx.instanceid
==Administrator Reports==
JOIN prefix_grading_areas AS garea
 
ON ctx.id = garea.contextid
===Config changes in Export friendly form===
JOIN prefix_grading_definitions AS gd
 
ON garea.id = gd.areaid
The Administrative report Config changes is very useful but it would be nice to have it in a format that could be easily exported in one listing. Here is code to do that.
JOIN prefix_gradingform_rubric_criteria AS crit
 
ON gd.id = crit.definitionid
<code sql>
JOIN prefix_gradingform_rubric_levels AS levels
SELECT
ON levels.criterionid = crit.id
DATE_FORMAT( FROM_UNIXTIME( g.timemodified ) , '%Y-%m-%d' ) AS date,
WHERE cm.visible='1' AND garea.activemethod = 'rubric' AND (crit.id NOT IN
u.username AS user,
(SELECT crit.id
g.name AS setting,
FROM prefix_gradingform_rubric_criteria AS crit
CASE
JOIN prefix_gradingform_rubric_levels AS levels
WHEN g.plugin IS NULL THEN "core"
ON levels.criterionid = crit.id WHERE levels.score = '0'))
ELSE g.plugin
END AS plugin,
g.value AS new_value,
g.oldvalue AS original_value
FROM prefix_config_log  AS g
JOIN prefix_user AS u ON g.userid = u.id
ORDER BY date DESC
</code>


===Cohorts by user===
GROUP BY Rubric
ORDER BY Course_ID, Rubric


How to get a list of all users and which cohorts they belong to.
%%FILTER_SEARCHTEXT:c.idnumber:~%%
</syntaxhighlight>


<code sql>
===Who is using "Single File Upload" assignment===
SELECT u.firstname, u.lastname, h.idnumber, h.name
<syntaxhighlight lang="SQL">
FROM prefix_cohort AS h
JOIN prefix_cohort_members AS hm ON h.id = hm.cohortid
JOIN prefix_user AS u ON hm.userid = u.id
ORDER BY u.firstname
</code>
 
 
===Courses created And Active courses by Year===
Active courses is counting course that have at least one Hit, And "Active_MoreThan100Hits" counts courses that have at least 100 Hits
<code sql>
SELECT  
SELECT  
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher


YEAR( FROM_UNIXTIME( `timecreated` ) ) AS YEAR, COUNT( * ) AS Counter
,ass.name as "Assignment Name"


, (SELECT COUNT( DISTINCT course )
FROM  
FROM prefix_log AS l
prefix_assignment as ass
WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
) AS "Active"


,(SELECT COUNT(*) FROM (
JOIN
SELECT COUNT( * ),time
prefix_course as c ON c.id = ass.course
FROM prefix_log AS l
GROUP BY course
HAVING COUNT(*) > 100) AS courses_log
WHERE YEAR( FROM_UNIXTIME( courses_log.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
) AS "Active_MoreThan100Hits"


FROM `prefix_course`  
WHERE `assignmenttype` LIKE 'uploadsingle'
GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )
</syntaxhighlight>
</code>


===Users created And Active users by Year===
==Feedback Module Reports==
Active users is counting users that have at least one Hit, And "Active_MoreThan500Hits" counts users that have at least 500 Hits
===List the answers to all the Feedback activities within the current course, submitted by the current user===
<code sql>
<syntaxhighlight lang="SQL">
SELECT
SELECT /* crs.fullname as "Course name", f.name AS "Journal name", CONCAT(u.firstname,' ',UPPER(u.lastname)) as "Participant", */ /* include these fields if you want to check the composition of the recordset */
DATE_FORMAT(FROM_UNIXTIME(c.timemodified),'%W %e %M, %Y') as "Answer Date",
CASE i.typ WHEN 'label' THEN i.presentation ELSE i.name END as "Topic",  /* usually labels are used as section titles, so you'd want them present in the recordset */
v.value as "My Answer"


YEAR( FROM_UNIXTIME( `firstaccess` ) ) AS YEAR, COUNT( * ) AS Counter
FROM prefix_feedback AS f
INNER JOIN prefix_course as crs on crs.id=f.course %%FILTER_COURSES:f.course%%
INNER JOIN prefix_feedback_item AS i ON f.id=i.feedback
INNER JOIN prefix_feedback_completed AS c on f.id=c.feedback %%FILTER_COURSEUSER:c.userid%%
LEFT JOIN prefix_feedback_value AS v on v.completed=c.id AND v.item=i.id
INNER JOIN prefix_user AS u on c.userid=u.id


, (SELECT COUNT( DISTINCT userid )
WHERE c.id = %%COURSEID%% AND u.id = %%USERID%%  AND c.anonymous_response = 1  /* This clause limits the recordset to the current course and the current user and includes/ excludes the anonymous responses as needed */
FROM prefix_log AS l
WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `firstaccess` ) )
) AS "Active"


,(SELECT COUNT(*) FROM (
ORDER BY f.id, c.timemodified, i.id
SELECT COUNT( * ),time
</syntaxhighlight>
FROM prefix_log AS l
GROUP BY userid
HAVING COUNT(*) > 500) AS users_log
WHERE YEAR( FROM_UNIXTIME( users_log.`time` ) ) = YEAR( FROM_UNIXTIME( `firstaccess` ) )
) AS "Active_MoreThan500Hits"


FROM `prefix_user`
===Show all Feedbacks from all courses for all users including showing names of anonymous users===
GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )
</code>


===Course Aggregation Report===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
Contributed by Elizabeth Dalton, Granite State College
 
Shows all Feedbacks in all Courses with all multi-choice questions and answers of all users including showing the username of anonymous users. Also shows truly anonymous users on the front page as 'Not-logged-in' users. This is a rough report, not a pretty report, and is limited to multiple-choice type questions, but is shows the answer number and the list of possible answers in raw form. I post it here as a basis for further reports, and also as away to get the identities of anonymous users if needed.
 
<syntaxhighlight lang="SQL">
SELECT
c.shortname AS Course,
f.name AS Feedback,
# i.id AS Itemid,
i.name AS Itemname,
i.label AS Itemlabel,
CASE
WHEN f.anonymous = 1 AND u.id != 0 THEN CONCAT(u.username, ' :ANON')
WHEN fc.userid = 0 THEN 'Not-logged-in'
ELSE u.username
END AS 'User',
DATE_FORMAT(FROM_UNIXTIME(fc.timemodified),'%Y-%m-%d %H:%i') AS "Completed",
v.value AS "Choice",
CASE
WHEN i.typ = 'multichoice' THEN
    IF (  SUBSTRING(i.presentation,1,6)='d>>>>>',
      SUBSTRING(i.presentation,7),
  i.presentation)
ELSE i.presentation
END AS "Answers",
i.typ,
i.dependitem,
i.dependvalue


If you are considering upgrading from Moodle 2.6 to 2.8 or later, your grades may be changed. This report can help quantify and identify the courses at risk of changes.
FROM prefix_feedback f
JOIN prefix_course c ON c.id=f.course
JOIN prefix_feedback_item AS i ON f.id=i.feedback
JOIN prefix_feedback_completed fc ON f.id=fc.feedback
LEFT JOIN prefix_feedback_value v ON v.completed=fc.id AND v.item=i.id
LEFT JOIN prefix_user AS u ON fc.userid=u.id
WHERE i.typ != 'pagebreak'
</syntaxhighlight>


In particular, be on the lookout for any courses with the following combinations of parameters, which are known to cause changes in calculations:


# mean of grades set with aggregate with subcategory.
===Show all Feedbacks from all courses for all users with their answers===
# Simple weighted mean of grades with aggregate with sub category and drop the lowest
# Sum of grades drop the lowest


Also review:
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
https://tracker.moodle.org/browse/MDL-48618
https://tracker.moodle.org/browse/MDL-48634
https://tracker.moodle.org/browse/MDL-49257
https://tracker.moodle.org/browse/MDL-50089
https://tracker.moodle.org/browse/MDL-50062


<code sql>
Shows all Feedbacks in all Courses with all multi-choice questions and answers of all users for multi-choice questions. It shows the possible answers, the number of the chosen answer and the text of the chosen answer by the user. As always, I disavow any prettiness here and you should update the fields as you need.
SELECT


COUNT(c.shortname) AS 'Count of Courses'
Known to work in Moodle 3.5 to 3.10.


# If you want to display all the courses for each aggregation type, uncomment the next line and change GROUP BY settings
<syntaxhighlight lang="SQL">
#, c.shortname AS 'course name'
SELECT
c.fullname as "Course",
f.name AS "Feedback",  
CONCAT(u.firstname,'  ',u.lastname) as "User",
DATE_FORMAT(FROM_UNIXTIME(fc.timemodified), '%Y-%m-%d %H:%i') AS "When",
IF(i.typ = 'label', i.presentation, i.name) AS "Question",
# answers presentation string starts with these 6 characters:  r>>>>>
CASE WHEN i.typ = 'multichoice' THEN SUBSTRING(i.presentation,7) END AS "Possible Answers",


# If you need to display grade categories for each aggregation type, uncomment the next line and change GROUP BY settings
CASE i.typ WHEN 'multichoice' THEN v.value ELSE '-' END AS "Chosen Answer Num",
#, gc.fullname AS 'grade category name'
CASE v.value
  WHEN 1 THEN SUBSTRING(i.presentation, 7, POSITION('|' IN i.presentation) - 7)
  WHEN 2 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',2), '|',-1)
  WHEN 3 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',3), '|',-1)
  WHEN 4 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',4), '|',-1)
  WHEN 5 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',5), '|',-1)
  WHEN 6 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',6), '|',-1)
  WHEN 7 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',7), '|',-1)
  WHEN 8 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',8), '|',-1)
  WHEN 9 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',9), '|',-1)
  ELSE CONCAT("More:", v.value)
END AS "Chosen Answer Text"
FROM prefix_feedback AS f
JOIN prefix_course AS c ON c.id=f.course
JOIN prefix_feedback_item AS i ON f.id=i.feedback
JOIN prefix_feedback_completed AS fc ON f.id=fc.feedback
LEFT JOIN prefix_feedback_value AS v ON v.completed=fc.id AND v.item=i.id
JOIN prefix_user AS u ON fc.userid=u.id


, gc.aggregation AS 'aggregation method'
WHERE i.typ IN ('label', 'multichoice')


#These aggregation text strings appear to be hard-coded. I couldn't find a table for them. If you have aggregation types I haven't included here, they'll be blank in your report results.
</syntaxhighlight>
, CASE gc.aggregation
  WHEN 0 THEN 'Mean of Grades'
  WHEN 2 THEN 'Median of Grades'
  WHEN 6 THEN 'Highest Grade'
  WHEN 8 THEN 'Mode of Grades'
  WHEN 10 THEN 'Weighted Mean of Grades'
  WHEN 11 THEN 'Simple Weighted Mean of Grades'
  WHEN 12 THEN 'Mean of Grades (with extra credits)'
  WHEN 13 THEN 'Sum of Grades'
END AS 'aggregation name'


# Note that gc.aggregatesubcats column is eliminated in 2.8 and later per MDL-47503, so comment that line on updated systems or you'll get an error
==Resource Module Reports==
, gc.keephigh AS 'keep high'
===List "Recently uploaded files"===
, gc.droplow AS 'dr0p low'
see what users are uploading
, gc.aggregateonlygraded AS 'Aggregate only graded'
<syntaxhighlight lang="SQL">
, gc.aggregateoutcomes AS 'aggregate outcomes'
SELECT FROM_UNIXTIME(time,'%Y %M %D %h:%i:%s') as time ,ip,userid,url,info 
, gc.aggregatesubcats AS 'aggregate subcategories'
FROM `prefix_log`
WHERE `action` LIKE 'upload'
ORDER BY `prefix_log`.`time`  DESC
</syntaxhighlight>
 
===List Courses that loaded a specific file: "X"===
Did the Teacher (probably) uploaded course's Syllabus ?
<syntaxhighlight lang="SQL">
SELECT c.id, c.fullname  FROM `prefix_log` as l
JOIN prefix_course as c ON c.id = l.course
WHERE `action` LIKE '%upload%' AND ( info LIKE '%Syllabus%' OR info LIKE '%Sylabus%' ) GROUP BY c.id
</syntaxhighlight>
 
===All resources that link to some specific external website===
+ link to course
+ who's the teacher
+ link to external resource
<syntaxhighlight lang="SQL">
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,c.shortname,r.name
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
,concat('<a target="_new" href="%%WWWROOT%%/mod/resource/view.php?id=',r.id,'">',r.name,'</a>') AS Resource
FROM prefix_resource AS r
JOIN prefix_course AS c ON r.course = c.id
WHERE r.reference LIKE 'http://info.oranim.ac.il/home%'
</syntaxhighlight>
 
==="Compose Web Page" RESOURCE count===
<syntaxhighlight lang="SQL">
SELECT course,prefix_course.fullname, COUNT(*) AS Total
FROM `prefix_resource`
JOIN `prefix_course` ON prefix_course.id = prefix_resource.course
WHERE type='html'
GROUP BY course
</syntaxhighlight>
 
===Resource count in courses===
+ (First)Teacher name
+ Where course is inside some specific Categories
<syntaxhighlight lang="SQL">
SELECT
COUNT(*) AS count
,r.course
,c.shortname shortname
,c.fullname coursename
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user as u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = r.course AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
FROM prefix_resource r
JOIN prefix_course c ON r.course = c.id
WHERE c.category IN (10,13,28,18,26)
GROUP BY r.course
ORDER BY COUNT(*) DESC
</syntaxhighlight>
 
===Delete all the automated backup files===
Prepare bash cli script to delete all the automated backup files on the file system. (clean up some disk space)
<syntaxhighlight lang="SQL">
SELECT CONCAT( 'rm -f /var/moodledatanew/filedir/', SUBSTRING( contenthash, 1, 2 ) , '/', SUBSTRING( contenthash, 3, 2 ) , '/', contenthash )
FROM `mdl_files`
WHERE `filename` LIKE '%mbz%'
AND filearea = 'automated'
</syntaxhighlight>
 
Find out how much disk space is used by all automated backup files:
<syntaxhighlight lang="SQL">
SELECT SUM(filesize)/(1024*1024*1024) FROM `mdl_files` WHERE  `filename` LIKE '%mbz%' AND filearea =  'automated'
</syntaxhighlight>
 
==Forum Module Reports==
===print all User's post in course Forums===
%%COURSEID%% is a variable the is replace by the current CourseID you are running the sql report from. if you are using the latest block/configurable_reports ! (You can always change it to a fixed course or remove it to display all courses.)
<syntaxhighlight lang="SQL">
SELECT
concat('<a target="_new" href="%%WWWROOT%%/mod/forum/user.php?course=',c.id,'&id=',u.id,'&mode=posts">',CONCAT(u.firstname,' ', u.lastname),'</a>') As Fullname
,concat('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',fd.forum,'">',f.name,'</a>') AS Forum
,count(*) as Posts
,(SELECT count(*) FROM prefix_forum_discussions AS ifd JOIN prefix_forum as iforum ON iforum.id = ifd.forum  WHERE ifd.userid = fp.userid AND iforum.id = f.id) AS cAllDiscussion
 
FROM prefix_forum_posts AS fp
JOIN prefix_user as u ON u.id = fp.userid
JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id
JOIN prefix_forum AS f ON f.id = fd.forum
JOIN prefix_course as c ON c.id = fd.course
WHERE fd.course = %%COURSEID%%
GROUP BY f.id,u.id
ORDER BY u.id
</syntaxhighlight>
 
===FORUM use Count per COURSE -- not including NEWS Forum!===
<syntaxhighlight lang="SQL">
SELECT prefix_course.fullname, prefix_forum.course, count(*) as total FROM prefix_forum
INNER JOIN prefix_course
ON prefix_course.id = prefix_forum.course
WHERE NOT(prefix_forum.type = 'news')
GROUP BY prefix_forum.course
ORDER BY total desc
</syntaxhighlight>
 
===FORUM use Count per COURSE by type -- not including NEWS Forum!===
<syntaxhighlight lang="SQL">
SELECT prefix_course.fullname, prefix_forum.course, prefix_forum.type, count(*) as total FROM prefix_forum
INNER JOIN prefix_course
ON prefix_course.id = prefix_forum.course
WHERE NOT(prefix_forum.type = 'news')
GROUP BY prefix_forum.course,prefix_forum.type
ORDER BY total desc
</syntaxhighlight>
 
===Forum activity - system wide===
<syntaxhighlight lang="SQL">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS CourseID
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
,c.fullname as Course
,f.type
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
, fd.forum, f.name,count(*) AS cPostAndDisc
,(SELECT count(*) FROM prefix_forum_discussions AS ifd WHERE ifd.forum = f.id) AS cDiscussion
FROM prefix_forum_posts AS fp
JOIN prefix_forum_discussions AS fd ON fd.id = fp.discussion
JOIN prefix_forum AS f ON f.id = fd.forum
JOIN prefix_course AS c ON c.id = f.course
WHERE f.type != 'news' AND c.fullname LIKE '%2013%'
## WHERE 1=1
## %%FILTER_YEARS:c.fullname%%
## You can enable the SEMESTER filter as well,
## by uncommenting the following line:
## %%FILTER_SEMESTERS:c.fullname%%
 
GROUP BY fd.forum
ORDER BY count( * ) DESC
</syntaxhighlight>
 
===Activity In Forums===
Trying to figure out how much real activity we have in Forums by aggregating:
Users in Course, Number of Posts, Number of Discussions, Unique student post, Unique student discussions, Number of Teachers , Number of Students, ratio between unique Student posts and the number of students in the Course...
<syntaxhighlight lang="SQL">
SELECT c.fullname,f.name,f.type
,(SELECT count(id) FROM prefix_forum_discussions as fd WHERE f.id = fd.forum) as Discussions
,(SELECT count(distinct fd.userid) FROM prefix_forum_discussions as fd WHERE fd.forum = f.id) as UniqueUsersDiscussions
,(SELECT count(fp.id) FROM prefix_forum_discussions fd JOIN prefix_forum_posts as fp ON fd.id = fp.discussion WHERE f.id = fd.forum) as Posts
,(SELECT count(distinct fp.userid) FROM prefix_forum_discussions fd JOIN prefix_forum_posts as fp ON fd.id = fp.discussion WHERE f.id = fd.forum) as UniqueUsersPosts
,(SELECT Count( ra.userid ) AS Students
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid =5
AND ctx.instanceid = c.id
) AS StudentsCount
,(SELECT Count( ra.userid ) AS Teachers
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid =3
AND ctx.instanceid = c.id
) AS 'Teacher<br/>Count'
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid IN (3,5)
AND ctx.instanceid = c.id
) AS UserCount
, (SELECT (UniqueUsersDiscussions / StudentsCount )) as StudentDissUsage
, (SELECT (UniqueUsersPosts /StudentsCount)) as StudentPostUsage
FROM prefix_forum as f
JOIN prefix_course as c ON f.course = c.id
WHERE `type` != 'news'
ORDER BY StudentPostUsage DESC
</syntaxhighlight>
 
===All Forum type:NEWS===
<syntaxhighlight lang="SQL">
SELECT f.id, f.name
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_forum AS f ON cm.instance = f.id
WHERE m.name = 'forum'
AND f.type = 'news'
</syntaxhighlight>
 
===All new forum NEWS items (discussions) from all my Courses===
change "userid = 26" and "id = 26" to a new user id
<syntaxhighlight lang="SQL">
SELECT c.shortname,f.name,fd.name,FROM_UNIXTIME(fd.timemodified ,"%d %M %Y ") as Date
FROM prefix_forum_discussions as fd
JOIN prefix_forum as f ON f.id = fd.forum
JOIN prefix_course as c ON c.id = f.course
JOIN prefix_user_lastaccess as ul ON (c.id = ul.courseid AND ul.userid = 26)
WHERE fd.timemodified > ul.timeaccess 
AND fd.forum IN (SELECT f.id
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_forum AS f ON cm.instance = f.id
WHERE m.name = 'forum'
AND f.type = 'news')
  AND c.id IN (SELECT c.id
  FROM prefix_course AS c
  JOIN prefix_context AS ctx ON c.id = ctx.instanceid
  JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
  JOIN prefix_user AS u ON u.id = ra.userid
  WHERE u.id = 26) ORDER BY `fd`.`timemodified` DESC
</syntaxhighlight>
 
 
===News Forum - Discussions COUNT===
Which is actually... How much instructions students get from their teachers
<syntaxhighlight lang="SQL">
SELECT c.shortname ,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
,concat('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',fd.forum,'">',count(fd.id),'</a>') AS DiscussionsSum
FROM prefix_forum_discussions AS fd
INNER JOIN prefix_forum AS f ON f.id = fd.forum
INNER JOIN prefix_course AS c ON c.id = f.course
WHERE f.type = 'news' AND c.category IN (10,13,28,18,26)
GROUP BY fd.forum
ORDER BY count(fd.id) DESC
</syntaxhighlight>
 
===Cantidad de foros que han sido posteados por profesor===
 
(Number of forums that have been posted by teacher/Google translator)
 
Queriamos saber cuales son las acciones del profesor dentro de los foros de cada curso, por ello se hizo este informe.
 
(We wanted to know what the teacher's actions are in the forums of each course, so this report was made. /Google translator)
<syntaxhighlight lang="SQL">
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS curso,
CONCAT(u.firstname ,' ',u.lastname) AS Facilitador,
 
(SELECT COUNT( m.name ) AS COUNT FROM
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%forum%') AS foros,
 
COUNT(*) AS Posts
 
FROM prefix_forum_posts AS fp
JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id
JOIN prefix_forum AS f ON f.id = fd.forum
JOIN prefix_course AS c ON c.id = fd.course
JOIN prefix_user AS u ON u.id = fp.userid
 
WHERE fp.userid =
(
select distinct prefix_user.id
from prefix_user
join prefix_role_assignments as ra on ra.userid = prefix_user.id
where ra.roleid = 3
and userid = fp.userid
limit 1
)
 
and c.shortname like '%2014-2-1%'
GROUP BY c.id, u.id
</syntaxhighlight>
 
 
===List all the Posts in all the Forums that got high rating===
We setup a scale that let teachers and students Rate forum post with "Important, interesting, valuable, not rated" scale
And then add a link to the following report at the begining of the course "Link to all interesting posts"
<syntaxhighlight lang="SQL">
SELECT
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',f.id,'">',f.name,'</a>') AS 'Forum name,
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/discuss.php?d=',fd.id,'#p',fp.id,'">',fp.subject,'</a>') AS 'Post link',
SUM(r.rating) AS 'Rating'
FROM mdl_rating AS r
  JOIN mdl_forum_posts AS fp ON fp.id = r.itemid
  JOIN mdl_forum_discussions AS fd ON fd.id = fp.discussion
  JOIN mdl_forum AS f ON f.id = fd.forum
WHERE r.component = 'mod_forum' AND r.ratingarea = 'post' AND f.course = %%COURSEID%%
GROUP BY r.itemid
ORDER BY SUM(r.rating) DESC
</syntaxhighlight>
 
===List all the Posts in all Discussions of a single Forum===
This report is used to help export all the student's posts and discussions of a single forum, by passing the course module id as a parameter to the report using "&filter_var=cmid"
<syntaxhighlight lang="SQL">
SELECT
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=', f.id, '">', f.name, '</a>') AS 'Forum name',
fd.name AS 'Discussion',
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/discuss.php?d=', fd.id, '#p', fp.id, '">', fp.subject, '</a>') AS 'Post (link)',
fp.message
 
FROM mdl_forum_posts AS fp
  JOIN mdl_forum_discussions AS fd ON fd.id = fp.discussion
  JOIN mdl_forum AS f ON f.id = fd.forum
  JOIN mdl_course_modules AS cm ON cm.module = 9 AND cm.instance = f.id
WHERE cm.id = %%FILTER_VAR%%
ORDER BY f.id, fd.id
</syntaxhighlight>
 
==Quiz Module Reports==
===Generate a list of instructors and their email addresses for those courses that has "essay questions" in their quizzes===
<syntaxhighlight lang="SQL">
SELECT qu.id AS quiz_id, qu.course AS course_id, qu.questions,
                co.fullname AS course_fullname, co.shortname AS course_shortname,
                qu.name AS quiz_name, FROM_UNIXTIME(qu.timeopen) AS quiz_timeopen, FROM_UNIXTIME(qu.timeclose) AS quiz_timeclose,
                u.firstname, u.lastname, u.email,
FROM prefix_quiz qu, prefix_course co, prefix_role re, prefix_context ct, prefix_role_assignments ra, prefix_user u
WHERE FROM_UNIXTIME(timeopen) > '2008-05-14' AND
                qu.course = co.id AND
                co.id = ct.instanceid AND
                ra.roleid = re.id AND
                re.name = 'Teacher' AND
                ra.contextid = ct.id AND
                ra.userid = u.id
SELECT Count('x') As NumOfStudents
                                FROM prefix_role_assignments a
                                JOIN prefix_user u ON userid = u.id
                                WHERE roleid = 5 AND contextid = (SELECT id FROM prefix_context WHERE instanceid = 668 AND contextlevel = 50)
</syntaxhighlight>
 
===Number of Quizes per Course===
<syntaxhighlight lang="SQL">
SELECT count(*)
,concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">Link</a>') AS Quizes
 
FROM prefix_course_modules cm
JOIN prefix_course c ON c.id = cm.course
JOIN prefix_modules as m ON m.id = cm.module
WHERE m.name LIKE 'quiz'
GROUP BY c.id
</syntaxhighlight>
 
===List all MultiAnswer (Cloze) Questions===
<syntaxhighlight lang="SQL">
SELECT concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/attempt.php?q=', quiz.id, '">', quiz.name, '</a>') AS Quiz
,question.id question_id, question.questiontext
FROM  prefix_question question
JOIN prefix_quiz_question_instances qqi ON question.id = qqi.question
JOIN prefix_quiz quiz ON qqi.quiz = quiz.id
WHERE  `qtype` LIKE  'multianswer'
</syntaxhighlight>
 
===List courses with MANUAL grades===
Which is basically and indication to teachers using Moodle to hold offline grades inside Moodle's Gradebook,
So grades could be uploaded into an administrative SIS. Use with Configurable Reports.
<syntaxhighlight lang="SQL">
SELECT COUNT( * )
,concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php?showadvanced=1&id=',c.id,'">',c.fullname,'</a>') AS Course
FROM  prefix_grade_items AS gi
JOIN prefix_course as c ON c.id = gi.courseid
WHERE  `itemtype` =  'manual'
GROUP BY courseid
</syntaxhighlight>
===List the users that did not take the Quiz===
Do not forget to change "c.id = 14" and q.name LIKE '%quiz name goes here%'
<syntaxhighlight lang="SQL">
SELECT
user2.id AS ID,
ul.timeaccess,
user2.firstname AS Firstname,
user2.lastname AS Lastname,
user2.email AS Email,
user2.username AS IDNumber,
user2.institution AS Institution,
IF (user2.lastaccess = 0,'never',
DATE_FORMAT(FROM_UNIXTIME(user2.lastaccess),'%Y-%m-%d')) AS dLastAccess
,(SELECT DATE_FORMAT(FROM_UNIXTIME(timeaccess),'%Y-%m-%d') FROM prefix_user_lastaccess WHERE userid=user2.id AND courseid=c.id) AS CourseLastAccess
,(SELECT r.name
FROM  prefix_user_enrolments AS uenrol
JOIN prefix_enrol AS e ON e.id = uenrol.enrolid
JOIN prefix_role AS r ON e.id = r.id
WHERE uenrol.userid=user2.id AND e.courseid = c.id) AS RoleName
FROM prefix_user_enrolments AS ue
JOIN prefix_enrol AS e ON e.id = ue.enrolid
JOIN prefix_course AS c ON c.id = e.courseid
JOIN prefix_user AS user2 ON user2 .id = ue.userid
LEFT JOIN prefix_user_lastaccess AS ul ON ul.userid = user2.id
WHERE c.id=14 and ue.userid NOT IN (SELECT qa.userid FROM prefix_quiz_attempts AS qa
JOIN prefix_quiz AS q ON qa.quiz = q.id
JOIN prefix_course AS c ON q.course = c.id
WHERE c.id = 14 AND q.name LIKE '%quiz name goes here%')
</syntaxhighlight>
 
===List Questions in each Quiz===
 
<syntaxhighlight lang="SQL">
SELECT quiz.id,quiz.name, q.id, q.name
FROM mdl_quiz AS quiz
JOIN mdl_question AS q ON FIND_IN_SET(q.id, quiz.questions)
WHERE quiz.course = %%COURSEID%%
ORDER BY quiz.id ASC
</syntaxhighlight>
 
Note: this query does not work in Moodle 2.8+. There is no mdl_quiz.questions field. It will need to be rewritten to use the usage/contextid organization.
 
Here is a version for Moodle 3.x
 
<syntaxhighlight lang="SQL">
SELECT cm.id 'cmid', quiz.id 'quiz id'
,CONCAT('<a target="_new" href="%%WWWROOT%%/mod/quiz/edit.php?cmid=',
  cm.id, '">', quiz.name, '</a>') AS 'edit quiz'
,q.id 'qid', q.name 'question name'
FROM mdl_quiz AS quiz
JOIN mdl_course_modules cm ON cm.instance = quiz.id AND cm.module = 33 # 33=quiz mdl_modules
JOIN mdl_quiz_slots qs ON qs.quizid = quiz.id
JOIN mdl_question AS q ON q.id = qs.questionid
WHERE quiz.course = %%COURSEID%%
ORDER BY quiz.id ASC
</syntaxhighlight>
 
===Quiz activity research===
This report was made to extract student full activity in quizzes for an academic research about adapting instructional design teaching methods in online learning. The students do not use the Quiz module as a standard quiz but more as Study booklets or mini courses with embedded questions and hints to assist students evaluate their progress (Similar to what you expect to find in a SCORM activity)
 
<syntaxhighlight lang="SQL">
SELECT
cm.course "course_id", cm.id "moduel_id", q.id "quiz_id", q.name "quiz_name",
CASE q.grademethod
      WHEN 1 THEN "GRADEHIGHEST"
      WHEN 2 THEN "GRADEAVERAGE"
      WHEN 3 THEN "ATTEMPTFIRST"
      WHEN 4 THEN "ATTEMPTLAST"
END "grade method"
 
, q.attempts "quiz_attempts_allowed", cm.groupmode "group_mode"
, qa.id "attempt_id", qa.state "attempt_state", qa.sumgrades "attempt_grade", qg.grade "user_final_grade", q.grade "quiz_max_grade"
,(SELECT GROUP_CONCAT(g.name) FROM mdl_groups AS g
JOIN mdl_groups_members AS m ON g.id = m.groupid WHERE g.courseid = q.course AND m.userid = u.id) "user_groups",
DATE_FORMAT(FROM_UNIXTIME(qa.timestart), '%d-%m-%Y %h:%k') "attempt_start",
DATE_FORMAT(FROM_UNIXTIME(qa.timefinish), '%d-%m-%Y %h:%k') "attempt_finish",
u.id "user_id", u.firstname, u.lastname,
question.id "question_id", question.name "question_name",
qas.state "question_step_state",qas.fraction "question_grade", qh.hint, question.qtype "question_type"
 
FROM mdl_quiz as q
JOIN mdl_course_modules as cm ON cm.instance = q.id and cm.module = 14
JOIN mdl_quiz_attempts qa ON q.id = qa.quiz
LEFT JOIN mdl_quiz_grades as qg ON qg.quiz = q.id and qg.userid = qa.userid
JOIN mdl_user as u ON u.id = qa.userid
JOIN mdl_question_usages as qu ON qu.id = qa.uniqueid
JOIN mdl_question_attempts as qatt ON qatt.questionusageid = qu.id
JOIN mdl_question as question ON question.id = qatt.questionid
JOIN mdl_question_attempt_steps as qas ON qas.questionattemptid = qatt.id
LEFT JOIN mdl_question_hints as qh ON qh.questionid = q.id
#WHERE q.id = "SOME QUIZ ID"
WHERE cm.course = "SOME COURSE ID"
</syntaxhighlight>
 
===Quiz Usage in Courses by Date===
Contributed by Elizabeth Dalton, Granite State College
 
This report lists the courses containing quizzes with the course start date between the two values, and provides a summary of the types of questions in the quizzes in each course and whether question randomization and answer randomization functions were used.
 
"Multiple Choice" questions include true/false and matching question types.
 
"Short Answer" are questions that accept a single phrase.
 
"Other" questions include fixed numerical, calculated, essay, and various drag and drop types.
 
"Min Quiz Age" and "Max Quiz Age" provide data about the last modified date for the quizzes in the course, compared to the course start date. The values are expressed in units of days. A negative value indicates that a quiz was edited after the start of the course. A value greater than 90 days indicates that the quiz may have been used in an earlier term (cohort) without modification.
 
'''Note''': In Configurable Reports, the Date Filter is not applied until the "Apply" button is clicked.
 
<syntaxhighlight lang="SQL">
SELECT
 
c.shortname AS 'Course'
#, u.lastname AS 'Instructor'
, COUNT(DISTINCT q.id) AS 'Quizzes'
, COUNT(DISTINCT qu.id) AS 'Questions'
, SUM(IF (qu.qtype = 'multichoice', 1, 0 )) + SUM(IF (qu.qtype = 'truefalse', 1, 0 )) + SUM(IF (qu.qtype = 'match', 1, 0 ))  AS 'multichoice'
 
, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'
 
, COUNT( qu.id) - SUM(IF (qu.qtype = 'multichoice', 1, 0 )) - SUM(IF (qu.qtype = 'truefalse', 1, 0 )) - SUM(IF (qu.qtype = 'match', 1, 0 )) - SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'Other'
 
, (SUM(IF (qu.qtype = 'multichoice', 1, 0 )) + SUM(IF (qu.qtype = 'truefalse', 1, 0 )) + SUM(IF (qu.qtype = 'match', 1, 0 )))/COUNT( qu.id) AS 'Percent MC'
 
#, SUM(IF (qu.qtype = 'numerical', 1, 0 )) AS 'numerical'
#, SUM(IF (qu.qtype LIKE 'calc%', 1, 0 )) AS 'calculated'
#, SUM(IF (qu.qtype = 'random', 1, 0 )) AS 'random'
#, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'
#, SUM(IF (qu.qtype = 'essay', 1, 0 )) AS 'essay'
 
 
, IF(q.shufflequestions > 0,'Yes','No') AS 'Randomized Questions'
, IF(q.shuffleanswers > 0,'Yes','No') AS 'Randomized Answers'
#, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
#, FROM_UNIXTIME(MIN(q.timemodified)) AS 'Last Modified'
 
#, DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(MIN(q.timemodified))) AS 'Quiz age'
 
, MIN(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Min Quiz Age'
, MAX(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Max Quiz Age'
 
#, SUM(IF (DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified)) < 90, 1,0)) AS 'new quizzes'
 
FROM prefix_quiz AS q
JOIN prefix_course AS c on c.id = q.course
JOIN prefix_quiz_question_instances AS qqi ON qqi.quiz = q.id
LEFT JOIN prefix_question AS qu ON qu.id = qqi.question
 
WHERE
1
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.startdate:<%%
 
GROUP BY c.id
 
ORDER BY c.shortname
</syntaxhighlight>
 
===Student responses (answers) to quiz questions===
(Contributed by Juan F with help from Tim hunt and fellow Moodlers on the forums)
A report that targets a specific quiz for all of our Biology courses, a summary of all questions and how many students get them right/wrong.
<syntaxhighlight lang="SQL">
SELECT
    concat( u.firstname, " ", u.lastname ) AS "Student Name",
    u.id,
    quiza.userid,
    q.course,
    q.name,
    quiza.attempt,
    qa.slot,
    que.questiontext AS 'Question',
    qa.rightanswer AS 'Correct Answer',
    qa.responsesummary AS 'Student Answer'
 
FROM mdl_quiz_attempts quiza
JOIN mdl_quiz q ON q.id=quiza.quiz
JOIN mdl_question_usages qu ON qu.id = quiza.uniqueid
JOIN mdl_question_attempts qa ON qa.questionusageid = qu.id
JOIN mdl_question que ON que.id = qa.questionid
JOIN mdl_user u ON u.id = quiza.userid
 
WHERE q.name = "BIO 208 Post Test Assessment"
AND q.course = "17926"
 
ORDER BY quiza.userid, quiza.attempt, qa.slot
</syntaxhighlight>
 
===Questions which are tagged within a course/quiz===
Calculates subgrades for tags in the each of the quizzes in a course.
Contributed by Daniel Thies in https://moodle.org/mod/forum/discuss.php?d=324314#p1346542
 
<syntaxhighlight lang="SQL">
SELECT
    quiz.name AS quiz,
    t.rawname AS tag,
    CONCAT('<a target="_new" href="%%WWWROOT%%/mod/quiz/review.php?attempt=',
            MAX(quiza.id),'">',u.firstname,' ',u.lastname,'</a>') AS student,
    CAST(SUM(qas.fraction) as decimal(12,1)) AS correct,
    CAST(SUM(qa.maxmark) as decimal(12,1)) AS maximum,
    CAST(SUM(qas.fraction)/SUM(qa.maxmark)*100 as decimal(4,2)) AS score
FROM prefix_quiz_attempts quiza
JOIN prefix_user u ON quiza.userid = u.id
JOIN prefix_question_usages qu ON qu.id = quiza.uniqueid
JOIN prefix_question_attempts qa ON qa.questionusageid = qu.id
JOIN prefix_quiz quiz ON quiz.id = quiza.quiz
JOIN prefix_tag_instance ti ON qa.questionid = ti.itemid
JOIN prefix_tag t ON t.id = ti.tagid
JOIN (SELECT MAX(fraction) AS fraction, questionattemptid
        FROM prefix_question_attempt_steps
        GROUP BY questionattemptid) qas ON qas.questionattemptid = qa.id
WHERE quiz.course = %%COURSEID%%
GROUP BY quiza.userid,
    quiza.quiz,
    quiz.name,
    u.firstname,
    u.lastname,
    ti.tagid,
    t.rawname
ORDER BY quiza.quiz, t.rawname, u.lastname, u.firstname, score
</syntaxhighlight>
 
==SCORM Activity Reports==
 
===Lists All completed SCORM activites by Course name===
This report will list all completed attempts for all SCORM activities. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. Please note: the FROM_UNIXTIME command is for MySQL.
<syntaxhighlight lang="SQL">
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
FROM prefix_scorm_scoes_track AS st
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
WHERE st.value='completed'
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt
</syntaxhighlight>
 
===Lists SCORM status for all enrolled users by Course name===
This report will list the SCORM status for all users enrolled in the course. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. This can be limited to individual courses by adding to the where clause the course id to report on. 
<syntaxhighlight lang="SQL">
SELECT
u.firstname AS First,
u.lastname AS Last,
u.idnumber AS Employee_ID, 
u.city AS City,
uid.data AS State,
u.country AS Country,
g.name AS Group_name,
c.fullname AS Course,
st.attempt AS Attempt,
st.value AS Status,
FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") AS Date
 
FROM prefix_scorm_scoes_track AS st
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_groups_members AS m ON g.id = m.groupid
 
WHERE st.element='cmi.core.lesson_status' AND m.userid=u.id
 
UNION
 
SELECT
user2.firstname AS First,
user2.lastname AS Last,
user2. idnumber AS Employee_ID,
user2.city AS City,
uid.data AS State,
user2.country AS Country,
g.name AS Group_name,
c.fullname AS Course,
"-" AS Attempt,
"not_started" AS Status,
"-" AS Date
 
FROM prefix_user_enrolments AS ue
JOIN prefix_enrol AS e ON e.id = ue.enrolid
JOIN prefix_course AS c ON c.id = e.courseid
JOIN prefix_user AS user2 ON user2 .id = ue.userid
JOIN prefix_user_info_data AS uid ON uid.userid = user2.id
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_groups_members AS m ON g.id = m.groupid
JOIN prefix_scorm AS sc ON sc.course=c.id
Left Join prefix_scorm_scoes_track AS st on st.scormid=sc.id AND st.userid=user2.id
 
WHERE  st.timemodified IS NULL AND m.userid=user2.id
 
ORDER BY  Course, Last, First, Attempt
 
</syntaxhighlight>
 
== Badges==
 
=== All badges issued, by User ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
This report will show you all the badges on a site that have been issued, both site and all courses, by the username of each user issued a badge. Includes the type of criteria passed (activity, course completion, manual), date issued, date expires, and a direct link to that issued badge page so you can see all the other details for that badge.
 
<syntaxhighlight lang="SQL">
SELECT u.username, b.name AS badgename,
CASE
WHEN b.courseid IS NOT NULL THEN
(SELECT c.shortname
    FROM prefix_course AS c
    WHERE c.id = b.courseid)
WHEN b.courseid IS NULL THEN "*"
END AS Context,
CASE
  WHEN t.criteriatype = 1 AND t.method = 1 THEN "Activity Completion (All)"
  WHEN t.criteriatype = 1 AND t.method = 2 THEN "Activity Completion (Any)"
  WHEN t.criteriatype = 2 AND t.method = 2 THEN "Manual Award"
  WHEN t.criteriatype = 4 AND t.method = 1 THEN "Course Completion (All)"
  WHEN t.criteriatype = 4 AND t.method = 2 THEN "Course Completion (Any)"
  ELSE CONCAT ('Other: ', t.criteriatype)
END AS Criteriatype,
DATE_FORMAT( FROM_UNIXTIME( d.dateissued ) , '%Y-%m-%d' ) AS dateissued,
DATE_FORMAT( FROM_UNIXTIME( d.dateexpire ), '%Y-%m-%d' ) AS dateexpires,
CONCAT ('<a target="_new" href="%%WWWROOT%%/badges/badge.php?hash=',d.uniquehash,'">link</a>') AS Details
FROM prefix_badge_issued AS d
JOIN prefix_badge AS b ON d.badgeid = b.id
JOIN prefix_user AS u ON d.userid = u.id
JOIN prefix_badge_criteria AS t on b.id = t.badgeid
WHERE t.criteriatype <> 0
ORDER BY u.username
</syntaxhighlight>
 
Please note: the FROM_UNIXTIME command is for MySQL.
 
=== All badges available in the system, with Earned count ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
Report of all badges in the system, with badge name and description, context, course shortname if a course badge, whether it is active and available, and a count of how many users have been issued that badge.
 
<syntaxhighlight lang="SQL">
SELECT b.id, b.name, b.description,
CASE
WHEN b.type = 1 THEN "System"
WHEN b.type = 2 THEN "Course"
END AS Context,
CASE
WHEN b.courseid IS NOT NULL THEN
(SELECT c.shortname
    FROM prefix_course AS c
    WHERE c.id = b.courseid)
WHEN b.courseid IS NULL THEN "*"
END AS Course,
CASE
WHEN b.status = 0 OR b.status = 2 THEN "No"
WHEN b.status = 1 OR b.status = 3 THEN "Yes"
WHEN b.status = 4 THEN "x"
END AS Available,
CASE
WHEN b.status = 0 OR b.status = 1 THEN "0"
WHEN b.status = 2 OR b.status = 3 OR b.status = 4 THEN
(SELECT COUNT(*)
  FROM prefix_badge_issued AS d
  WHERE d.badgeid = b.id
)
END AS Earned
FROM prefix_badge AS b
 
</syntaxhighlight>
 
=== Badges Leaderboard ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
A simple list of usernames and how many badges they have earned overall.
 
<syntaxhighlight lang="SQL">
SELECT u.username, (SELECT COUNT(*) FROM prefix_badge_issued AS d WHERE d.userid = u.id) AS earned
FROM prefix_user AS u
ORDER BY earned DESC, u.username ASC
</syntaxhighlight>
 
=== Manage badges (System & Course) ===
 
List system wide badges, course and system level badges + a link to relevant "manage badges" page.
 
<syntaxhighlight lang="SQL">
SELECT b.id, b.name, b.description
,CASE
  WHEN b.type = 1 THEN 'System'
  WHEN b.type = 2 THEN 'Course'
END AS Level
,CONCAT('<a target="_new" href="%%WWWROOT%%/badges/index.php?type=', b.type, '&id=',
  c.id, '">Manage badges in: ', c.fullname, '</a>') AS Manage
FROM prefix_badge AS b
JOIN prefix_course AS c ON c.id = b.courseid
</syntaxhighlight>
 
==Administrator Reports==
 
===Config changes in Export friendly form===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
The Administrative report Config changes is very useful but it would be nice to have it in a format that could be easily exported in one listing. Here is code to do that.
 
<syntaxhighlight lang="SQL">
SELECT
DATE_FORMAT( FROM_UNIXTIME( g.timemodified ) , '%Y-%m-%d' ) AS date,
u.username AS user,
g.name AS setting,
CASE
WHEN g.plugin IS NULL THEN "core"
ELSE g.plugin
END AS plugin,
g.value AS new_value,
g.oldvalue AS original_value
FROM prefix_config_log  AS g
JOIN prefix_user AS u ON g.userid = u.id
ORDER BY date DESC
</syntaxhighlight>
 
===Cohorts by user===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
How to get a list of all users and which cohorts they belong to.
 
<syntaxhighlight lang="SQL">
SELECT u.firstname, u.lastname, h.idnumber, h.name
FROM prefix_cohort AS h
JOIN prefix_cohort_members AS hm ON h.id = hm.cohortid
JOIN prefix_user AS u ON hm.userid = u.id
ORDER BY u.firstname
</syntaxhighlight>
 
===Cohorts with Courses===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
List of all cohorts with name, id, visibility, and which courses they are enrolled in.
 
<syntaxhighlight lang="SQL">
SELECT
# h.id,
# e.customint1,
h.name AS Cohort,
h.idnumber AS Cohortid,
CASE
WHEN h.visible = 1 THEN 'Yes'
ELSE '-'
END AS Cohortvisible,
CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php', CHAR(63),'id=',c.id,'">',c.fullname,'</a>') AS Course
FROM prefix_cohort h
JOIN prefix_enrol e ON h.id = e.customint1
JOIN prefix_course c ON c.id = e.courseid %%FILTER_COURSES:e.courseid%%
WHERE e.enrol = 'cohort' AND e.roleid = 5
</syntaxhighlight>
 
===Courses created And Active courses by Year===
Active courses is counting course that have at least one Hit, And "Active_MoreThan100Hits" counts courses that have at least 100 Hits
<syntaxhighlight lang="SQL">
SELECT
 
YEAR( FROM_UNIXTIME( `timecreated` ) ) AS YEAR, COUNT( * ) AS Counter
 
, (SELECT COUNT( DISTINCT course )
FROM prefix_log AS l
WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
) AS "Active"
 
,(SELECT COUNT(*) FROM (
SELECT COUNT( * ),time
FROM prefix_log AS l
GROUP BY course
HAVING COUNT(*) > 100) AS courses_log
WHERE YEAR( FROM_UNIXTIME( courses_log.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
) AS "Active_MoreThan100Hits"
 
FROM `prefix_course`
GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )
</syntaxhighlight>
 
===Users created And Active users by Year===
Active users is counting users that have at least one Hit, And "Active_MoreThan500Hits" counts users that have at least 500 Hits
<syntaxhighlight lang="SQL">
SELECT
 
YEAR( FROM_UNIXTIME( `firstaccess` ) ) AS YEAR, COUNT( * ) AS Counter
 
, (SELECT COUNT( DISTINCT userid )
FROM prefix_log AS l
WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `firstaccess` ) )
) AS "Active"
 
,(SELECT COUNT(*) FROM (
SELECT COUNT( * ),time
FROM prefix_log AS l
GROUP BY userid
HAVING COUNT(*) > 500) AS users_log
WHERE YEAR( FROM_UNIXTIME( users_log.`time` ) ) = YEAR( FROM_UNIXTIME( `firstaccess` ) )
) AS "Active_MoreThan500Hits"
 
FROM `prefix_user`
GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )
</syntaxhighlight>
 
===Course Aggregation Report===
Contributed by Elizabeth Dalton, Granite State College
 
If you are considering upgrading from Moodle 2.6 to 2.8 or later, your grades may be changed. This report can help quantify and identify the courses at risk of changes.
 
In particular, be on the lookout for any courses with the following combinations of parameters, which are known to cause changes in calculations:
 
# mean of grades set with aggregate with subcategory.
# Simple weighted mean of grades with aggregate with sub category and drop the lowest
# Sum of grades drop the lowest
 
Also review:
https://tracker.moodle.org/browse/MDL-48618
https://tracker.moodle.org/browse/MDL-48634
https://tracker.moodle.org/browse/MDL-49257
https://tracker.moodle.org/browse/MDL-50089
https://tracker.moodle.org/browse/MDL-50062
 
<syntaxhighlight lang="SQL">
SELECT
 
COUNT(c.shortname) AS 'Count of Courses'
 
# If you want to display all the courses for each aggregation type, uncomment the next line and change GROUP BY settings
#, c.shortname AS 'course name'
 
# If you need to display grade categories for each aggregation type, uncomment the next line and change GROUP BY settings
#, gc.fullname AS 'grade category name'
 
, gc.aggregation AS 'aggregation method'
 
#These aggregation text strings appear to be hard-coded. I couldn't find a table for them. If you have aggregation types I haven't included here, they'll be blank in your report results.
, CASE gc.aggregation
  WHEN 0 THEN 'Mean of Grades'
  WHEN 2 THEN 'Median of Grades'
  WHEN 6 THEN 'Highest Grade'
  WHEN 8 THEN 'Mode of Grades'
  WHEN 10 THEN 'Weighted Mean of Grades'
  WHEN 11 THEN 'Simple Weighted Mean of Grades'
  WHEN 12 THEN 'Mean of Grades (with extra credits)'
  WHEN 13 THEN 'Sum of Grades'
END AS 'aggregation name'
 
# Note that gc.aggregatesubcats column is eliminated in 2.8 and later per MDL-47503, so comment that line on updated systems or you'll get an error
, gc.keephigh AS 'keep high'
, gc.droplow AS 'dr0p low'
, gc.aggregateonlygraded AS 'Aggregate only graded'
, gc.aggregateoutcomes AS 'aggregate outcomes'
, gc.aggregatesubcats AS 'aggregate subcategories'


# If you are displaying data about individual courses, you may want to know how old they are
# If you are displaying data about individual courses, you may want to know how old they are
#, FROM_UNIXTIME(c.startdate) AS 'course start date'
#, FROM_UNIXTIME(c.startdate) AS 'course start date'
 
 
# If you are trying to use this report to check to see if final grades have changed after an upgrade, you might want these data items, but calculations can still change later when the courses are actually viewed. Also, you'll need to uncomment the necessary JOINs below
# If you are trying to use this report to check to see if final grades have changed after an upgrade, you might want these data items, but calculations can still change later when the courses are actually viewed. Also, you'll need to uncomment the necessary JOINs below
#, gi.itemname AS 'grade item'
#, gi.itemname AS 'grade item'
#, gg.finalgrade AS 'final grade'
#, gg.finalgrade AS 'final grade'
 
 
FROM
FROM
 
 
prefix_course AS c
prefix_course AS c
JOIN prefix_grade_categories AS gc ON gc.courseid = c.id
JOIN prefix_grade_categories AS gc ON gc.courseid = c.id
JOIN prefix_course_categories AS cc ON cc.id = c.category
JOIN prefix_course_categories AS cc ON cc.id = c.category
 
 
#LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id #AND gi.categoryid=gc.id
#LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id #AND gi.categoryid=gc.id
#LEFT JOIN prefix_grade_grades AS gg ON gg.itemid = gi.id AND gg.userid = u.id
#LEFT JOIN prefix_grade_grades AS gg ON gg.itemid = gi.id AND gg.userid = u.id
 
 
WHERE
WHERE
1
1
#AND gc.aggregation = 13 #only the dreaded Sum of Grades aggregations
#AND gc.aggregation = 13 #only the dreaded Sum of Grades aggregations
#AND gc.depth = 1 # if for some reason you only want course aggregations, not subcategories
#AND gc.depth = 1 # if for some reason you only want course aggregations, not subcategories
 
 
 
 
GROUP BY gc.aggregation, gc.keephigh, gc.droplow, gc.aggregateonlygraded, gc.aggregateoutcomes, gc.aggregatesubcats
GROUP BY gc.aggregation, gc.keephigh, gc.droplow, gc.aggregateonlygraded, gc.aggregateoutcomes, gc.aggregatesubcats
 
 
</code>
</syntaxhighlight>
 
 
== Useful sub queries ==
=== Running Cron jobs (task_scheduled) ===
 
<syntaxhighlight lang="SQL">
=== All teachers in the course ===
SELECT classname
<code sql>
  ,DATE_FORMAT(FROM_UNIXTIME(lastruntime), '%H:%i [%d]') AS 'last'
,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) )  
  ,DATE_FORMAT(now(), '%H:%i') AS 'now'
FROM prefix_course ic
  ,DATE_FORMAT(FROM_UNIXTIME(nextruntime), '%H:%i [%d]') AS 'next'
JOIN prefix_context con ON con.instanceid = ic.id
  ,DATE_FORMAT(FROM_UNIXTIME(UNIX_TIMESTAMP()-nextruntime), '%i') AS 'next in min'
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
FROM mdl_task_scheduled
JOIN prefix_role r ON ra.roleid = r.id
WHERE now() > FROM_UNIXTIME(nextruntime)
JOIN prefix_user u ON u.id = ra.userid
</syntaxhighlight>
WHERE r.id = 3 AND ic.id = c.id
 
GROUP BY ic.id
=== Flat file enrollments waiting for processing ===
) AS TeacherNames
 
</code>
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
This lists all enrolments uploaded by the [[Flat_file|Flat file enrolment method]] that are currently waiting to be processed. When the optional enrolment start date is set for a user in the file, and this start date is in the future, the enrolment information is held in the database until the time for the actual enrolment to start at which time the user is actually enroled. This report allows you to see any and all such enrolments that are waiting to be done.
 
<syntaxhighlight lang="SQL">
SELECT
u.username,
c.fullname AS "Course",
ef.action,
r.shortname AS "Role",
DATE_FORMAT(FROM_UNIXTIME(ef.timestart),'%Y-%m-%d %H:%i')  AS "Enrolment Start",
DATE_FORMAT(FROM_UNIXTIME(ef.timeend),'%Y-%m-%d %H:%i')  AS "Enrolment End",
DATE_FORMAT(FROM_UNIXTIME(ef.timemodified),'%Y-%m-%d %H:%i') AS "Uploaded Date"
 
FROM prefix_enrol_flatfile ef
JOIN prefix_user u ON u.id = ef.userid
JOIN prefix_course c ON c.id = ef.courseid
JOIN prefix_role r ON r.id = ef.roleid
 
ORDER BY u.username
</syntaxhighlight>
 
=== All Meta courses with Parent and Child course relationships ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
This shows the list of courses with Meta course link enrollments in them ('Parent course'), and the courses which are connected to them to provide enrollments ('Child courses').
 
<syntaxhighlight lang="SQL">
SELECT
c.fullname AS 'Parent course name',
c.shortname AS 'Parent course shortname',
en.courseid AS 'Parent course id',
(SELECT fullname FROM prefix_course WHERE prefix_course.id = en.customint1) As 'Child course name',
(SELECT shortname FROM prefix_course WHERE prefix_course.id = en.customint1) As 'Child course shortname',
en.customint1 AS 'Child course id'
FROM prefix_enrol en
JOIN prefix_course c ON c.id = en.courseid
WHERE en.enrol = 'meta'
ORDER BY c.fullname
</syntaxhighlight>
 
=== All Private Files by User ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
Lists all files by all users in the Private Files repository, with the file path location and name in the moodledata/filedir directory structure, and time created.
 
<syntaxhighlight lang="SQL">
SELECT
u.username,
f.filename,
CONCAT('/', LEFT(f.contenthash,2), '/', MID(f.contenthash,3,2), '/', f.contenthash) AS "Filedir_Location",
DATE_FORMAT(FROM_UNIXTIME(f.timecreated),'%Y-%m-%d %H:%i') AS "Created"
FROM prefix_files f
JOIN prefix_user u ON u.id = f.userid
WHERE f.component = 'user'
AND f.filearea = 'private'
AND f.filesize > 0
ORDER BY u.username, f.filename
</syntaxhighlight>
 
=== All Tags in use in Courses and Activities ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
Shows all tags that are in use in Courses and in Activities. Shows the tag name, which course it is used in, whether it is a course level tag or an activity level tag, along with handy links to the course and activity. If it is an tag in an activity, it shows the activity type and its name. Also shows you if the tag is a Standard tag or not in the system, and if not, which user created the tag.
 
Note: this version includes the new H5P core activity in its list of modules. 
 
<syntaxhighlight lang="SQL">
SELECT
t.name AS "Tag",
CASE ti.itemtype
  WHEN 'course' THEN 'Course'
  ELSE "Activity"
END AS "Tag_Type",
 
# get the course name
CASE ti.itemtype
  WHEN 'course' THEN
  (SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',id,'">',shortname,'</a>') FROM prefix_course WHERE id = ti.itemid)
  ELSE
  (SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',id,'">',shortname,'</a>') FROM prefix_course WHERE id = cm.course)
END AS "Course",
 
# get the activity type
CASE ti.itemtype
  WHEN 'course' THEN '-'
  ELSE
    # (SELECT CONCAT(name, ' (',cm.module,')') FROM prefix_modules WHERE id = cm.module)
m.name
END AS "Activity_Type",
 
# get the activity name
CASE ti.itemtype
  WHEN 'course' THEN '-'
  ELSE
    CASE
    WHEN m.name = 'assign' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_assign WHERE id = cm.instance)
    WHEN m.name = 'assignment' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_assignment WHERE id = cm.instance)
    WHEN m.name = 'book' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_book WHERE id = cm.instance)
    WHEN m.name = 'chat' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_chat WHERE id = cm.instance)
    WHEN m.name = 'choice' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_choice WHERE id = cm.instance)
    WHEN m.name = 'data' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_data WHERE id = cm.instance)
    WHEN m.name = 'feedback' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_feedback WHERE id = cm.instance)
    WHEN m.name = 'folder' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_folder WHERE id = cm.instance)
    WHEN m.name = 'forum' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_forum  WHERE id = cm.instance)
    WHEN m.name = 'glossary' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_glossary WHERE id = cm.instance)
    WHEN m.name = 'h5pactivity' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_h5pactivity WHERE id = cm.instance)
    WHEN m.name = 'imscp' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_imscp WHERE id = cm.instance)
    WHEN m.name = 'label' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_label WHERE id = cm.instance)
    WHEN m.name = 'lesson' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_lesson WHERE id = cm.instance)
    WHEN m.name = 'lti' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_lti WHERE id = cm.instance)
    WHEN m.name = 'page' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_page WHERE id = cm.instance)
    WHEN m.name = 'quiz' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_quiz WHERE id = cm.instance)
    WHEN m.name = 'resource' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_resource WHERE id = cm.instance)
    WHEN m.name = 'scorm' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_scorm WHERE id = cm.instance)
    WHEN m.name = 'survey' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_survey WHERE id = cm.instance)
    WHEN m.name = 'url' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_url WHERE id = cm.instance)
    WHEN m.name = 'wiki' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_wiki WHERE id = cm.instance)
    WHEN m.name = 'workshop' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_workshop WHERE id = cm.instance)
    # add any others you have installed here with their id number
    ELSE CONCAT("Unknown_mod_id: ", cm.module)
    END
END AS "Activity_name",
 
# get tag standard
CASE t.isstandard
  WHEN 1 THEN 'Yes'
  ELSE CONCAT('No (', (SELECT username FROM prefix_user WHERE id = t.userid),')')
END AS "Standard"
 
FROM prefix_tag_instance ti
JOIN prefix_tag t ON t.id = ti.tagid
JOIN prefix_tag_coll tc ON tc.id = t.tagcollid
JOIN prefix_course_modules cm ON cm.id = ti.itemid
JOIN prefix_modules m ON m.id = cm.module
 
WHERE ti.component = 'core'
AND (ti.itemtype = 'course' OR ti.itemtype = 'course_modules')
 
ORDER BY 1,2,3,4,5
</syntaxhighlight>
 
== Learning Analytics Reports ==
(Moodle v. 3.4 and later)
 
=== Learning Analytics Model Summary ===
This report provides a list of the learning analytics models on your site, whether enabled or not, and several details about them.
 
(Note: this report was created on a system using PostgreSQL. Some changes may be needed for other forms of SQL.)
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
am.id AS "model id",
split_part(am.target,'\',5) AS "target",
CASE WHEN am.enabled=1 THEN 'YES' ELSE 'NO' END AS "enabled",
CASE WHEN am.trained=1 THEN 'YES' ELSE 'NO' END AS "trained",
am.name,
/* indicators,*/
char_length(am.indicators) - char_length(REPLACE(am.indicators,',',''))+1 AS "indicator count",
split_part(am.timesplitting,'\',5) AS "interval",
/*
to_timestamp(am.version) AS "version",
to_timestamp(am.timecreated) AS "time created",
to_timestamp(am.timemodified) AS "time modified",
*/
COUNT(DISTINCT ap.contextid) AS "contexts",
COUNT(ap.sampleid) AS "samples",
/* AVG(ap.prediction) AS "avg prediction", */
ROUND(ap.prediction,1) AS "prediction",  
ROUND(AVG(aml.score),3) AS "model accuracy (avg)",
apa.actionname AS "action",
COUNT(apa.id) AS "number actions taken"
 
FROM prefix_analytics_models AS am
JOIN prefix_analytics_predictions AS ap ON am.id = ap.modelid
LEFT JOIN prefix_analytics_models_log AS aml ON aml.modelid = am.id
LEFT JOIN prefix_analytics_prediction_actions AS apa ON apa.predictionid = ap.id
GROUP BY am.id, ap.prediction, apa.actionname
</syntaxhighlight>
 
=== Analytics Indicator Calculations ===
Pulls calculations from the "analytics_indicator_calc" table consisting of all calculations made for each indicator for each sample within each context for every model. In most cases you will want to limit this per context or sample, or at least group by context and sample.
 
<syntaxhighlight lang="SQL">
SELECT
id,
to_timestamp(starttime) AS "start time",
to_timestamp(endtime) AS "end time",
contextid,
sampleorigin,
sampleid,
/*indicator, */
split_part(indicator,'\',2) AS "module",
split_part(indicator,'\',5) AS "indicator type",
value,
to_timestamp(timecreated) AS "time created"
 
FROM prefix_analytics_indicator_calc
WHERE id = 1
</syntaxhighlight>
 
===Analytics Models ===
Pulls data from the "analytics_models" table consisting of one row per model. See the "Learning Analytics Model Summary" report, above, for an expanded report that JOINs model data from different tables to provide a more comprehensive view.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
id,
enabled,
trained,
name,
split_part(target,'\',5) AS "target",
/* indicators,*/
char_length(indicators) - char_length(REPLACE(indicators,',',''))+1 AS "indicator count",
split_part(timesplitting,'\',5) AS "interval",
predictionsprocessor,
to_timestamp(version) AS "version",
to_timestamp(timecreated) AS "time created",
to_timestamp(timemodified) AS "time modified",
usermodified
 
FROM prefix_analytics_models
</syntaxhighlight>
 
 
=== Analytics Models Log ===
Pulls data from the "analytics_models_log" table consisting of evaluation calculations per model. If model evaluations have not been manually executed on the system from the command line, there will be no contents in this table.
Contributed by Elizabeth Dalton, Moodle HQ
 
 
<syntaxhighlight lang="SQL">
SELECT
id,
modelid,
to_timestamp(version) AS "version",
evaluationmode,
split_part(target,'\',5) AS "target",
/* indicators,*/
char_length(indicators) - char_length(REPLACE(indicators,',',''))+1 AS "indicator count",
split_part(timesplitting,'\',5) AS "interval",
score,
info,
dir,
to_timestamp(timecreated) AS "time created",
usermodified
 
FROM prefix_analytics_models_log
</syntaxhighlight>
 
=== Analytics Predictions ===
Pulls data from the "analytics_predictions" table consisting of one row per prediction per model. Counts the number of indicators calculated for each prediction, but does not list them. If a model has not yet been trained, the system cannot make predictions and this table will not include rows for that model ID. See the "Learning Analytics Model Summary" report, above, for an expanded report that JOINs model data from different tables to provide a more comprehensive view.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
id,
modelid,
contextid,
sampleid,
rangeindex,
prediction,
predictionscore,
char_length(calculations) - char_length(REPLACE(calculations,',',''))+1 AS "indicators calculated",
to_timestamp(timecreated) AS "time created",
to_timestamp(timestart) AS "time start",
to_timestamp(timeend) AS "time end"
 
from prefix_analytics_predictions
</syntaxhighlight>
 
=== Analytics Prediction Actions ===
Pulls data from the "analytics_prediction_actions" table consisting of one row per action taken per prediction (e.g. a teacher viewing the outline report for a student at risk). If the model has not yet made predictions, there can be no prediction actions. See the "Learning Analytics Model Summary" report, above, for an expanded report that JOINs model data from different tables to provide a more comprehensive view.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
id,
predictionid,
userid,
actionname,
to_timestamp(timecreated) AS "time created"
 
FROM prefix_analytics_prediction_actions
</syntaxhighlight>
 
 
=== Analytics Predictions with All Indicators ===
Pulls data from the "analytics_predictions" table consisting of one row per prediction per model. Lists the indicators calculated for each prediction. If a model has not yet been trained, the system cannot make predictions and this table will not include rows for that model ID.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
id AS "Prediction ID",
modelid AS "Model ID",
contextid AS "Context ID",
sampleid AS "Sample ID",
rangeindex AS "Analysis Interval",
prediction AS "Prediction value",
predictionscore,
calculations,
char_length(calculations) - char_length(REPLACE(calculations,',',''))+1 AS "indicators calculated",
to_timestamp(timecreated) AS "time created",
to_timestamp(timestart) AS "time start",
to_timestamp(timeend) AS "time end"
 
from prefix_analytics_predictions
</syntaxhighlight>
 
=== Analytics Predict Samples ===
Pulls data from the "analytics_predict_samples" table consisting of one row per analysis interval per model, with a count of the samples used for each prediction. Sample details are not included here, but the report can be modified to list samples by IDs if needed by parsing the contents of the sampleids field. For example, this counts the number of student enrolments for which the system has generated predictions for a given model and analysis interval.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
id,
modelid,
analysableid,
split_part(timesplitting,'\',5) AS "interval",
rangeindex,
/* sampleids, */
char_length(sampleids) - char_length(REPLACE(sampleids,',',''))+1 AS "samples used",
to_timestamp(timecreated) AS "time created",
to_timestamp(timemodified) AS "time modified"
 
FROM prefix_analytics_predict_samples
</syntaxhighlight>
 
=== Analytics Train Samples ===
Pulls data from the "analytics_train_samples" table consisting of one row per analysis interval per model, with a count of the samples used for each training calculation.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
id,
modelid,
analysableid,
split_part(timesplitting,'\',5) AS "interval",
/* sampleids, */
char_length(sampleids) - char_length(REPLACE(sampleids,',',''))+1 AS "samples used",
to_timestamp(timecreated) AS "time created"
 
FROM prefix_analytics_train_samples
</syntaxhighlight>
 
=== Analytics Used Analysables ===
Pulls data from the "analytics_used_analysables" table consisting of one row per context per model, noting whether the analysable was used to train the model or to make a prediction. This data is used to control the training and prediction processes.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
id,
modelid,
action,
analysableid,
to_timestamp(firstanalysis) AS "first analysis",
to_timestamp(timeanalysed) AS "time analysed"
 
FROM prefix_analytics_used_analysables
</syntaxhighlight>
 
=== Analytics Used Files ===
Pulls data from the "analytics_used_files" table consisting of one row per file per model, noting whether the file was used to train the model or to make a prediction. This data is used to control the training and prediction processes.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
 
id,
modelid,
fileid,
action,
TO_TIMESTAMP(time) AS Time
 
FROM prefix_analytics_used_files
</syntaxhighlight>
 
===Average Cognitive Depth and Social Breadth===
 
Here is a simple SQL snippet to calculate average cognitive depth and social breadth indicators for all students in the system. This one ignores  indicator values of 0, as they are nulls as defined in this model.
Contributed by Elizabeth Dalton, Moodle HQ
 
<syntaxhighlight lang="SQL">
SELECT
 
i.contextid,
i.sampleid,
 
TRUNC(AVG(CASE
WHEN i.indicator LIKE '%cognitive%' THEN i.value
ELSE '0'
END),2) AS "Average Cognitive Depth",
 
TRUNC(AVG(CASE
WHEN i.indicator LIKE '%social%' THEN i.value
ELSE '0'
END),2) AS "Average Social Breadth"
 
FROM prefix_analytics_indicator_calc as i
WHERE
i.value != 0
GROUP BY i.contextid, i.sampleid
</syntaxhighlight>
 
==Competencies==
 
===List of competencies from a framework and the courses including them===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
 
<syntaxhighlight lang="SQL">
SELECT
f.shortname AS 'Framework',
comp.shortname AS 'Competency',
cccomp.courseid AS 'Course id',
c.fullname AS 'Course name',
c.shortname AS 'Course code'
FROM
prefix_competency_coursecomp AS cccomp
INNER JOIN prefix_competency AS comp ON cccomp.competencyid = comp.id
INNER JOIN prefix_course AS c ON cccomp.courseid = c.id
INNER JOIN prefix_competency_framework AS f ON comp.competencyframeworkid = f.id
</syntaxhighlight>
 
===Count the courses using each competency from frameworks===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
 
Unfortunately, there is not a filter by competency framework.
 
<syntaxhighlight lang="SQL">
select
f.shortname AS framework,
comp.shortname AS 'Competency',
COUNT(cccomp.competencyid) AS 'nb course'
FROM prefix_competency AS comp
INNER JOIN prefix_competency_framework AS f ON comp.competencyframeworkid = f.id
LEFT JOIN prefix_competency_coursecomp AS cccomp ON cccomp.competencyid = comp.id
GROUP BY comp.id, comp.shortname
</syntaxhighlight>
 
 
=== Scale details with ids ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
Competency import and export files include scales with id numbers. However, the management page in Grades > Scales does not have the scale id, nor other useful details that scales store about themselves, like who made them and when, and what context they pertain to. This simple query shows you that information.
 
<syntaxhighlight lang="SQL">
SELECT
s.id AS Scaleid,
s.name AS Scale_Name,
s.scale AS Scale,
CASE 
  WHEN s.courseid = 0 THEN 'System'
  ELSE (SELECT shortname FROM prefix_course WHERE id = s.courseid)
END AS Context,
CASE
  WHEN s.userid = 0 THEN 'System'
  ELSE (SELECT username FROM prefix_user WHERE id = s.userid)
END AS User,
s.description,
DATE_FORMAT( FROM_UNIXTIME(s.timemodified), '%Y-%m-%d %H:%i' ) AS 'Modified'
FROM prefix_scale s
 
</syntaxhighlight>
 
==Syllabus==
 
Our school simply asks teachers to drop a file (resource) on their course page
and rename this resource (not the file) starting with "syllabus" (case insensitive)
 
===Count the number of resources whose name starts by "Syllabus"===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
<syntaxhighlight lang="SQL">
Select
r.name As 'Resource name',
cc.name AS 'Category',
CONCAT('<a href="%%WWWROOT%%/pluginfile.php/', ct.id, '/mod_resource/content/1/', f.filename, '">',f.filename,'</a>') AS 'Clickable filename',
 
c.fullname AS 'Course name',
c.shortname AS 'Course shortname',
 
# the date filters are connected to this "last modif" field
# userful to check if the syllabus has been updated this year
DATE_FORMAT(FROM_UNIXTIME(f.timemodified), '%e %b %Y') AS 'last modif',
 
# tell if the file is visible by the students or hidden
IF(cm.visible=0,"masqué","visible") AS 'Visibility',
 
# next line tries to give the real path (local path) if you want to create a zip file using an external script)
# notice that the path is in the column "contenthash" and NOT in the column pathhash
# if the contenthash starts with 9af3... then the file is stored in moodledata/filedir/9a/f3/contenthash
# I try to get the path to moodledata from the value of the geoip variable in the mdl_config table... maybe a bad idea
CONCAT('"',(Select left(value, length(value)-25) from prefix_config where name ="geoip2file"),'/filedir/', left(f.contenthash,2), "/",substring(f.contenthash,3,2),'/', f.contenthash, '"') AS 'link'
 
FROM prefix_resource AS r
INNER JOIN prefix_course_modules AS cm ON cm.instance = r.id
INNER JOIN prefix_course AS c ON c.id = r.course
INNER JOIN prefix_context AS ct ON ct.instanceid = cm.id
JOIN prefix_course_categories cc ON c.category = cc.id
INNER JOIN prefix_files AS f ON f.contextid = ct.id AND f.mimetype IS NOT NULL AND f.component = 'mod_resource'
WHERE LOWER( r.name) LIKE 'syllabus%'
%%FILTER_STARTTIME:f.timemodified:>%% %%FILTER_ENDTIME:f.timemodified:<%%
%%FILTER_SUBCATEGORIES:cc.path%%
</syntaxhighlight>
 
===List files which have been tagged "Syllabus"===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
 
<syntaxhighlight lang="SQL">
Select
t.rawname AS 'rawtag',
c.shortname AS 'Cours shortname',
c.fullname AS 'Course name',
r.name As 'Resource name',
CONCAT('<a href="%%WWWROOT%%/pluginfile.php/', ti.contextid, '/mod_resource/content/1/', f.filename, '">cliquez ici</a>') AS 'link',
ti.contextid AS 'Instance for link',
f.id AS 'file id'
FROM prefix_tag_instance AS ti
INNER JOIN prefix_tag AS t ON ti.tagid = t.id
INNER JOIN prefix_course_modules AS cm ON ti.itemid = cm.id
INNER JOIN prefix_course AS c ON cm.course = c.id
INNER JOIN prefix_resource AS r ON r.id = cm.instance
INNER JOIN prefix_files AS f ON f.contextid = ti.contextid AND f.mimetype IS NOT NULL
WHERE t.rawname = 'Syllabus'
</syntaxhighlight>
 
===List of courses WITHOUT a resource with a name starting by "syllabus"===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
 
<syntaxhighlight lang="SQL">
select c.id, c.shortname,
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', c.id, '">',c.fullname,'</a>') AS 'Course link'
FROM prefix_course AS c
LEFT JOIN (
  Select r.course
  from prefix_resource AS r
  WHERE LOWER( r.name) LIKE 'syllabus%'
  GROUP BY r.course) AS r ON r.course = c.id
INNER JOIN prefix_course_categories cc ON c.category = cc.id
WHERE r.course IS NULL
%%FILTER_SUBCATEGORIES:cc.path%%
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.enddate:<%%
</syntaxhighlight>
 
===List of courses have MULTIPLE resource with a name like "Syllabus%"===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
 
<syntaxhighlight lang="SQL">
select
r.course,
c.shortname,
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', r.id, '">',c.fullname,'</a>') AS 'Course link'
FROM prefix_resource AS r
INNER JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories cc ON c.category = cc.id
WHERE LOWER( r.name) LIKE 'syllabus%'
GROUP BY r.course HAVING count(r.course)>1
%%FILTER_SUBCATEGORIES:cc.path%%
</syntaxhighlight>
 
==Chat==
 
===List the chats===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
This report gives the list of all chats with the name of the course and various ids needed for further queries.
 
The column "participants" is intended to work with an (optional) secondary report. If you don't need it , you can erase it.
It produces a direct link to another (optional) report which will give you the current participants list to this chat.
 
<syntaxhighlight lang="SQL">
select
c.shortname,
c.fullname,
ch.course,
ch.id,
# if you intend to use a secondary report to see the participants of a specific chat
# create the secondary report, check the id of the report in the url, and change the 21 in next line to your participant report's id
CONCAT('<a href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?id=21&filter_courses=', ch.id,'">Chat participants</a>') AS 'Course link',
ch.chattime
 
FROM
prefix_chat ch
INNER JOIN prefix_course c ON c.id = ch.course
 
ORDER BY ch.chattime, c.fullname
</syntaxhighlight>
===Participants to a chat (optional secondary report)===
This version of the participant list is intended to work with a link given in the previous report.
* User opens the report listing all the chats on the platform
* user clicks on the link from the column "chat participant"
* which open this report with a filter on the chatid
''(careful, we are tweaking the coursefilter to carry instead the chatid: the displayed "course filter" will not work! but we need it)''
 
<syntaxhighlight lang="SQL">
 
SELECT
c.id AS courseid,
chu.chatid,
chu.userid AS 'chat user userid',
c.fullname,
u.username,
u.firstname,
u.lastname,
u.email
                               
FROM
prefix_user u
LEFT JOIN prefix_chat_users chu ON chu.userid = u.id
INNER JOIN prefix_course c ON c.id = chu.course
 
WHERE 1=1
%%FILTER_COURSES:chu.chatid%%
# you can also filter by course
# but don't put comment line between where and filter
# %%FILTER_COURSES:chu.course%%
 
                               
ORDER BY c.fullname
 
</syntaxhighlight>
 
===List current participants to chat===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
<syntaxhighlight lang="SQL">
SELECT
c.id AS courseid,
chu.chatid,
chu.userid AS 'chat user userid',
c.fullname,
u.username,
u.firstname,
u.lastname,
u.email
                               
FROM
prefix_user u
LEFT JOIN prefix_chat_users chu ON chu.userid = u.id
INNER JOIN prefix_course c ON c.id = chu.course
 
WHERE 1=1
%%FILTER_COURSES:chu.course%%
                               
ORDER BY c.fullname
</syntaxhighlight>
 
== Useful sub queries ==
 
IN this section please put any short one purpose sub queries that show how common procedures often useful as part of larger queries.
 
=== All teachers in the course ===
 
 
This snippet shows how to get teachers from a course. The contextevel for course objects is 50. And the default Teacher role is role id 3.
 
<syntaxhighlight lang="SQL">
,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) )  
FROM prefix_course ic
JOIN prefix_context con ON con.instanceid = ic.id
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
JOIN prefix_role r ON ra.roleid = r.id
JOIN prefix_user u ON u.id = ra.userid
WHERE r.id = 3 AND ic.id = c.id
GROUP BY ic.id
) AS TeacherNames
</syntaxhighlight>
 
=== Get custom User profile fields for a user ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
This snippet of code shows how to connect a user with their custom profile field data. This will list all users with all custom profile fields and data. Custom profile fields have two tables, one for the definition of the profile field (user_info_field) and its settings, and a separate table to hold the data entered by users (user_info_data).
 
<syntaxhighlight lang="SQL">
SELECT u.username, uif.name, uid.data
FROM prefix_user AS u
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
JOIN prefix_user_info_field AS uif ON uid.fieldid = uif.id
</syntaxhighlight>
 
If you want to limit it to one of those fields, you can restrict it by shortname of the custom profile field, so:
 
<syntaxhighlight lang="SQL">
SELECT u.username, uif.name, uid.data
FROM prefix_user AS u
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
JOIN prefix_user_info_field AS uif ON (uid.fieldid = uif.id AND uif.shortname = 'shortname1')
</syntaxhighlight>
 
will show you only the data from the custom profile field with the shortname 'shortname1'.
 
If you want to do this with two or more custom profile fields, you will need to have a JOIN and table alias for each with a restriction for each profile field shortname. Example:
 
<syntaxhighlight lang="SQL">
SELECT u.username, d1.data AS 'Profile One', d2.data As 'Profile Two'
FROM prefix_user u
JOIN prefix_user_info_data d1 ON d1.userid = u.id
JOIN prefix_user_info_field f1 ON d1.fieldid = f1.id AND f1.shortname = 'shortname1'
JOIN prefix_user_info_data d2 ON d2.userid = u.id
JOIN prefix_user_info_field f2 ON d2.fieldid = f2.id AND f2.shortname = 'shortname2'
</syntaxhighlight>
 
==== NOTE: Alternate Method ====
 
If you have more than a couple of fields you need to use, then this query may time out or not return data due to too many joins. The limit seems to be around 10 custom profile fields.
 
Instead you should use an alternate method which uses Subselects for each of the profile fields. Details and sample code are in this forum discussion: https://moodle.org/mod/forum/discuss.php?d=355502#p1434854. A sample of the style is:
 
<syntaxhighlight lang="SQL">
SELECT u.username
 
,(SELECT d1.data FROM prefix_user_info_data d1
JOIN prefix_user_info_field f1 ON d1.fieldid = f1.id AND f1.shortname = 'shortname1'
WHERE d1.userid = u.id
) AS thefirstfield
 
,(SELECT d1.data FROM prefix_user_info_data d1
JOIN prefix_user_info_field f1 ON d1.fieldid = f1.id AND f1.shortname = 'shortname2'
WHERE d1.userid = u.id
) AS thesecondfield
 
FROM prefix_user u
</syntaxhighlight>
 
=== How to use Configurable Reports Date Time Filters===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
In the Configurable Reports block, you can set the Time and Date filter to allow you to pick your report Start date/time and End date/time interactively. This will work on any column in a table that is a timestamp.
 
Here is a simple example:
 
<syntaxhighlight lang="SQL">
SELECT u.username,
DATE_FORMAT(FROM_UNIXTIME(u.firstaccess),'%Y-%m-%d %H:%i') AS 'FirstAccess',
DATE_FORMAT(FROM_UNIXTIME(u.lastaccess),'%Y-%m-%d %H:%i') AS 'LastAccess' 
FROM prefix_user u
 
WHERE 1=1
%%FILTER_STARTTIME:u.firstaccess:>%%
%%FILTER_ENDTIME:u.lastaccess:<%%
</syntaxhighlight>


=== Get custom User profile fields for a user ===
1) You will need to replace name of the table and column for the filter to use the time and date column you need for your query. In the example above, it filters on the firstaccess and lastaccess columns in the user table. If you were doing a report on course completion, you might put the timecompleted column, and so forth.


This snippet of code shows how to connect a user with their custom profile field data.
2) You MUST then add the Start / End date filter on the Filters tab of the Report. If you don't, the report will still run, probably, but the filter will be ignored.


<code sql>
Note: the WHERE 1=1 statement is a peculiarity of the filters in Config reports: if you don't have a WHERE statement in your query already, then you must add this dummy WHERE to keep the statement valid. If you already have a WHERE statement in your code, simply add the %%FILTER%% placeholders after it (and before any GROUP or ORDER BY statements.)
SELECT u.username, uif.name, uid.data
FROM prefix_user AS u
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
JOIN prefix_user_info_field AS uif ON uid.fieldid = uif.id
WHERE u.username = 'someusername'
</code>


==See also==
==See also==
[https://github.com/jleyva/moodle-configurable_reports_repository Configurable Reports Repository on GitHub]
* [https://github.com/jleyva/moodle-configurable_reports_repository Configurable Reports Repository on GitHub]
* [https://moodleschema.zoola.io/index.html Moodle DB schema explorer] - searching and filtering tables, fields and external key connections between tables.


[[Category:Contributed code]]
[[Category:Contributed code]]


[[es:Reportes específicos hechos por usuarios]]
[[es:Reportes específicos hechos por usuarios]]

Latest revision as of 16:18, 14 October 2021

User and Role Report

Count number of distinct learners and teachers enrolled per category (including all its sub categories)

SELECT COUNT(DISTINCT lra.userid) AS learners, COUNT(DISTINCT tra.userid) as teachers
FROM prefix_course AS c #, mdl_course_categories AS cats
LEFT JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments  AS lra ON lra.contextid = ctx.id
JOIN prefix_role_assignments  AS tra ON tra.contextid = ctx.id
JOIN prefix_course_categories AS cats ON c.category = cats.id
WHERE c.category = cats.id
AND (
	cats.path LIKE '%/CATEGORYID/%' #Replace CATEGORYID with the category id you want to count (eg: 80)
	OR cats.path LIKE '%/CATEGORYID'
	)
AND lra.roleid=5
AND tra.roleid=3

Detailed ACTIONs for each ROLE (TEACHER, NON-EDITING TEACHER and STUDENT)

SELECT r.name, l.action, COUNT( l.userid ) AS counter
FROM prefix_log AS l
JOIN prefix_context AS context ON context.instanceid = l.course AND context.contextlevel = 50
JOIN prefix_role_assignments AS ra ON l.userid = ra.userid AND ra.contextid = context.id
JOIN prefix_role AS r ON ra.roleid = r.id
WHERE ra.roleid IN ( 3, 4, 5 ) 
GROUP BY roleid, l.action

Student (user) COUNT in each Course

Including (optional) filter by: year (if included in course fullname).

SELECT CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',course.id,'">',course.fullname,'</a>') AS Course
,CONCAT('<a target="_new" href="%%WWWROOT%%/user/index.php?contextid=',context.id,'">Show users</a>') AS Users
, COUNT(course.id) AS Students
FROM prefix_role_assignments AS asg
JOIN prefix_context AS context ON asg.contextid = context.id AND context.contextlevel = 50
JOIN prefix_user AS user ON user.id = asg.userid
JOIN prefix_course AS course ON context.instanceid = course.id
WHERE asg.roleid = 5 
# AND course.fullname LIKE '%2013%'
GROUP BY course.id
ORDER BY COUNT(course.id) DESC

Enrolment count in each Course

Shows the total number of enroled users of all roles in each course. Sorted by course name.

SELECT c.fullname, COUNT(ue.id) AS Enroled
FROM prefix_course AS c 
JOIN prefix_enrol AS en ON en.courseid = c.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
GROUP BY c.id
ORDER BY c.fullname

LIST of all site USERS by COURSE enrollment (Moodle 2.x)

SELECT
user2.firstname AS Firstname,
user2.lastname AS Lastname,
user2.email AS Email,
user2.city AS City,
course.fullname AS Course
,(SELECT shortname FROM prefix_role WHERE id=en.roleid) as Role
,(SELECT name FROM prefix_role WHERE id=en.roleid) as RoleName

FROM prefix_course as course 
JOIN prefix_enrol AS en ON en.courseid = course.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
JOIN prefix_user AS user2 ON ue.userid = user2.id

Enrolled users,which did not login into the Course, even once (Moodle 2)

Designed forMoodle 2 table structure and uses special plugin filter : %%FILTER_SEARCHTEXT:table.field%%

SELECT
user2.id as ID,
ul.timeaccess,
user2.firstname AS Firstname,
user2.lastname AS Lastname,
user2.email AS Email,
user2.city AS City,
user2.idnumber AS IDNumber,
user2.phone1 AS Phone,
user2.institution AS Institution,

IF (user2.lastaccess = 0,'never',
DATE_FORMAT(FROM_UNIXTIME(user2.lastaccess),'%Y-%m-%d')) AS dLastAccess

,(SELECT DATE_FORMAT(FROM_UNIXTIME(timeaccess),'%Y-%m-%d') FROM prefix_user_lastaccess WHERE userid=user2.id and courseid=c.id) as CourseLastAccess

,(SELECT r.name
FROM  prefix_user_enrolments AS uenrol
JOIN prefix_enrol AS e ON e.id = uenrol.enrolid
JOIN prefix_role AS r ON e.id = r.id
WHERE uenrol.userid=user2.id and e.courseid = c.id) AS RoleName

FROM prefix_user_enrolments as ue
JOIN prefix_enrol as e on e.id = ue.enrolid
JOIN prefix_course as c ON c.id = e.courseid
JOIN prefix_user as user2 ON user2 .id = ue.userid
LEFT JOIN prefix_user_lastaccess as ul on ul.userid = user2.id
WHERE c.id=16 AND ul.timeaccess IS NULL
%%FILTER_SEARCHTEXT:user2.firstname%%

Enrolled users who have never accessed a given course (simpler version)

SELECT username, firstname, lastname, idnumber
FROM prefix_user_enrolments ue
JOIN prefix_enrol en ON ue.enrolid = en.id
JOIN prefix_user uu ON uu.id = ue.userid 
WHERE en.courseid = 123456
AND NOT EXISTS (
    SELECT * FROM prefix_user_lastaccess la
    WHERE la.userid = ue.userid
    AND la.courseid = en.courseid
)

(Replace 123456 near the middle with your courseid)

Role assignments on categories

SELECT 
concat('<a target="_new" href="%%WWWROOT%%/course/category.php?id=',cc.id,'">',cc.id,'</a>') AS id,
concat('<a target="_new" href="%%WWWROOT%%/course/category.php?id=',cc.id,'">',cc.name,'</a>') AS category,
cc.depth, cc.path, r.name AS role,
concat('<a target="_new" href="%%WWWROOT%%/user/view.php?id=',usr.id,'">',usr.lastname,'</a>') AS name,
usr.firstname, usr.username, usr.email
FROM prefix_course_categories cc
INNER JOIN prefix_context cx ON cc.id = cx.instanceid
AND cx.contextlevel = '40'
INNER JOIN prefix_role_assignments ra ON cx.id = ra.contextid
INNER JOIN prefix_role r ON ra.roleid = r.id
INNER JOIN prefix_user usr ON ra.userid = usr.id
ORDER BY cc.depth, cc.path, usr.lastname, usr.firstname, r.name, cc.name

Permissions Overides on Categories

(By: Séverin Terrier )

SELECT rc.id, ct.instanceid, ccat.name, rc.roleid, rc.capability, rc.permission, 
DATE_FORMAT( FROM_UNIXTIME( rc.timemodified ) , '%Y-%m-%d' ) AS timemodified, rc.modifierid, ct.instanceid, ct.path, ct.depth
FROM `prefix_role_capabilities` AS rc
INNER JOIN `prefix_context` AS ct ON rc.contextid = ct.id
INNER JOIN `prefix_course_categories` AS ccat ON ccat.id = ct.instanceid
AND `contextlevel` =40

Lists "Totally Opened Courses" (visible, opened to guests, with no password)

(By: Séverin Terrier )

SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS id,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS 'Course',
concat('<a target="_new" href="%%WWWROOT%%/enrol/instances.php?id=',c.id,'">Méthodes inscription</a>') AS 'Enrollment plugins',
e.sortorder
FROM prefix_enrol AS e, prefix_course AS c
WHERE e.enrol='guest' AND e.status=0 AND e.password='' AND c.id=e.courseid AND c.visible=1

Lists "loggedin users" from the last 120 days

SELECT id,username,FROM_UNIXTIME(`lastlogin`) as days 
FROM `prefix_user` 
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120

and user count for that same population:

SELECT COUNT(id) as Users  FROM `prefix_user` 
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120

Users loggedin within the last 7 days

SELECT
    l.* FROM mdl_logstore_standard_log l
WHERE
   l.eventname = '\\core\\event\\user_loggedin'
   AND FROM_UNIXTIME(l.timecreated, '%Y-%m-%d') >= DATE_SUB(NOW(), INTERVAL 7 DAY)

SELECT l.eventname FROM mdl_logstore_standard_log l
GROUP BY l.eventname

Lists the users who have only logged into the site once

SELECT id, username, firstname, lastname, idnumber
FROM prefix_user
WHERE prefix_user.deleted = 0
AND prefix_user.lastlogin = 0 
AND prefix_user.lastaccess > 0

Students in all courses of some institute

What is the status (deleted or not) of all Students (roleid = 5) in all courses of some Institute

SELECT c.id, c.fullname, u.firstname, u.lastname, u.deleted
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid =5
AND ctx.instanceid = c.id
AND u.institution = 'please enter school name here'

Full User info (for deleted users)

Including extra custom profile fields (from prefix_user_info_data)

SELECT * 
FROM prefix_user as u 
JOIN prefix_user_info_data as uid ON uid.userid = u.id 
JOIN prefix_user_info_field as uif ON (uid.fieldid = uif.id AND uif.shortname = 'class')
WHERE `deleted` = "1" and `institution`="your school name" and `department` = "your department" and `data` = "class level and number"

User's courses

change "u.id = 2" with a new user id

SELECT u.firstname, u.lastname, c.id, c.fullname
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE u.id = 2

List Users with extra info (email) in current course

blocks/configurable_reports replaces %%COURSEID%% with course id.

SELECT u.firstname, u.lastname, u.email
FROM prefix_role_assignments AS ra
JOIN prefix_context AS context ON context.id = ra.contextid AND context.contextlevel = 50
JOIN prefix_course AS c ON c.id = context.instanceid AND c.id = %%COURSEID%%
JOIN prefix_user AS u ON u.id = ra.userid

List Students with enrollment and completion dates in current course

This is meant to be a "global" report in Configurable Reports containing the following: firstname, lastname, idnumber, institution, department, email, student enrolment date, student completion date Note: for PGSQL, use to_timestamp() instead of FROM_UNIXTIME() Contributed by Elizabeth Dalton, Moodle HQ

SELECT 
u.firstname
, u.lastname
, u.idnumber
, u.institution
, u.department
, u.email
, FROM_UNIXTIME(cc.timeenrolled)
, FROM_UNIXTIME(cc.timecompleted)

FROM prefix_role_assignments AS ra
JOIN prefix_context AS context ON context.id = ra.contextid AND context.contextlevel = 50
JOIN prefix_course AS c ON c.id = context.instanceid AND c.id = %%COURSEID%%
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_course_completions AS cc ON cc.course = c.id AND cc.userid = u.id

Special Roles

SELECT ra.roleid,r.name
,concat('<a target="_new" href="%%WWWROOT%%/course/user.php?id=1&user=',ra.userid,'">',u.firstname ,' ',u.lastname,'</a>') AS Username
,concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
FROM prefix_role_assignments AS ra
JOIN prefix_role AS r ON r.id = ra.roleid
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_context AS ctx ON (ctx.id = ra.contextid AND ctx.contextlevel = 50)
JOIN prefix_course AS c ON ctx.instanceid = c.id
WHERE ra.roleid > 6

Courses without Teachers

Actually, shows the number of Teachers in a course.

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Teachers
FROM prefix_course AS c
ORDER BY Teachers ASC

List of users who have been enrolled for more than 4 weeks

For Moodle 2.2 , by Isuru Madushanka Weerarathna

SELECT uenr.userid As User, IF(enr.courseid=uenr.courseid ,'Y','N') As Enrolled, 
IF(DATEDIFF(NOW(), FROM_UNIXTIME(uenr.timecreated))>=28,'Y','N') As EnrolledMoreThan4Weeks
FROM prefix_enrol As enr, prefix_user_enrolments AS uenr
WHERE enr.id = uenr.enrolid AND enr.status = uenr.status

List of users with language

Contributed by: Randy Thornton

An issue with systems that do not have their default language set up properly is the need to do a mass change for all users to a localization. A common case (in the U.S., Canada and the Americas) is changing the default English to United States English.

This will show you the language setting for all users:

SELECT username, lang from prefix_user

NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools.

This code will change the setting from 'en' to 'en_us' for all users:

UPDATE prefix_user SET lang = 'en_us' WHERE lang = 'en'

To do this for only users who have a particular country set, use this as an example:

UPDATE prefix_user SET lang = 'en_us' WHERE country = 'US' AND lang = 'en'

List of users with Authentication

Contributed by: Randy Thornton

Sometimes you need to do mass changes of authentication methods. A common case is changing default manual to LDAP.

This will show you the Authentication setting for all users:

SELECT username, auth from prefix_user

NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools.

This code will change the setting from 'manual' to 'ldap' for all users except for the first two accounts which are Guest and Admin. (WARNING: it is bad practice to change your admin account from manual to an external method as failure of that external method will lock you out of Moodle as admin.)

UPDATE prefix_user SET auth = 'ldap' WHERE auth = 'manual' AND id > 2

Compare role capability and permissions

Compatibility: MySQL and PostgreSQL

SELECT DISTINCT mrc.capability 
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '1' AND rc.contextid = '1') AS Manager
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '2' AND rc.contextid = '1') AS Course_Creator
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '3' AND rc.contextid = '1') AS Teacher
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '4' AND rc.contextid = '1') AS Assistant_Teacher
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '5' AND rc.contextid = '1') AS Student
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '6' AND rc.contextid = '1') AS Guest
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '7' AND rc.contextid = '1') AS Authenticated
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '8' AND rc.contextid = '1') AS Auth_front
FROM prefix_role_capabilities AS mrc

User's accumulative time spent in course

A sum up of the time delta between logstore_standard_log user's records, considering the a 2 hour session limit.

Uses: current user's id %%USERID%% and current course's id %%COURSEID%%

And also using a date filter (which can be ignored)

The extra "User" field is used as a dummy field for the Line chart Series field, in which I use X=id, Series=Type, Y=delta.

SELECT 
l.id, 
l.timecreated, 
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%d-%m-%Y') AS dTime,
@prevtime := (SELECT max(timecreated) FROM mdl_logstore_standard_log 
		WHERE userid = %%USERID%% and id < l.id ORDER BY id ASC LIMIT 1) AS prev_time,
IF (l.timecreated - @prevtime < 7200, @delta := @delta + (l.timecreated-@prevtime),0) AS sumtime,
l.timecreated-@prevtime AS delta,
"User" as type

FROM prefix_logstore_standard_log as l, 
(SELECT @delta := 0) AS s_init 
# Change UserID
WHERE l.userid = %%USERID%% AND l.courseid = %%COURSEID%%
%%FILTER_STARTTIME:l.timecreated:>%% %%FILTER_ENDTIME:l.timecreated:<%%

Low-Participation Student Report

Contributed by Elizabeth Dalton, Granite State College / Moodle HQ

This report returns a list of students who are enrolled in courses filtered by a short-name text marker (in this case "OL-") in the specified category, but have very low participation in the course during the specified time period (fewer than 2 "Edits" to Activity Modules, indicating few active contributions to the course). The number of "Edits" is provided for each student for the time period specified.

An "Edit" is defined as course activity other than viewing content. Click the "Logs" link to review the student activity. The Logs offer the option to review "View" activity as well as "Edit" activity.

Only "visible" courses are included in this report. The report may be downloaded as an Excel spreadsheet.

Don't forget to set up Filters: "Start / End date filter" and "Filter categories" on the Filters tab in Configurable reports.

SELECT u.lastname AS Last, u.firstname AS First, u.idnumber AS IDnumber, u.email AS email, c.shortname AS CourseID,  count(l.id) AS Edits, CONCAT('<a target="_new" href="https://learn.granite.edu/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=-view&logformat=showashtml','">','Logs','</a>') AS Link

FROM prefix_user AS u
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid

LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id AND l.action NOT LIKE "view%" %%FILTER_STARTTIME:l.TIME:>%% %%FILTER_ENDTIME:l.TIME:<%%

WHERE ra.roleid =5
AND ctx.instanceid = c.id
AND c.visible=1
# This prefix filter allows the exclusion of non-online courses at the original institution. Alter this to fit your institution, or remove it.
AND c.shortname LIKE '%OL-%'
%%FILTER_CATEGORIES:c.category%%

GROUP BY u.idnumber

HAVING Edits < 2

Messages of All Users

Contributed by: Randy Thornton. Updated for Moodle 3.6 and above.

This is a version of this query that has been tested with Moodle 3.10 back to Moodle 3.6 (thank you Sandy Noe for testing!)

SELECT
cv.id AS "Conversation_id",
DATE_FORMAT(FROM_UNIXTIME(me.timecreated), '%Y-%m-%d %H:%i') AS "At",
(SELECT CONCAT(firstname,' ',lastname,' (',username,')') FROM prefix_user WHERE id = me.useridfrom) AS 'From',

(SELECT 
 GROUP_CONCAT(DISTINCT CONCAT(u.firstname ,' ',lastname,' (',username,')'))
 FROM prefix_user u
 JOIN prefix_message_conversation_members cvm ON cvm.userid = u.id
 WHERE cvm.conversationid = cv.id
 AND u.id != me.useridfrom 
 GROUP BY cvm.conversationid
) AS "To",
IF(me.subject IS NULL, "(reply)", me.subject) AS "Subject",
me.fullmessage AS "Message"

FROM prefix_messages me
JOIN prefix_message_conversations cv ON cv.id = me.conversationid

ORDER BY cv.id, me.timecreated

NOTE: This query will return a lot of data, probably too much. In that case, you will probably need to add a WHERE clause or other method to this query to limit or restrict it, for example by date range or usernames, etc. See this post for an example of date range.

(If you need the earlier version of this query, for Moodle 3.4 or earlier (please upgrade!), then take a look at the earlier versions of this page for your particular version of Moodle. - RT)

Unread Moodle Messages

This report will show a list of unread Moodle messages with a direct link to view messages from applicable users. Contributed by: Ben Haensel. This is a version of this query that has been tested with Moodle 3.9

SELECT u.id userid,
concat('<a target="_blank" href="%%WWWROOT%%/message/index.php?id=',u.id,'">',u.lastname, ', ', u.firstname,'</a>') User
from prefix_messages m
join prefix_message_conversations mc ON mc.id = m.conversationid
join prefix_message_conversation_members mcm ON m.conversationid = mcm.conversationid
left join prefix_message_user_actions mua ON mua.messageid = m.id AND mua.userid = %%USERID%%
left join prefix_message_conversation_members mcx on mcx.conversationid = mcm.conversationid
and mcx.userid <> mcm.userid
left join prefix_user u on u.id = mcx.userid
where mcm.userid = %%USERID%%
and m.useridfrom <> %%USERID%%
and mua.id is NULL
order by u.lastname, u.firstname

List of attendees/students that were marked present across courses

This report will pull all Present students across a specific category. Contributed by: Emma Richardson

SELECT u.firstname AS "First Name", u.lastname AS "Last Name", u.Institution AS "District",c.fullname AS "Training", DATE_FORMAT(FROM_UNIXTIME(att.sessdate),'%d %M %Y')AS Date

FROM prefix_attendance_sessions AS att
JOIN prefix_attendance_log AS attlog ON att.id = attlog.sessionid
JOIN prefix_attendance_statuses AS attst ON attlog.statusid = attst.id
JOIN prefix_attendance AS a ON att.attendanceid = a.id
JOIN prefix_course AS c ON a.course = c.id
JOIN prefix_user AS u ON attlog.studentid = u.id

WHERE attst.acronym = "P"
AND c.category = INSERT YOUR CATEGORY ID HERE
ORDER BY c.fullname

List of deactivated users in a course

List of deactivated users in a specific course

SELECT username, idnumber,
concat('<a target="_new" href="%%WWWROOT%%/user/profile.php?id=',uu.id,'">',uu.id,'</a>') as userid_and_link,
firstname, lastname, email, suspended as 'suspended/deactivated: 1'
FROM prefix_user_enrolments ue
JOIN prefix_enrol en ON ue.enrolid = en.id
JOIN prefix_user uu ON uu.id = ue.userid 
WHERE en.courseid = 1234567
AND suspended = 1

List of users and their private files

List all users who use private files and list all files in their private repository

Select u.firstname, u.lastname, u.username,
concat('<a target="_new" href="%%WWWROOT%%/user/view.php?id=',u.id,'">',u.id,'</a>') as 'ID and Link to User Profilel', 
DATE_FORMAT(FROM_UNIXTIME(u.lastlogin), '%e %b %Y') AS 'lastlogin', u.suspended AS 'activated (0) or deactivated (1) User', f.filename, f.filesize
from prefix_files AS f 
JOIN prefix_user AS u ON u.id = f.userid 
where filearea = "private" 
AND f.filename != "."


List of all private files of users as alias/shortcut to any activity/course

Lists all files of users that have been linked as "alias/shortcut" to any activity/course

select f.contextid, f.component, f.filearea, f.filename,
concat('<a target="_new" href="%%WWWROOT%%/user/view.php?id=',f.userid,'">',f.userid,'</a>') as 'ID and Link to Userprofile',
u.firstname, u.lastname,
f.filesize, f.mimetype, f.source, f.author, f.referencefileid,
c.instanceid as 'ID from prefix_context',
cm.id as 'ID from prefix_course_modules',
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',cm.course,'</a>') as kursid_and_link,
co.fullname,
co.shortname
from prefix_files as f
JOIN prefix_context AS c ON c.id = f.contextid
JOIN prefix_course_modules as cm ON cm.id = c.instanceid
JOIN prefix_user as u ON u.id = f.userid
JOIN prefix_course as co ON co.id = cm.course
where referencefileid IS NOT NULL


Log Activity Reports

Count all Active Users by ROLE in a course category (including all of its sub-categories)

SELECT COUNT(DISTINCT l.userid) as active
FROM mdl_course as c
JOIN mdl_context AS ctx ON  ctx.instanceid=c.id
JOIN mdl_role_assignments AS ra ON ra.contextid = ctx.id
JOIN mdl_user_lastaccess as l ON ra.userid = l.userid
JOIN mdl_course_categories AS cats ON c.category = cats.id
WHERE c.category=cats.id AND (
	cats.path LIKE '%/80/%'
	OR cats.path LIKE '%/80'
) 
AND ra.roleid=3  AND ctx.contextlevel=50  #ra.roleid= TEACHER 3, NON-EDITING TEACHER 4, STUDENT 5
AND  l.timeaccess > (unix_timestamp() - ((60*60*24)*NO_OF_DAYS)) #NO_OF_DAYS change to number

Detailed "VIEW" ACTION for each ROLE (TEACHER,NONE-EDITING TEACHER and STUDENT)

SELECT l.action, count( l.userid ) as counter , r.name
FROM `prefix_log` as l
JOIN `prefix_role_assignments` AS ra on l.userid = ra.userid
JOIN `prefix_role` AS r ON ra.roleid = r.id
WHERE (ra.roleid IN (3,4,5)) AND (l.action LIKE '%view%' )
GROUP BY roleid,l.action
order by r.name,counter desc

Total Activity of Roles:"Teacher" and "None-Editing Teacher" by Dates and by Hours

The output columns of this report table can be used as base for a Pivot-Table which will show the amount of activity per hour per days in 3D graph view.

SELECT DATE_FORMAT( FROM_UNIXTIME( l.time ) , '%Y-%m-%d' ) AS grptimed ,
DATE_FORMAT( FROM_UNIXTIME( l.time ) , '%k' ) AS grptimeh  , count( l.userid ) AS counter 
FROM `prefix_log` AS l
JOIN prefix_user AS u ON u.id = l.userid
JOIN prefix_role_assignments AS ra ON l.userid = ra.userid
JOIN prefix_role AS r ON r.id = ra.roleid
WHERE ra.roleid IN (3,4)
GROUP BY grptimed,grptimeh
ORDER BY grptimed,grptimeh

How many LOGINs per user and user's Activity

+ link username to a user activity graph report

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/user.php?id=1&user=',u.id,'&mode=alllogs">',u.firstname ,' ',u.lastname,'</a>') as Username
,count(*) as logins
,(SELECT count(*) FROM prefix_log WHERE userid = l.userid GROUP BY userid) as Activity 
FROM prefix_log as l JOIN prefix_user as u ON l.userid = u.id 
WHERE `action` LIKE '%login%' group by userid
ORDER BY Activity DESC

Distinct user logins per month

Contributed by: Randy Thornton

The following will show you the months of the current calendar year with the total number of distinct, unique user logins per month. Change the year in the WHERE clause to the year you need.

SELECT 
 COUNT(DISTINCT l.userid) AS 'DistinctUserLogins', 
 DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%M') AS 'Month'
FROM prefix_logstore_standard_log l
WHERE l.action = 'loggedin' AND YEAR(FROM_UNIXTIME(l.timecreated)) = '2017' 
GROUP BY MONTH(FROM_UNIXTIME(l.timecreated))

Total activity per course, per unique user on the last 24h

SELECT
    COUNT(DISTINCT userid) AS countUsers
  , COUNT(l.courseid) AS countVisits
  , CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">', c.fullname, '</a>') AS Course

FROM mdl_logstore_standard_log AS l
  JOIN mdl_course AS c ON c.id = l.courseid
WHERE l.courseid > 0
      AND FROM_UNIXTIME(l.timecreated) >= DATE_SUB(NOW(), INTERVAL 1 DAY)
      AND c.fullname LIKE '%תשעו%'
GROUP BY l.courseid
ORDER BY countVisits DESC

Weekly Instructor Online Participation

Contributed by Elizabeth Dalton, Granite State College

Displays participation of instructors in all courses per week of a term, including pre-term and post-term edits. An edit is defined as a change to the course, such as a discussion post, the grading of an assignment, or the uploading of file attachments, as well as alterations to course content.

  • To specify a subject and/or course number, use % as a wildcard, e.g. ARTS% or ARTS501%
  • To match part of a last name, use %, e.g. Smi% will match "Smith", "Smile", etc.

At our institution, we include filters on the course name or category to constrain by terms. These are very specific to how course names and categories are constructed at our institution, so I've removed those elements from this code. Also, our terms are 12 weeks long. You would want to insert additional "SUM" lines for longer terms, or remove lines for shorter terms.

Note: This report can take a long time to run. While it can be run in Configurable Reports on demand, it may be more appropriate to implement it in the Ad Hoc Queries plugin as a scheduled report.

Note: This version uses legacy (pre-2.7) logs. See below for post-2.7 Standard Logs version.

SELECT 
c.shortname AS CourseID
, cc.name AS Category
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor

, (SELECT COUNT( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students

, c.startdate AS Course_Start_Date

, c.visible AS Visible

,  COUNT(l.id) AS Edits

, SUM(IF(WEEK(FROM_UNIXTIME(l.time)) - WEEK(FROM_UNIXTIME(c.startdate))<0,1,0)) AS BeforeTerm

, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=0,1,0)) AS Week1
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=1,1,0)) AS Week2
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=2,1,0)) AS Week3
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=3,1,0)) AS Week4
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=4,1,0)) AS Week5
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=5,1,0)) AS Week6
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=6,1,0)) AS Week7
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=7,1,0)) AS Week8
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=8,1,0)) AS Week9
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=9,1,0)) AS Week10
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=10,1,0)) AS Week11
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=11,1,0)) AS Week12

, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))>=12,1,0)) AS AfterTerm

, CONCAT('<a target="_new" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS Link

FROM prefix_user AS u
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id

LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id  AND l.action NOT LIKE "view%"

WHERE ra.roleid =3
AND ctx.instanceid = c.id
AND c.shortname LIKE :course
AND u.lastname LIKE :last_name

GROUP BY u.idnumber, c.id
HAVING students > 0
ORDER BY c.shortname

Note: Post-2.7 log version:

SELECT 
c.shortname AS CourseID
, cc.name AS Category
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor

, (SELECT COUNT( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students

, FROM_UNIXTIME(c.startdate) AS Course_Start_Date

, c.visible AS Visible

,  COUNT(DISTINCT l.id) AS Edits

, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'

, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=7,l.id,NULL)) AS 'Week 8'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=8,l.id,NULL)) AS 'Week 9'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=9,l.id,NULL)) AS 'Week 10'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=10,l.id,NULL)) AS 'Week 11'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=11,l.id,NULL)) AS 'Week 12'

, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'

, CONCAT('<a target="_new" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS Link

FROM prefix_user AS u
LEFT JOIN prefix_role_assignments AS ra ON u.id = ra.userid
LEFT JOIN prefix_context AS ctx ON ra.contextid = ctx.id
LEFT JOIN prefix_course AS c ON c.id = ctx.instanceid
LEFT JOIN prefix_course_categories as cc ON c.category = cc.id

LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id  AND l.crud IN ('c','u')

WHERE ra.roleid =3
AND ctx.instanceid = c.id
AND c.shortname LIKE '%OL-%'
AND cc.idnumber LIKE '%current%'

GROUP BY u.idnumber, c.id
#HAVING students > 0
ORDER BY RIGHT(c.shortname,2), c.shortname

Weekly Student Online Participation

Contributed by Elizabeth Dalton, Granite State College

Displays participation of students in the current course by week, including pre-term and post-term edits. An edit is defined as a change to the course, such as a discussion post, the submission of an assignment, or the completion of a quiz, as well as alterations to course content such as database entries (if permitted).

Links to three other reports are also provided:

  • Logs: complete log entries for the student in the course, organized by date
  • Activity Outline: the "Outline Report" from the User Activity Reports, summarizing the student's activity in the course, organized by course content
  • Consolidated Activity Report: the "Complete Report" from the User Activity Reports, detailing the student's activity in the course, organized by course content (includes text of forum posts)

Note: This should be defined as a "Global" report (visible from within all courses). At our institution, our terms are 12 weeks long. You would want to insert additional "SUM" lines for longer terms, or remove lines for shorter terms. We pull advisor names into student user profiles as part of our configuration. These lines are present in the code below, but are commented out, as they are very specific to your Moodle configuration.

Note: This version of the report uses legacy (pre-2.7) logs. See below for a post-2.7 Standard Logs version.

SELECT 
u.lastname AS 'Last Name'
, u.firstname AS 'First Name'
,  COUNT(l.id) AS 'Edits'

, SUM(IF((l.time-c.startdate)/7<0,1,0)) AS 'Before Term'

, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=0,1,0)) AS 'Week 1'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=1,1,0)) AS 'Week 2'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=2,1,0)) AS 'Week 3'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=3,1,0)) AS 'Week 4'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=4,1,0)) AS 'Week 5'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=5,1,0)) AS 'Week 6'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=6,1,0)) AS 'Week 7'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=7,1,0)) AS 'Week 8'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=8,1,0)) AS 'Week 9'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=9,1,0)) AS 'Week 10'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=10,1,0)) AS 'Week 11'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=11,1,0)) AS 'Week 12'

, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))>=15,1,0)) AS 'After Term'

, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS 'Logs'

, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=outline">','Outline','</a>') AS 'Activity Outline'

, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=complete">','Activity','</a>') AS 'Consolidated Activity'

FROM prefix_user AS u
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id

LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id  AND l.action NOT LIKE "view%"

WHERE ra.roleid =5
AND ctx.instanceid = c.id

AND c.id = %%COURSEID%%

GROUP BY u.idnumber

ORDER BY u.lastname, u.firstname

Note: Post-2.7 (Standard Logs) version

SELECT 
u.lastname AS 'Last Name'
, u.firstname AS 'First Name'
,  COUNT(l.id) AS 'Edits'

, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'

, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=7,l.id,NULL)) AS 'Week 8'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=8,l.id,NULL)) AS 'Week 9'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=9,l.id,NULL)) AS 'Week 10'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=10,l.id,NULL)) AS 'Week 11'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=11,l.id,NULL)) AS 'Week 12'

, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'

# Our institution stores academic advisor names and emails in custom profile fields
#, CONCAT('<a href="mailto:',uce.data,'">',uid.data, '</a>')  AS 'Academic Advisor'

, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/log/index.php',CHAR(63),'chooselog=1&showusers=1&showcourses=0&id=',c.id,'&user=',u.id,'&date=0&modid=&modaction=&logformat=showashtml','">','Logs','</a>') AS 'Logs'

, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=outline">','Outline','</a>') AS 'Activity Outline'

, CONCAT('<a target="_blank" href="%%WWWROOT%%/report/outline/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'&mode=complete">','Activity','</a>') AS 'Consolidated Activity'

, CONCAT('<a target="_blank" href="%%WWWROOT%%/mod/forum/user.php',CHAR(63),'id=',u.id,'&course=',c.id,'">','Posts','</a>') AS 'Posts'

FROM prefix_user AS u
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id

# student academic coach - you can include custom profile field data with these methods
# LEFT JOIN prefix_user_info_data as uid ON u.id = uid.userid AND uid.fieldid = '2'
# student academic coach email
# LEFT JOIN prefix_user_info_data as uce on u.id = uce.userid AND uce.fieldid = '6'

LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id  AND l.crud IN ('c','u')

WHERE ra.roleid =5
AND ctx.instanceid = c.id

AND c.id = %%COURSEID%%

GROUP BY u.idnumber

ORDER BY u.lastname, u.firstname

My Weekly Online Participation

Contributed by Elizabeth Dalton, Granite State College

Displays participation of the current user in the current course by week, including pre-term and post-term submissions/edits. A submission/edit is defined as a change to the course, such as a discussion post, the submission of an assignment, or the completion of a quiz, as well as alterations to course content such as database entries or new course activities or resources (if permitted).

This report uses Standard Logs (post 2.7).

SELECT 

l.component AS 'activity'

, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'

, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=7,l.id,NULL)) AS 'Week 8'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=8,l.id,NULL)) AS 'Week 9'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=9,l.id,NULL)) AS 'Week 10'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=10,l.id,NULL)) AS 'Week 11'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=11,l.id,NULL)) AS 'Week 12'

, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'

,  COUNT(l.id) AS 'Total'

FROM prefix_user AS u
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id

LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id  AND l.crud IN ('c','u')

WHERE 1
AND ctx.instanceid = c.id

AND c.id = %%COURSEID%%
AND u.id = %%USERID%%

GROUP BY l.component

ORDER BY l.component

Faculty/Student Interactions

Contributed by Elizabeth Dalton, Granite State College

Returns a count of instructor and other-student responses to student activity for the specified time period. This report can help indicate whether students' comments are being responded to, as well as summarizing post activity by students during the specified time.

Note: This version of the report uses legacy (pre-2.7) logs. See below for the post-2.7 Standard Logs version.

Note: This should be defined as a "Global" report (visible from within all courses).

Note: This report can take a long time to run.


SELECT 

# Identify student
CONCAT('<a target="_blank" href="%%WWWROOT%%/message/index.php?id=' , allstu.id , '">' , allstu.firstname , ' ' , allstu.lastname , '</a>' ) AS 'Student - click to send message'

, IF((COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL) )>0) OR (COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL))>0) OR  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id AND mfs.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))),'YES','NO') AS 'Student Participated This week'

, IF((COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) )>0) OR (COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asg.id,NULL))>0) OR (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id  AND mts.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))),'YES','NO') AS 'Student Contacted This week'

## Only posts within last 7 days

# Count posts by student
, COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL)) AS 'Forum Stu Posts - 7 days'

# Count replies to student posts by instructors
, COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Instr Replies - 7 days'

# using link back to student posts on replies, get unique student IDs responded
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpsr.id,NULL)) - COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Stu Replies - 7 days'

# all replies
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpsr.id,NULL)) AS 'Forum All Replies - 7 days'

# add in count of graded assignments - 7 days
, COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL)) AS 'Assign Submit - 7 days'
, COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asg.id,NULL)) AS 'Assign Grades - 7 days'

# Messages between students and instructors - 7 days
,  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id AND mfs.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))) AS 'Msg Stu to Instr - 7 days'
, (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id  AND mts.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))) AS 'Msg Instr to Stu - 7 days'

## All posts in course so far
# Count posts by student
, COUNT(DISTINCT fps.id) AS 'Forum Stu Posts - to date'

# Count replies to student posts by instructors
, COUNT(DISTINCT fpi.id) AS 'Forum Instr Replies - to date'

# using link back to student posts on replies, get unique student IDs responded
, COUNT(DISTINCT fpsr.id) - COUNT(DISTINCT fpi.id) AS 'Forum Stu Replies - to date'

# all replies
, COUNT(DISTINCT fpsr.id) AS 'Forum All Replies - to date'

# add in count of graded assignments - whole course
, COUNT(DISTINCT asb.id) AS 'Assign Submit - to date'
, COUNT(DISTINCT asg.id) AS 'Assign Grades - to date'

# Messages between students and instructors - to date
,  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id ) AS 'Msg Stu to Instr - to date'
, (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id) AS 'Msg Instr to Stu - to date'

## JOINS

# Start by getting all the students in the course
FROM prefix_user AS allstu 
JOIN prefix_role_assignments AS ras ON allstu.id = ras.userid AND ras.roleid = 5
JOIN prefix_context AS ctx  ON ras.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id

# Now we get the forums and forum discussions from this course only
LEFT JOIN prefix_forum AS frm ON frm.course = c.id AND c.id = %%COURSEID%%
LEFT JOIN prefix_forum_discussions AS fd ON fd.course = %%COURSEID%% AND fd.forum = frm.id

# These are forum discussion posts just by students within specified time
LEFT JOIN prefix_forum_posts AS fps ON fps.userid = allstu.id AND fps.discussion = fd.id

# Separately, we connect the instructors of the courses
# We can use the context we have already gotten for the students
LEFT JOIN prefix_role_assignments AS rai ON rai.contextid = ctx.id
LEFT JOIN prefix_user AS instr ON instr.id = rai.userid AND rai.roleid =3

# Now we will connect to posts by instructors that are replies to student posts
# This is a left join, because we don't want to eliminate any students from the list
LEFT JOIN prefix_forum_posts AS fpi ON fpi.discussion = fd.id AND fpi.userid = instr.id AND fpi.parent = fps.id

# To get identities of only those students who were replied to:
# Connect from instr replies back up to parent posts by students again
# This has to be a LEFT JOIN, we know these posts exist but don't eliminate non-responded students
LEFT JOIN prefix_forum_posts AS fpir ON fpir.id = fpi.parent

# We also want to know if students are replying to one another
# These are posts that are replies to student posts
# Again, a left join
LEFT JOIN prefix_forum_posts AS fpsr ON fpsr.discussion = fd.id AND fpsr.parent = fps.id

# get the activity modules
LEFT JOIN prefix_course_modules AS cm ON c.id = cm.course

# get the assignments
LEFT JOIN prefix_assign AS a ON  cm.instance = a.id
 LEFT JOIN prefix_assign_submission AS asb ON a.id = asb.assignment AND asb.userid=allstu.id 
LEFT JOIN prefix_assign_grades AS asg ON asg.assignment = a.id AND asg.userid = allstu.id AND asg.assignment = asb.assignment 

# We care about messages that involve both the instructor and students of this course
# messages from instructor to students:
# LEFT JOIN prefix_message AS mts ON mts.useridfrom = instr.id AND mts.useridto = allstu.id
# LEFT JOIN prefix_message AS mfs ON mfs.useridfrom = instr.id AND mfs.useridto = allstu.id

WHERE  
c.id = %%COURSEID%% 

# GROUP BY c.shortname , allstu.id
GROUP BY allstu.id

ORDER BY allstu.lastname

Note: Post-2.7 Standard Logs version

SELECT 

# Identify student
CONCAT('<a target="_blank" href="%%WWWROOT%%/message/index.php?id=' , allstu.id , '">' , allstu.firstname , ' ' , allstu.lastname , '</a>' ) AS 'Student - click to send message'

, IF((COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL) )>0) OR (COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL))>0) OR  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id AND mfs.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))),'YES','NO') AS 'Student Participated This week'

, IF((COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) )>0) OR (COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asg.id,NULL))>0) OR (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id  AND mts.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))),'YES','NO') AS 'Student Contacted This week'

## Only posts within last 7 days

# Count posts by student
, COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL)) AS 'Forum Stu Posts - 7 days'

# Count replies to student posts by instructors
, COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Instr Replies - 7 days'

# using link back to student posts on replies, get unique student IDs responded
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpsr.id,NULL)) - COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Stu Replies - 7 days'

# all replies
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpsr.id,NULL)) AS 'Forum All Replies - 7 days'

# add in count of graded assignments - 7 days
, COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL)) AS 'Assign Submit - 7 days'
, COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asg.id,NULL)) AS 'Assign Grades - 7 days'

# Messages between students and instructors - 7 days
,  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id AND mfs.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))) AS 'Msg Stu to Instr - 7 days'
, (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id  AND mts.timecreated > (UNIX_TIMESTAMP()  - (7*24*60*60))) AS 'Msg Instr to Stu - 7 days'

## All posts in course so far
# Count posts by student
, COUNT(DISTINCT fps.id) AS 'Forum Stu Posts - to date'

# Count replies to student posts by instructors
, COUNT(DISTINCT fpi.id) AS 'Forum Instr Replies - to date'

# using link back to student posts on replies, get unique student IDs responded
, COUNT(DISTINCT fpsr.id) - COUNT(DISTINCT fpi.id) AS 'Forum Stu Replies - to date'

# all replies
, COUNT(DISTINCT fpsr.id) AS 'Forum All Replies - to date'

# add in count of graded assignments - whole course
, COUNT(DISTINCT asb.id) AS 'Assign Submit - to date'
, COUNT(DISTINCT asg.id) AS 'Assign Grades - to date'

# Messages between students and instructors - to date
,  (SELECT COUNT(DISTINCT mfs.id) FROM prefix_message AS mfs WHERE mfs.useridfrom = allstu.id AND mfs.useridto = instr.id ) AS 'Msg Stu to Instr - to date'
, (SELECT COUNT(DISTINCT mts.id) FROM prefix_message AS mts WHERE mts.useridfrom = instr.id AND mts.useridto = allstu.id) AS 'Msg Instr to Stu - to date'

## JOINS

# Start by getting all the students in the course
FROM prefix_user AS allstu 
JOIN prefix_role_assignments AS ras ON allstu.id = ras.userid AND ras.roleid = 5
JOIN prefix_context AS ctx  ON ras.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id

# Now we get the forums and forum discussions from this course only
JOIN prefix_forum AS frm ON frm.course = c.id AND c.id = %%COURSEID%%
JOIN prefix_forum_discussions AS fd ON fd.course = %%COURSEID%% AND fd.forum = frm.id

# These are forum discussion posts just by students within specified time
LEFT JOIN prefix_forum_posts AS fps ON fps.userid = allstu.id AND fps.discussion = fd.id

# Separately, we connect the instructors of the courses
# We can use the context we have already gotten for the students
JOIN prefix_role_assignments AS rai ON rai.contextid = ctx.id
JOIN prefix_user AS instr ON instr.id = rai.userid AND rai.roleid =3

# Now we will connect to posts by instructors that are replies to student posts
# This is a left join, because we don't want to eliminate any students from the list
LEFT JOIN prefix_forum_posts AS fpi ON fpi.discussion = fd.id AND fpi.userid = instr.id AND fpi.parent = fps.id

# To get identities of only those students who were replied to:
# Connect from instr replies back up to parent posts by students again
# This has to be a LEFT JOIN, we know these posts exist but don't eliminate non-responded students
LEFT JOIN prefix_forum_posts AS fpir ON fpir.id = fpi.parent

# We also want to know if students are replying to one another
# These are posts that are replies to student posts
# Again, a left join
LEFT JOIN prefix_forum_posts AS fpsr ON fpsr.discussion = fd.id AND fpsr.parent = fps.id

# get the activity modules
JOIN prefix_course_modules AS cm ON c.id = cm.course

# get the assignments
 JOIN prefix_assign AS a ON  cm.instance = a.id
 LEFT JOIN prefix_assign_submission AS asb ON a.id = asb.assignment AND asb.userid=allstu.id 
LEFT JOIN prefix_assign_grades AS asg ON asg.assignment = a.id AND asg.userid = allstu.id AND asg.assignment = asb.assignment 

WHERE  
c.id = %%COURSEID%% 

# GROUP BY c.shortname , allstu.id
GROUP BY allstu.id

ORDER BY allstu.lastname

Student Resource Usage

Contributed by Elizabeth Dalton, Granite State College

Displays usage by students of all activities and resources in the current course by activity. Only activities and sections which are visible in the course are included. This version requires the new "Standard Logs" from Moodle 2.7+.

Note: This should be defined as a "Global" report (visible from within all courses).

SELECT 
cs.section AS 'Week'
, cs.name AS 'Section Name'
, m.name AS 'item type'

, CONCAT(
COALESCE(a.name, ''), 
COALESCE(b.name,''), 
COALESCE(cert.name,''), 
COALESCE(chat.name,''), 
COALESCE(choice.name,''), 
COALESCE(data.name,''), 
COALESCE(feedback.name,''), 
COALESCE(folder.name,''), 
COALESCE(forum.name,''), 
COALESCE(glossary.name,''), 
COALESCE(imscp.name,''), 
COALESCE(lesson.name,''), 
COALESCE(p.name,''),
COALESCE(questionnaire.name,''), 
COALESCE(quiz.name,''), 
COALESCE(cr.name,''), 
COALESCE(scorm.name,''), 
COALESCE(survey.name,''), 
COALESCE(url.name,''), 
COALESCE(wiki.name,''), 
COALESCE(workshop.name,''), 
COALESCE(kalvidassign.name,''), 
COALESCE(attendance.name,''), 
COALESCE(checklist.name,''), 
COALESCE(flashcard.name,''), 
COALESCE(lti.name,''), 
COALESCE(oublog.name,''), 
COALESCE(ouwiki.name,''), 
COALESCE(subpage.name,''), 
COALESCE(journal.name,''), 
COALESCE(lightboxgallery.name,''), 
COALESCE(elluminate.name,''), 
COALESCE(adaptivequiz.name,''), 
COALESCE(hotpot.name,''), 
COALESCE(wiziq.name,''), 
COALESCE(turnitintooltwo.name,''), 
COALESCE(kvr.name,'')
) AS 'item name'


, SUM(IF(l.crud IN ('r'),1,0)) AS 'total views'
, SUM(IF(l.crud IN ('c','u'),1,0)) AS 'total submissions'
, COUNT(DISTINCT IF(l.crud IN ('r'),u.id,NULL)) AS 'count of students who viewed'
, COUNT(DISTINCT IF(l.crud IN ('c','u'),u.id,NULL)) AS 'count of students who submitted'

FROM prefix_user AS u
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id

JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section <= 14 #AND cs.section > 0
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
JOIN prefix_modules AS m ON m.id = cm.module AND m.name NOT LIKE 'label'

LEFT JOIN prefix_assign AS a ON a.id = cm.instance AND m.name = 'assign'
LEFT JOIN prefix_book AS b ON b.id = cm.instance AND m.name = 'book'
LEFT JOIN prefix_certificate AS cert ON cert.id = cm.instance AND m.name = 'certificate'
LEFT JOIN prefix_chat AS chat ON chat.id = cm.instance AND m.name = 'chat'
LEFT JOIN prefix_choice AS choice ON choice.id = cm.instance AND m.name = 'choice'
LEFT JOIN prefix_data AS data ON data.id = cm.instance AND m.name = 'data'
LEFT JOIN prefix_feedback AS feedback ON feedback.id = cm.instance AND m.name = 'feedback'
LEFT JOIN prefix_folder AS folder ON folder.id = cm.instance AND m.name = 'folder'
LEFT JOIN prefix_forum AS forum ON forum.id = cm.instance AND m.name = 'forum'
LEFT JOIN prefix_glossary AS glossary ON glossary.id = cm.instance AND m.name = 'glossary'
LEFT JOIN prefix_imscp AS imscp ON imscp.id = cm.instance AND m.name = 'imscp'
LEFT JOIN prefix_lesson AS lesson ON lesson.id = cm.instance AND m.name = 'lesson'
LEFT JOIN prefix_page AS p ON p.id = cm.instance AND m.name = 'page'
LEFT JOIN prefix_questionnaire AS questionnaire ON questionnaire.id = cm.instance AND m.name = 'questionnaire'
LEFT JOIN prefix_quiz AS quiz ON quiz.id = cm.instance AND m.name = 'quiz'
LEFT JOIN prefix_resource AS cr ON cr.id = cm.instance AND m.name = 'resource'
LEFT JOIN prefix_scorm AS scorm ON scorm.id = cm.instance AND m.name = 'scorm'
LEFT JOIN prefix_survey AS survey ON survey.id = cm.instance AND m.name = 'survey'
LEFT JOIN prefix_url AS url ON url.id = cm.instance AND m.name = 'url'
LEFT JOIN prefix_wiki AS wiki ON wiki.id = cm.instance AND m.name = 'wiki'
LEFT JOIN prefix_workshop AS workshop ON workshop.id = cm.instance AND m.name = 'workshop'
LEFT JOIN prefix_kalvidassign AS kalvidassign ON kalvidassign.id = cm.instance AND m.name = 'kalvidassign'
LEFT JOIN prefix_kalvidres AS kvr ON kvr.id = cm.instance AND m.name = 'kalvidres'
LEFT JOIN prefix_attendance AS attendance ON attendance.id = cm.instance AND m.name = 'attendance'
LEFT JOIN prefix_checklist AS checklist ON checklist.id = cm.instance AND m.name = 'checklist'
LEFT JOIN prefix_flashcard AS flashcard ON flashcard.id = cm.instance AND m.name = 'flashcard'
LEFT JOIN prefix_lti AS lti ON lti.id = cm.instance AND m.name = 'lti'
LEFT JOIN prefix_oublog AS oublog ON oublog.id = cm.instance AND m.name = 'oublog'
LEFT JOIN prefix_ouwiki AS ouwiki ON ouwiki.id = cm.instance AND m.name = 'ouwiki'
LEFT JOIN prefix_subpage AS subpage ON subpage.id = cm.instance AND m.name = 'subpage'
LEFT JOIN prefix_journal AS journal ON journal.id = cm.instance AND m.name = 'journal'
LEFT JOIN prefix_lightboxgallery AS lightboxgallery ON lightboxgallery.id = cm.instance AND m.name = 'lightboxgallery'
LEFT JOIN prefix_elluminate AS elluminate ON elluminate.id = cm.instance AND m.name = 'elluminate'
LEFT JOIN prefix_adaptivequiz AS adaptivequiz ON adaptivequiz.id = cm.instance AND m.name = 'adaptivequiz'
LEFT JOIN prefix_hotpot AS hotpot ON hotpot.id = cm.instance AND m.name = 'hotpot'
LEFT JOIN prefix_wiziq AS wiziq ON wiziq.id = cm.instance AND m.name = 'wiziq'
LEFT JOIN prefix_turnitintooltwo AS turnitintooltwo ON turnitintooltwo.id = cm.instance AND m.name = 'turnitintooltwo'

LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id


WHERE ra.roleid =5
AND ctx.instanceid = c.id
AND cs.visible = 1
AND cm.visible = 1

AND c.id = %%COURSEID%%

GROUP BY cm.id

ORDER BY cs.section

Module activity (Hits) between dates

SELECT module, COUNT( * ) 
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME( l.`timecreated` ) BETWEEN  '2018-10-01 00:00:00' AND  '2019-09-31 00:00:00')
GROUP BY module

Module activity (Instances and Hits) for each academic year

SELECT name

,(SELECT COUNT(*) 
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2017-10-01 00:00:00' AND '2018-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2017"

,(SELECT COUNT(*) 
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2017-10-01 00:00:00' AND '2018-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2017"

,(SELECT COUNT(*) 
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2018-10-01 00:00:00' AND '2019-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2018"

,(SELECT COUNT(*) 
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2018-10-01 00:00:00' AND '2019-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2018"

,(SELECT COUNT(*) 
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2019-10-01 00:00:00' AND '2020-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2019"

,(SELECT COUNT(*) 
FROM prefix_logstore_standard_log AS l
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2019-10-01 00:00:00' AND '2020-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2019"

FROM mdl_modules AS m

Unique user sessions per day and month + graph

The "graph" column is used when displaying a graph (which needs at least three columns to pick from)

SELECT COUNT(DISTINCT userid) AS "Unique User Logins"
,DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y /%m / %d") AS "Year / Month / Day", "Graph" 
FROM `mdl_logstore_standard_log` 
WHERE action LIKE 'loggedin'
#AND timecreated >  UNIX_TIMESTAMP('2015-01-01 00:00:00') # optional start date
#AND timecreated <= UNIX_TIMESTAMP('2015-01-31 23:59:00') # optional end date
GROUP BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
ORDER BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))

And...

Counting user's global and unique hits per day + counting individual usage of specific activities and resources (on that day),

And since I am using phpMyAdmin's "Display Graph" feature (at the bottom of the query's output page), I have scaled down the "User Hits" by 10 to fit the graph. that's it.

SELECT DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y-%m-%d") AS "Datez"
,COUNT(DISTINCT userid) AS "Unique Users"
,ROUND(COUNT(*)/10) "User Hits (K)"
,SUM(IF(component='mod_quiz',1,0)) "Quizzes"
,SUM(IF(component='mod_forum' or component='mod_forumng',1,0)) "Forums"
,SUM(IF(component='mod_assign',1,0)) "Assignments"
,SUM(IF(component='mod_oublog',1,0)) "Blogs"
,SUM(IF(component='mod_resource',1,0)) "Files (Resource)"
,SUM(IF(component='mod_url',1,0)) "Links (Resource)"
,SUM(IF(component='mod_page',1,0)) "Pages (Resource)"

FROM `mdl_logstore_standard_log` 
WHERE 1=1
AND timecreated >  UNIX_TIMESTAMP('2015-03-01 00:00:00') # optional START DATE
AND timecreated <= UNIX_TIMESTAMP('2015-05-31 23:59:00') # optional END DATE
GROUP BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
ORDER BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))

System wide, daily unique user hits for the last 7 days

SELECT
  DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%m%d') 'Day'
  ,COUNT(DISTINCT l.userid) AS 'Distinct Users Hits'
  ,COUNT( l.userid) AS 'Users Hits'

FROM prefix_logstore_standard_log AS l
WHERE l.courseid > 1
      AND FROM_UNIXTIME(l.timecreated) >= DATE_SUB(NOW(), INTERVAL 7 DAY)
GROUP BY DAY(FROM_UNIXTIME(timecreated))

User detailed activity in course modules

Considering only several modules: url, resource, forum, quiz, questionnaire.

SELECT u.id, ra.roleid,
CONCAT(u.lastname, ' ', u.firstname) AS 'Student'
,COUNT(l.id) AS 'Actions'
,l.component "Module type"
,l.objectid "Module ID"
,CASE 
  WHEN l.component = 'mod_url' THEN (SELECT u.name FROM prefix_url AS u WHERE u.id = l.objectid )
  WHEN l.component = 'mod_resource' THEN (SELECT r.name FROM prefix_resource AS r WHERE r.id = l.objectid )
  WHEN l.component = 'mod_forum' THEN (SELECT f.name FROM prefix_forum AS f WHERE f.id = l.objectid )
  WHEN l.component = 'mod_quiz' THEN (SELECT q.name FROM prefix_quiz AS q WHERE q.id = l.objectid )
  WHEN l.component = 'mod_questionnaire' THEN (SELECT q.name FROM prefix_questionnaire AS q WHERE q.id = l.objectid )
END AS 'Module name'

,(SELECT GROUP_CONCAT(g.name) FROM prefix_groups AS g
JOIN prefix_groups_members AS m ON g.id = m.groupid WHERE g.courseid = l.courseid AND m.userid = u.id) "user_groups"

,(SELECT s.name 
  FROM prefix_course_modules AS cm 
  JOIN prefix_course_sections AS s ON s.course = cm.course AND s.id = cm.section 
  WHERE cm.id = l.contextinstanceid) AS "Section name"

FROM prefix_logstore_standard_log AS l  
JOIN prefix_user AS u ON u.id = l.userid
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid 
  AND ra.contextid = (SELECT id FROM prefix_context WHERE instanceid = l.courseid AND contextlevel = 50) 
WHERE l.courseid = %%COURSEID%%
  AND l.component IN ('mod_url', 'mod_resource', 'mod_forum', 'mod_quiz', 'mod_questionnaire') 
  %%FILTER_STARTTIME:l.timecreated:>%% %%FILTER_ENDTIME:l.timecreated:<%%
 
GROUP BY u.id, l.component
ORDER BY u.lastname, u.firstname

What teachers and courses considered active?

This report display several calculations and parameters that help the Online academic training team find teachers that might need more support getting their courses more supporting of online learning pedagogical methodologies.

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',
			  course.id,'">',course.fullname,'</a>') AS Course 

#,course.shortname

,CASE 
  WHEN course.fullname LIKE '%2012%' THEN '2012'
  WHEN course.fullname LIKE '%2013%' THEN '2013' 
  WHEN course.fullname LIKE '%2014%' THEN '2014'
  WHEN course.fullname LIKE '%2015%' THEN '2015'
END AS Year

,CASE 
  WHEN course.fullname LIKE '%semester a%' THEN 'Spring semester'
  WHEN course.fullname LIKE '%semester b%' THEN 'Fall semester'
  WHEN course.fullname LIKE '%semester s%' THEN 'Summer semester'
END AS Semester

,IF(course.startdate>0, DATE_FORMAT(FROM_UNIXTIME(startdate), '%d-%m-%Y'), 'no date') AS "Course Start Date" 

,(SELECT COUNT( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = course.id
) AS Students

,(SELECT COUNT( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 4 AND ctx.instanceid = course.id
) AS "Assistant teacher"

,(SELECT COUNT( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 3 AND ctx.instanceid = course.id
) AS Teachers

# Uncomment to use the new Moodle 2.8+ logstore
#,(SELECT COUNT(*) FROM mdl_logstore_standard_log AS l WHERE l.courseid = course.id) AS Hits

#,(SELECT COUNT(*)
#FROM mdl_logstore_standard_log AS l
#JOIN mdl_role_assignments AS ra ON ra.userid= l.userid AND ra.roleid = 5 AND ra.contextid = (SELECT id FROM mdl_context WHERE instanceid = l.courseid AND contextlevel = 50) 
#WHERE l.courseid = course.id ) AS "Student HITs"

#,(SELECT COUNT(*)
#FROM mdl_logstore_standard_log AS l
#JOIN mdl_role_assignments AS ra ON ra.userid= l.userid AND ra.roleid = 3 AND ra.contextid = (SELECT id FROM mdl_context WHERE instanceid = l.courseid AND contextlevel = 50) 
#WHERE l.courseid = course.id ) AS "Teacher HITs"

,(SELECT COUNT(*) FROM mdl_log AS l WHERE l.course = course.id) AS Hits

,(SELECT COUNT(*)
FROM mdl_log AS l
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 5 
WHERE l.course = course.id) AS "Students HITs"
 
,(SELECT COUNT(*)
FROM mdl_log AS l
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3 
WHERE l.course = course.id) AS "Teachers HITs"

,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) ) 
FROM prefix_course c
JOIN prefix_context con ON con.instanceid = c.id
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
JOIN prefix_role r ON ra.roleid = r.id
JOIN prefix_user u ON u.id = ra.userid
WHERE r.id = 3 AND c.id = course.id
GROUP BY c.id
) AS Teachers
  
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = course.id) Modules

,(SELECT COUNT(DISTINCT cm.module) FROM prefix_course_modules cm 
  WHERE cm.course = course.id) UniqueModules

,(SELECT GROUP_CONCAT(DISTINCT m.name) 
  FROM prefix_course_modules cm 
  JOIN mdl_modules as m ON m.id = cm.module
  WHERE cm.course = course.id) UniqueModuleNames

,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module 
  WHERE cm.course = course.id AND m.name IN ( 'ouwiki', 'wiki') ) "Num Wikis"

,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module 
  WHERE cm.course = course.id AND m.name IN ( 'oublog') ) "Num Blogs"

,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module 
  WHERE cm.course = course.id AND m.name IN ( 'forum', 'forumng') ) "Num Forums"

,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module 
  WHERE cm.course = course.id AND m.name IN ('resource', 'folder', 'url', 'tab', 'file', 'book', 'page') ) Resources

,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module 
  WHERE cm.course = course.id AND m.name IN ('forum', 'forumng', 'oublog', 'page', 'file', 'url', 'wiki' , 'ouwiki') ) "Basic Activities"

,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module 
  WHERE cm.course = course.id AND m.name IN ('advmindmap', 'assign', 'attendance', 'book', 'choice', 'folder', 'tab', 'glossary', 'questionnaire', 'quiz', 'label' ) ) "Avarage Activities"

,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module 
  WHERE cm.course = course.id AND m.name IN ('elluminate', 'game', 'workshop') ) "Advanced Activities"

FROM prefix_course AS course

#WHERE course.shortname LIKE '%2015%'
#WHERE 1=1
#%%FILTER_SEARCHTEXT:course.shortname:~%%

WHERE course.fullname LIKE '%2015%' 

HAVING Modules > 2
ORDER BY UniqueModules DESC

Weekly attendance report

This report display weekly report in format HH:M:SS This MySQL query works together with AttendaceRegister module, and gather Log information from Attendanceregister_log table.

SELECT u.username, SEC_TO_TIME (SUM(arsess.duration)) AS weekly_online_attendance,  FROM_UNIXTIME (arsess.logout) AS Last_Logout
FROM prefix_attendanceregister_session AS arsess
JOIN prefix_user AS u ON arsess.userid = u.id

WHERE (((arsess.logout) BETWEEN UNIX_TIMESTAMP(DATE_SUB(CURDATE(), INTERVAL 7 DAY)) AND UNIX_TIMESTAMP(CURDATE())))

GROUP BY arsess.userid

How many distinct users connected to Moodle using the app by month

https://moodle.org/mod/forum/discuss.php?d=336086#p1354194 by Iñigo Zendegi Urzelai

SELECT 
  to_char(to_timestamp("timecreated"),'YYYY') as year, 
  to_char(to_timestamp("timecreated"),'MM') as month, 
  count(distinct userid) as distinct_users

FROM prefix_logstore_standard_log l
WHERE l.origin='ws'
GROUP BY to_char(to_timestamp("timecreated"),'YYYY'), to_char(to_timestamp("timecreated"),'MM') 
ORDER BY to_char(to_timestamp("timecreated"),'YYYY'), to_char(to_timestamp("timecreated"),'MM');

Course Reports

Most Active courses

SELECT count(l.userid) AS Views
FROM `mdl_logstore_standard_log` l, `mdl_user` u, `mdl_role_assignments` r
WHERE l.courseid=35
AND l.userid = u.id
AND (l.timecreated > UNIX_TIMESTAMP('2015-01-01 00:00:00') AND l.timecreated <= UNIX_TIMESTAMP('2015-01-31 23:59:59'))AND r.contextid= (
	 SELECT id
	 FROM mdl_context
	 WHERE contextlevel=50 AND instanceid=l.courseid
 )
AND r.roleid=5
AND r.userid = u.id

Active courses, advanced

Including: Teacher's name, link to the course, All types of log activities, special YEAR generated field, Activities and Resource count, enrolled Student count

SELECT COUNT(l.id) hits, concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course 

,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher

,CASE 
  WHEN c.fullname LIKE '%תשע' THEN 'תשע'
  WHEN c.fullname LIKE '%תשעא' THEN 'תשעא'
  WHEN c.fullname LIKE '%תשעב' THEN 'תשעב'
END AS Year

,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = l.course) Modules

,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students

FROM prefix_log l 
INNER JOIN prefix_course c ON l.course = c.id
GROUP BY c.id
#The following line restricts the courses returned to those having more than 2 modules.  Adjust based on your needs.
HAVING Modules > 2
ORDER BY Year DESC, hits DESC

Least active or probably empty courses

Contributed by: Randy Thornton

It is difficult to know sometimes when a course is actually empty or was never really in use. Other than the simple case where the course was created and never touched again, in which case the course timecreated and timemodified will be the same, many courses created as shells for teachers or other users may be used once or a few times and have few or no test users enrollments in them. This query helps you see the range of such courses, showing you how many days if any it was used after initial creation, and how many user are enrolled. It denotes a course never ever modified by "-1" instead of "0" so you can sort those to the top. By default it limits this to courses used within 60 days of creation, and to courses with 3 or less enrollments (for example, teacher and assistant and test student account only.) You can easily adjust these numbers. The query includes a link to the course as well.

SELECT
c.fullname,
CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'CourseLink',
DATE_FORMAT(FROM_UNIXTIME(c.timecreated), '%Y-%m-%d %H:%i') AS 'Timecreated',
DATE_FORMAT(FROM_UNIXTIME(c.timemodified), '%Y-%m-%d %H:%i') AS 'Timemodified',
CASE
 WHEN c.timecreated = c.timemodified THEN '-1'
 ELSE DATEDIFF(FROM_UNIXTIME(c.timemodified),FROM_UNIXTIME(c.timecreated))
END AS 'DateDifference',
COUNT(ue.id) AS Enroled
FROM prefix_course AS c
JOIN prefix_enrol AS en ON en.courseid = c.id
LEFT JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
WHERE DATEDIFF(FROM_UNIXTIME(c.timemodified),FROM_UNIXTIME(c.timecreated) ) < 60
GROUP BY c.id
HAVING COUNT(ue.id) <= 3
ORDER BY c.fullname

Count unique teachers with courses that use at least X module (Moodle19)

You can remove the outer "SELECT COUNT(*) FROM (...) AS ActiveTeachers" SQL query and get the list of the Teachers and Courses.

SELECT COUNT(*)
FROM (SELECT c.id AS CourseID, c.fullname AS Course, ra.roleid AS RoleID, CONCAT(u.firstname, ' ', u.lastname) AS Teacher
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = c.id) AS Modules
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid AND ctx.contextlevel = 50 
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE  ra.roleid = 3 
GROUP BY u.id
HAVING Modules > 5) AS ActiveTeachers

RESOURCE count for each COURSE

SELECT COUNT(l.id) count, l.course, c.fullname coursename
FROM prefix_resource l INNER JOIN prefix_course c on l.course = c.id
GROUP BY course
ORDER BY count DESC

Common resource types count for each Category (Moodle19)

Including sub-categories in total count.

SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category
,(SELECT COUNT( * ) 
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference LIKE 'http://%'
) AS Links
 
,(SELECT COUNT( * ) 
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference NOT LIKE 'http://%'
) AS Files
 
,(SELECT COUNT( * ) 
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'directory' 
) AS Folders
 
,(SELECT COUNT( * ) 
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'html' 
) AS Pages
 
,(SELECT COUNT(*) 
FROM stats_log_context_role_course 
WHERE roleid = 5 AND module = 'resource' AND category = mcc.id
) AS Hits

FROM prefix_course_categories AS mcc
ORDER BY mcc.path

Where "stats_log_context_role_course" (in the above SQL query) is a VIEW generated by:

CREATE VIEW stats_log_context_role_course AS
SELECT l.course, c.category, cc.path, l.module, l.action, ra.userid, ra.roleid
FROM prefix_log AS l
JOIN prefix_context AS context ON context.instanceid = l.course AND context.contextlevel = 50
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid AND ra.contextid = context.id
JOIN prefix_course AS c ON c.id = l.course
JOIN prefix_course_categories AS cc ON cc.id = c.category

Same query but for Moodle2+

SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category,
mcc.path,

(SELECT COUNT(*) 
FROM prefix_url AS u
JOIN prefix_course AS c ON c.id = u.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS URLs,

(SELECT COUNT(*) 
FROM prefix_folder AS f
JOIN prefix_course AS c ON c.id = f.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS FOLDERs,

(SELECT COUNT(*) 
FROM prefix_page AS p
JOIN prefix_course AS c ON c.id = p.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS PAGEs,

(SELECT COUNT(*) 
FROM prefix_book AS b
JOIN prefix_course AS c ON c.id = b.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS BOOKs,

(SELECT COUNT(*) 
FROM prefix_label AS l
JOIN prefix_course AS c ON c.id = l.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS LABELs,

(SELECT COUNT(*) 
FROM prefix_tab AS t
JOIN prefix_course AS c ON c.id = t.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS TABs

FROM prefix_course_categories AS mcc
ORDER BY mcc.path

Detailed Resource COUNT by Teacher in each course

Including (optional) filter by: year, semester and course id.

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS CourseID
, c.id
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher

, (CASE 
WHEN c.fullname LIKE '%תשעב%' THEN '2012' 
WHEN c.fullname LIKE '%תשעא%' THEN '2011'
END ) as Year
, (CASE 
WHEN c.fullname LIKE '%סמסטר א%' THEN 'Semester A' 
WHEN c.fullname LIKE '%סמסטר ב%' THEN 'Semester B'
WHEN c.fullname LIKE '%סמסטר ק%' THEN 'Semester C'
END ) as Semester
,COUNT(c.id) AS Total
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 20) AS TABs
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 33) AS BOOKs

FROM `prefix_resource` as r 
JOIN `prefix_course` AS c on c.id = r.course
#WHERE type= 'file' and reference NOT LIKE 'http://%' 

#WHERE 1=1
#%%FILTER_YEARS:c.fullname%%
#AND c.fullname LIKE '%2013%'

GROUP BY course
ORDER BY COUNT(c.id) DESC

Courses that are defined as using GROUPs

SELECT concat('<a target="_new" href="%%WWWROOT%%/group/index.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = c.id) Modules
,(SELECT count(*) FROM prefix_groups g WHERE g.courseid = c.id) Groups
 FROM `prefix_course` AS c
WHERE groupmode > 0

Courses with Groups

Contributed by: Randy Thornton

List of all courses with Groups in them (groupmode > 0). You can also use groupmode=1 to list just Separate type groups or groupmode=2 to list Visible type groups.

SELECT c.shortname, g.name, c.groupmode
FROM prefix_course AS c
JOIN prefix_groups AS g ON c.id = g.courseid
WHERE c.groupmode > 0

Users enrolled in a course with groups but not assigned a group

Displays by course all enrolled users that have not been assigned a group in courses that have groups. NOTE: This needs to be optimized.

SELECT DISTINCT
user2.firstname AS Firstname,
user2.lastname AS Lastname,
user2.email AS Email,
user2.city AS City,
course.fullname AS Course
,(SELECT shortname FROM prefix_role WHERE id=en.roleid) AS ROLE
,(SELECT name FROM prefix_role WHERE id=en.roleid) AS RoleName

FROM prefix_course AS course 
JOIN prefix_enrol AS en ON en.courseid = course.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
JOIN prefix_user AS user2 ON ue.userid = user2.id
JOIN prefix_groups AS g ON g.courseid = course.id

WHERE ue.enrolid NOT IN (select userid from prefix_groups_members WHERE g.id=groupid)

ORDER BY Course, Lastname

Groups in course with member list

Contributed by: Randy Thornton

List the groups in a course (replace the # by the course id number) with the members of each group.

SELECT c.shortname, g.name AS Groupname, u.username
FROM prefix_course AS c
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_groups_members AS m ON g.id = m.groupid
JOIN prefix_user AS u ON m.userid = u.id
WHERE c.id = #

Note: if you are using Configurable Reports block and want to perform this query on the current course you are in, then you can use a WHERE clause like this:

WHERE c.id = %%COURSEID%%

Group Export

Contributed by: Randy Thornton

There's a group import function, but no export. Use this to give you a report with the proper column order and headings to export to a csv file you can then import into another course to replicate the groups. This is a simple version with just the main fields: groupname, description, enrolment key.

SELECT g.name AS groupname, g.description, g.enrolmentkey
FROM prefix_groups AS g 
JOIN prefix_course as c ON g.courseid = c.id
WHERE c.id = #

Note: if you are using Configurable Reports block and want to perform this query on the current course you are in, then you can use a WHERE clause like this:

WHERE c.id = %%COURSEID%%

List all Courses in and below a certain category

Use this SQL code to retrieve all courses that exist in or under a set category.

$s should be the id of the category you want to know about...

SELECT prefix_course. * , prefix_course_categories. *
FROM prefix_course, prefix_course_categories
WHERE prefix_course.category = prefix_course_categories.id
AND (
prefix_course_categories.path LIKE '%/$s/%'
OR prefix_course_categories.path LIKE '%/$s'
)

List all Categories in one level below a certain category

Use this PHP code to retrieve a list of all categories below a certain category.

$s should be the id of the top level category you are interested in.

<?php

require_once('./config.php');

$parent_id = $s;

$categories= array();

$categories = get_categories($parent_id);

echo '<ol>';
foreach ($categories as $category)
        {
        echo '<li><a href="'.$CFG->wwwroot.'/course/category.php?id='.$category->id.'">'.$category->name.'</a></li>';
        }
echo '</ol>';

?>

Blog activity per Course (not including VIEW)

Filter activity logging to some specific Course Categories! + link course name to actual course (for quick reference) (you can change %blog% to %wiki% to filter down all wiki activity or any other module you wish)

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID
,m.name ,count(cm.id) as counter 
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5
AND ctx.instanceid = c.id
) AS Students
, ( SELECT count(id) FROM prefix_log WHERE `module` LIKE '%blog%' AND course = c.id AND action NOT LIKE '%view%' ) as BlogActivity
FROM `prefix_course_modules` as cm JOIN prefix_modules as m ON cm.module=m.id JOIN prefix_course as c ON cm.course = c.id 
WHERE m.name LIKE '%blog%' AND c.category IN ( 8,13,15)
GROUP BY cm.course,cm.module order by counter desc

Student's posts content in all course blogs (oublog)

SELECT 
b.name 
,op.title
,op.message
,( SELECT CONCAT(u.firstname, ' ',u.lastname) FROM prefix_user AS u WHERE u.id = oi.userid) AS "Username"

FROM prefix_oublog_posts AS op
JOIN prefix_oublog_instances AS oi ON oi.id = op.oubloginstancesid 
JOIN prefix_oublog as b ON b.id = oi.oublogid
JOIN prefix_course AS c ON b.course = c.id

WHERE c.id = %%COURSEID%%

All Courses which uploaded a Syllabus file

+ under specific Category + show first Teacher in that course + link Course's fullname to actual course

SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
,c.shortname,r.name
,(SELECT CONCAT(u.firstname,' ', u.lastname) as Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user as u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) as Teacher
FROM prefix_resource as r 
JOIN prefix_course as c ON r.course = c.id
WHERE ( r.name LIKE '%סילבוס%' OR r.name LIKE '%סילאבוס%' OR r.name LIKE '%syllabus%' OR r.name LIKE '%תכנית הקורס%' ) 
AND c.category IN (10,18,26,13,28)

Site-wide completed SCORM activities by Course name

This report will list all completed attempts for all SCORM activities. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. Please note: the FROM_UNIXTIME command is for MySQL.

SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date 
FROM prefix_scorm_scoes_track AS st 
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
WHERE st.value='completed' 
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt

All users enrolled in a course without a role

Identifies All users that are enrolled in a course but are not assigned a role.

SELECT
user.firstname AS Firstname,
user.lastname AS Lastname,
user.idnumber Employee_ID,
course.fullname AS Course

FROM prefix_course AS course 
JOIN prefix_enrol AS en ON en.courseid = course.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
JOIN prefix_user as user ON user.id = ue.userid

WHERE user.id NOT IN (
SELECT u.id
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_role AS r ON r.id = ra.roleid
JOIN prefix_user AS u ON u.id = ra.userid
WHERE c.id=course.id
)
ORDER BY Course, Lastname, Firstname

List course resources accumulative file size and count

This is the main (first) report, which has a link (alias) to a second report (the following on this page) which list each file in the course.

SELECT c.id "CourseID", context.id "ContextID"
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=', c.id, '">', c.fullname ,'</a>') AS "Course Name"
, COUNT(*) "Course Files" , ROUND( SUM( f.filesize ) /1048576 ) AS file_size_MB
,CONCAT('<a target="_new" href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?alias=coursefiles&courseid=1&filter_courses=', c.id, '">List files</a>') AS "List Files"

FROM mdl_files AS f
JOIN mdl_context AS context ON context.id = f.contextid
JOIN mdl_course AS c ON c.id = (
  SELECT instanceid
  FROM mdl_context
  WHERE id = SUBSTRING_INDEX( SUBSTRING_INDEX( context.path, '/' , -2 ) , '/', 1 ) )
WHERE filesize >0
GROUP BY c.id

With this report, you will have to define "alias" report property to "coursefiles" for it to be able to be called from the above report. And also setup (add) a FILTER_COURSES filter.

SELECT 
id ,CONCAT('<a target="_new" href="%%WWWROOT%%/pluginfile.php/', contextid, '/', component, '/', filearea, '/', itemid, '/', filename, '">', filename,'</a>') AS "File"
,filesize, mimetype ,author, license, timecreated, component, filearea, filepath

FROM mdl_files AS f
WHERE filesize >0
            AND f.contextid
            IN (   SELECT id
                     FROM mdl_context
                    WHERE path 
                     LIKE (   SELECT CONCAT('%/',id,'/%')
                                  AS contextquery
                                FROM mdl_context
                               WHERE 1=1
			        %%FILTER_COURSES:instanceid%%
                                 AND contextlevel = 50
                           )
                )

Which courses has redundant topics

This report list several "active topics" calculations, per course. which should give an administrator some indications for which topics/sections/weeks are filled with resources and activities and which ones are empty and not used (usually, at the end of the course).

The following, second SQL query, could be used to "trim" down those redundant course topics/sections/weeks by updating the course format's numsection (Number of sections) setting. (It's a per course format setting!)

SELECT id, format,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">', c.fullname,'</a>') AS Course 

,(SELECT value  FROM  `mdl_course_format_options` WHERE  `courseid` = c.id AND `format` = c.format AND `name` = 'numsections' ) AS "numsections"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND `sequence` !=  '' ) AS "Non empty sections count"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id ) AS "Total section count"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND sequence IS NOT NULL) AS "Non NULL sections count"
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND name != '') AS "Non empty section Name count"
 ,(SELECT COUNT(*) FROM mdl_course_modules cm WHERE cm.course = c.id) "Modules count"

FROM mdl_course AS c

The following SQL REPLACE query is used for "fixing" (updating) the "numsections" of a specific course format "onetopics" (you can always change it, or discard it to use this SQL REPLACE on all course formats)

REPLACE INTO `mdl_course_format_options` (`id`, `courseid`, `format`, `sectionid`, `name`, `value`) 
SELECT NULL, c.id, 'onetopic', '0', 'numsections', (SELECT COUNT(*) FROM `mdl_course_sections` WHERE `course` = c.id AND name != '')
FROM `mdl_course` c where format = 'onetopic'

Hidden Courses with Students Enrolled

Contributed by Eric Strom

This query identifies courses with student enrollment that are currently hidden from students. Includes the defined course start date, count of students and instructors, and a clickable email link of instructor (first found record if more than one).

SELECT c.visible AS Visible, 
DATE(FROM_UNIXTIME(c.startdate)) AS StartDate, 
concat('<a target="_new" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',
c.id,'">',c.idnumber,'</a>') AS Course_ID,

(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students,

(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Instructors,

(SELECT DISTINCT concat('<a href="mailto:',u.email,'">',u.email,'</a>')
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS 'Instructor_Email', 

now() AS Report_Timestamp

FROM prefix_course AS c 
WHERE c.visible = 0 AND (SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id WHERE ra.roleid = 5 AND ctx.instanceid = c.id) > 0
ORDER BY StartDate, Instructor_Email, Course_ID

Course formats used on my system

SELECT COUNT(*) 'Count', c.format 'Format'
FROM prefix_course AS c
GROUP BY c.format

Course catalogue with future courses

SELECT CONCAT('<a href="%%WWWROOT%%/course/info.php?id=',course.id,'">',course.fullname,'</a>') AS Kurs, FROM_UNIXTIME(startdate, '%Y/%m/%d') AS Beginn
FROM prefix_course AS course
WHERE DATEDIFF(NOW(),FROM_UNIXTIME(startdate)) < 0
ORDER BY startdate

Course Design Reports

These are reports which summarize course design aspects, such as activity and resource modules per section, types of activities used, etc.

Course Content/Week

Contributed by Elizabeth Dalton, Granite State College

This report assumes that the first 14 sections in a course, not including the "0" or "Welcome" section, correspond to weeks (with "Subsections" given numbers much higher in the sequence). Of those sections, each is checked to count the number of:

   Forums
   Graded Activities (may include Forums)
   Resources (not including a Label)

Totals of each of these types of content elements per section are provided.

Note: Only visible resources and activities are counted. Note: this is a "Global" report. Run it within a course to see a summary of the contents of that course.

SELECT
 
cs.section AS 'Week'
, cs.name AS 'Section Name'

, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT LIKE 'label'),cm.id,NULL)) AS 'Ungraded Resources'

, COUNT(DISTINCT IF(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'

, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Graded Activities'

FROM prefix_course AS c
JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section <= 14 AND cs.section > 0
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id 
JOIN prefix_modules AS m ON m.id = cm.module
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.itemmodule = m.name AND gi.iteminstance = cm.instance

WHERE 
cs.visible = 1
AND cm.visible = 1
AND c.id = %%COURSEID%%

GROUP BY cs.section
ORDER BY cs.section

Assignments and Weights

Contributed by Elizabeth Dalton, Granite State College

Returns a list of grade book categories for the current course, grade book weightings, the first type of assignment included in the category, a count of different assignment types for each category, and a count of assignments for each category.

Categories with weights of 0 are not included in this report.

Only visible activities are included in this report.

Note: This is designed to be a "Global" report in Configurable Reports.

SELECT

IF(gc.parent IS NOT NULL, gc.fullname, 'None') AS 'Grade Book Category'
, IF(gc.parent IS NOT NULL, ROUND(gic.aggregationcoef, 2), ROUND(SUM(DISTINCT gi.aggregationcoef), 2)+ROUND(SUM(DISTINCT mgi.aggregationcoef), 2)) AS 'Category weight'

, CONCAT_WS(', ',GROUP_CONCAT(DISTINCT gi.itemmodule SEPARATOR ', '), IF(mgi.id, 'manual',NULL)) AS 'Activity Types'
, COUNT(DISTINCT gi.itemmodule) + IF(mgi.id,1,0) AS 'Different Activity Types'
, CONCAT_WS('<br>', GROUP_CONCAT(DISTINCT gi.itemname ORDER BY gi.itemname SEPARATOR '<br>'), GROUP_CONCAT(DISTINCT mgi.itemname ORDER BY mgi.itemname SEPARATOR '<br>')) AS 'Activity Names'
, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) + COUNT(DISTINCT mgi.id) AS 'Activity Count'

FROM prefix_course AS c

#get grade categories
LEFT JOIN prefix_grade_categories AS gc ON gc.courseid = c.id 
# back from categories to grade items to get aggregations and weights
JOIN prefix_grade_items AS gic ON gic.courseid = c.id AND gic.itemtype = 'category' AND gic.aggregationcoef != 0 AND (LOCATE(gic.iteminstance, gc.path) OR (gc.parent IS NULL))

# attach activities to course
JOIN prefix_course_modules AS cm ON cm.course = c.id 
# attach grade items to activities
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.iteminstance = cm.instance AND gi.itemtype = 'mod' AND gi.categoryid = gc.id AND gi.hidden != 1

# attach manual grade items to course-- they don't have modules
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual' AND mgi.categoryid = gc.id

WHERE 
cm.visible = 1
AND c.id = %%COURSEID%%

GROUP BY gc.id
ORDER BY gc.id

Pre-Term Course Review

Contributed by Elizabeth Dalton, Granite State College

Provides an overview of the readiness of ONLINE, HYBRID, and BLENDED courses in the Staging category and all subcategories. Links to each course are provided. Other details:

  1. "Required blocks" include Instructor Block (mooprofile), Activities, and the Research block.
  2. "Instructor Details" block is not the "Instructor" block (mooprofile) automatically provided by the system. It is an optional block that can be edited by the instructor. If not edited to remove boilerplate text, it should be hidden.
  3. All courses should be in the "Collapsed Topics" format with the "Weeks" structure.
  4. "Weeks defined in course settings" is taken from our SIS when the course shells are created, but can be edited by faculty. "# of weeks named and visible" should usually match or exceed this value.
  5. We recommend that each week contain at least one forum, at least one graded activity, and at least one ungraded resource.
  6. "Syllabus updated" date is for the first attached file found with the text "syllabus" in the name. The "Days ago" calculation is included for convenience.

Note: At our institution, we construct categories each term, and insert a text string "staging" in the Category ID for pre-term courses during the preparation or "staging" phase of course development. We remove this text string (and change it to "production") when courses go live at the start of the new term.

SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS Course

#,RIGHT(c.idnumber,2) AS Type # Specific to GSC "Instructional Method" storage

#, substring_index(substr(c.shortname FROM locate('.',c.shortname)+1),'-',1) AS Section # Specific to GSC
 
,(SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/user/view.php',CHAR(63),'id=',u.id,'">',u.lastname,', ', u.firstname,'</a>')
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Instructor' 

,(SELECT IF((u2.description IS NULL) OR (u2.description LIKE ''),'NO', 'YES')
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u2 ON u2.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Profile Has Bio'

,(SELECT IF(u3.picture > 0,'YES','NO')
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u3 ON u3.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Profile Has Picture'

, IF(((bpi.visible IS NULL) OR (bpi.visible !=0)) AND ((bpm.visible IS NULL) OR (bpm.visible !=0)) AND ((bpa.visible IS NULL) OR (bpa.visible !=0)) AND ((bpr.visible IS NULL) OR (bpr.visible !=0)),'YES','NO') AS 'Required blocks visible'
#, IF((bpm.visible IS NULL) OR (bpm.visible !=0),'YES','NO') AS 'Messages block visible'
#, IF((bpa.visible IS NULL) OR (bpa.visible !=0),'YES','NO') AS 'activities block visible'
#, IF((bpr.visible IS NULL) OR (bpr.visible !=0),'YES','NO') AS 'research block visible'

#, IF(SUM(IF(bi.configdata LIKE 'Tzo4OiJzdGRDbGFzcyI6Mzp7czo1OiJ0aXRsZSI7czoxODoiSW5zdHJ1Y3RvciBEZXRhaWxzI%',1,0)) AND (bip.visible !=0),'YES','') AS 'Instructor Details Block visible' # This is a hack based on UUencoded string data from the title of HTML "Instructor Details" block

#, IF(bi.configdata LIKE '%ZGl0IHRoaXMgYmxvY2s%','NO','') AS 'Instructor Details Block Updated' # HTML block has string 'dit this block'

#, IF(COUNT(bi.id) -  SUM(IF(bi.configdata LIKE 'Tzo4OiJzdGRDbGFzcyI6Mzp7czo1OiJ0aXRsZSI7czoxODoiSW5zdHJ1Y3RvciBEZXRhaWxzI%',1,0)),'YES','') AS 'possible extra instructor blocks' #looking for any HTML block with "instructor" in the title

, IF(c.format='topcoll','YES', c.format) AS 'Collapsed Topics course format' # change this if you want to test for a different format
, IF(cfo.value = 2, 'YES','NO') AS 'weeks structure'

, cfw.value AS 'weeks defined in course settings'

, COUNT(DISTINCT IF(((cs.name IS NOT NULL) AND (cs.visible = 1) AND (cs.section != '0') AND (cs.sequence IS NOT NULL)),cs.id,NULL)) AS '# of weeks named & visible (includes orphans)'

, COUNT(DISTINCT IF(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'
, COUNT(DISTINCT IF(m.name LIKE 'forum' ,cs.id , NULL)) AS 'Weeks with Forum'

, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Activities'
, COUNT(DISTINCT IF(gi.id, cs.id, NULL)) AS 'Weeks with Activities'
, COUNT(DISTINCT mgi.id) AS 'Manual Grade Items'

, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT IN ('forum','label')),cm.id,NULL)) AS 'Resources'
, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT IN ('forum','label')), cs.id, NULL)) AS 'Weeks with Resources'

# Here are some other things you could check for per course
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%forum%') AS Forums
 
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%quiz%') AS Quizzes
 
#,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%assign%') AS Assignments

#,(SELECT COUNT(prefix_resource.id) FROM prefix_resource JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course) AS Files

#,(SELECT COUNT(prefix_url.id) FROM prefix_url JOIN prefix_course ON prefix_course.id = prefix_url.course WHERE c.id = prefix_url.course) AS Links

,(SELECT FROM_UNIXTIME(MAX(prefix_resource.timemodified))
FROM prefix_resource
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS SyllabusDate

,(SELECT TO_DAYS(NOW())-TO_DAYS(FROM_UNIXTIME(MAX(prefix_resource.timemodified)))
FROM prefix_resource
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS DaysAgo

, IF(COUNT(DISTINCT IF(f.type LIKE 'news', f.id,NULL)),'YES','NO' ) AS 'Announcement Forum Visible'

, IF(COUNT(DISTINCT IF(f.type LIKE 'news', fd.id,NULL)),'YES','NO' ) AS 'Announcement posted'

FROM prefix_course AS c
LEFT JOIN prefix_course_categories as cc ON c.category = cc.id
LEFT JOIN prefix_context AS ctxx ON c.id = ctxx.instanceid 

LEFT JOIN prefix_block_positions AS bpi ON bpi.contextid = ctxx.id AND bpi.blockinstanceid = '43692' # mooprofile
LEFT JOIN prefix_block_positions AS bpm ON bpm.contextid = ctxx.id AND bpm.blockinstanceid = '43962' # messages
LEFT JOIN prefix_block_positions AS bpa ON bpa.contextid = ctxx.id AND bpa.blockinstanceid = '43963' # activities
LEFT JOIN prefix_block_positions AS bpr ON bpr.contextid = ctxx.id AND bpr.blockinstanceid = '38368' # html research help

LEFT JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.visible = 1 AND cs.sequence IS NOT NULL
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id 
LEFT JOIN prefix_modules AS m ON m.id = cm.module
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.itemmodule = m.name AND gi.iteminstance = cm.instance

LEFT JOIN prefix_forum AS f ON f.course = c.id AND cm.instance = f.id AND cm.visible = 1
LEFT JOIN prefix_forum_discussions AS fd ON fd.forum = f.id

# attach manual grade items to course-- they don't have modules
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual'

LEFT JOIN prefix_course_format_options AS cfo ON cfo.courseid = c.id AND cfo.name = 'layoutstructure'
LEFT JOIN prefix_course_format_options AS cfw ON cfw.courseid = c.id AND cfw.name = 'numsections'

LEFT JOIN prefix_block_instances AS bi ON bi.parentcontextid = ctxx.id AND bi.blockname = 'html' AND (bi.configdata LIKE '%SW5zdHJ1Y3Rvc%' or bi.configdata LIKE '%bnN0cnVjdG9y%')
LEFT JOIN prefix_block_positions AS bip ON bip.blockinstanceid = bi.id

WHERE RIGHT(c.idnumber,2) IN ('OL', 'BL', 'HY') 
# AND substring(cc.path,2,2) IN ('26') # Staging
#AND substring(cc.path,2,3) IN ('158') # UG
AND cc.idnumber LIKE '%staging%'
AND ctxx.contextlevel = 50

GROUP BY c.shortname

Module instances + Module HITs by role teacher and student in course

SELECT 
m.name AS "Module name"
, COUNT(*) AS "Module count"

,(SELECT COUNT(*) 
FROM prefix_log AS l 
WHERE l.course = cm.course AND l.module = m.name ) AS "Hits"

,(SELECT COUNT(*)
FROM prefix_log AS l
JOIN prefix_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN prefix_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 5 
WHERE l.course = cm.course AND l.module = m.name) AS "Students HITs"

,(SELECT COUNT(*)
FROM prefix_log AS l
JOIN prefix_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN prefix_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3 
WHERE l.course = cm.course AND l.module = m.name) AS "Teachers HITs"

FROM mdl_course_modules AS cm
JOIN mdl_modules AS m on m.id = cm.module
WHERE cm.course = '%%COURSEID%%'
GROUP BY cm.module

Course Syllabus

Contributed by Elizabeth Dalton, Granite State College / Moodle HQ

This report requires ELIS. It runs from within a course and constructs a course syllabus based on content in the course and in the ELIS entries related to the course (Class Instance, Course Description, and Program). It is a proof-of-concept of an automated syllabus production tool. Fields such as "Course Policies" and "Teaching Philosophy" are added to the Class Instance records, and instructors enter them there. The Instructor Bio is pulled from the User Profile of all users with the Teacher role in the course.

SELECT 

c.fullname AS 'fullname'
, ec.idnumber AS 'elis-id'
, DATE_FORMAT(FROM_UNIXTIME(ec.startdate), '%b %e, %Y') AS 'start'
, DATE_FORMAT(FROM_UNIXTIME(ec.enddate), '%b %e, %Y') AS 'end'
, ecd.name AS 'longname'
, ecd.code AS 'coursecode'
, ecd.credits AS 'coursecredits'
, ecd.syllabus AS 'description'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'learning-outcomes'
WHERE ctxecd.id = eft.contextid) AS 'outcomes'

,(SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/user/view.php',CHAR(63),'id=',u.id,'">',u.firstname,' ', u.lastname,'</a> ', u.email)
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Instructor' 

, (SELECT  efc.data
FROM prefix_local_eliscore_fld_data_char AS efc
JOIN prefix_local_eliscore_field AS ef ON ef.id = efc.fieldid AND ef.shortname = 'term-code'
WHERE ctxci.id = efc.contextid) AS 'termcode'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'prerequisites'
WHERE ctxecd.id = eft.contextid) AS 'prerequisites'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'textbooks'
WHERE ctxci.id = eft.contextid) AS 'textbooks'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'other-class-materials'
WHERE ctxci.id = eft.contextid) AS 'other-class-materials'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'course-policies'
WHERE ctxci.id = eft.contextid) AS 'course-policies'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'teaching-philosophy'
WHERE ctxci.id = eft.contextid) AS 'teaching-philosophy'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'course-methods'
WHERE ctxci.id = eft.contextid) AS 'course-methods'

,(SELECT u2.description
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u2 ON u2.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Bio'

,(SELECT

GROUP_CONCAT(DISTINCT CONCAT(

'<tr><td style="border: solid #000 .5px">',IF(gc.parent IS NOT NULL, gc.fullname, 'None')
, ' </td><td style="border: solid #000 .5px"> '
,IF(gc.parent IS NOT NULL, ROUND(gic.aggregationcoef, 2), ROUND( gi.aggregationcoef, 2)+ROUND(mgi.aggregationcoef, 2))

) SEPARATOR '</td></tr>')
#get grade categories
FROM prefix_grade_categories AS gc 
# back from categories to grade items to get aggregations and weights
LEFT JOIN prefix_grade_items AS gic ON gic.courseid = gc.courseid AND gic.itemtype = 'category' AND gic.aggregationcoef != 0 AND (LOCATE(gic.iteminstance, gc.path) OR (gc.parent IS NULL))
# attach grade items to activities
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = gc.courseid  AND gi.itemtype = 'mod' AND gi.categoryid = gc.id AND gi.hidden != 1
# attach manual grade items to course-- they don't have modules
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = gc.courseid and mgi.itemtype = 'manual' AND mgi.categoryid = gc.id
WHERE gc.courseid = c.id  ) AS 'grade categories'

, '<table width = "50%" >' AS 'table start'
, '<table width = "100%" >' AS 'table start 2'
, '</table>' AS 'table end'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'activities-schedule'
WHERE ctxci.id = eft.contextid) AS 'activities'


, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'schedule'
WHERE ctxci.id = eft.contextid) AS 'schedule'

, (SELECT  eft.data
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'grading-scale'
WHERE ctxepm.id = eft.contextid) AS 'gradescale'

FROM
prefix_course AS c 

# connect moodle course to ELIS class instance
LEFT JOIN prefix_local_elisprogram_cls_mdl AS ecm ON ecm.moodlecourseid = c.id
LEFT JOIN prefix_local_elisprogram_cls AS ec ON ec.id = ecm.classid
# class instance context
LEFT JOIN prefix_context AS ctxci ON ctxci.instanceid = ec.id AND ctxci.contextlevel = '14'

# connect ELIS class instance to ELIS course description
LEFT JOIN prefix_local_elisprogram_crs AS ecd ON ecd.id = ec.courseid
# course description context
LEFT JOIN prefix_context AS ctxecd ON ctxecd.instanceid = ecd.id AND ctxecd.contextlevel = '13'

#connect ELIS program to ELIS Course Description
LEFT JOIN prefix_local_elisprogram_pgm_crs AS epc ON epc.courseid = ecd.id
LEFT JOIN prefix_local_elisprogram_pgm AS epm ON epm.id = epc.curriculumid
# course program context
LEFT JOIN prefix_context AS ctxepm ON ctxepm.instanceid = epm.id AND ctxepm.contextlevel = '11'

WHERE

c.id = %%COURSEID%%

Course Activities Helper

Contributed by Elizabeth Dalton, Granite State College

This report provides a list of the graded activities in a course.

  • Note: Only graded activities are displayed.
  • Note: This is a "Global" report. Run it within a course to see a summary of the contents of that course.
  • Note: This report assumes that course sections each last one week.
# 303 Course Activities Helper

SELECT 

gi.itemmodule AS 'activity type'
# cs.section AS 'section number'

# Calculation assumes each section lasts one week
, CONCAT(DATE_FORMAT(FROM_UNIXTIME(c.startdate + (7*24*60*60* (cs.section-1))), '%b %e, %Y'),' - <br>',DATE_FORMAT(FROM_UNIXTIME(c.startdate + (7*24*60*60* (cs.section))), '%b %e, %Y')) AS 'Date'

, gi.itemname AS 'activity name'

#, (SELECT asg.intro FROM prefix_assign AS asg WHERE asg.id = cm.instance) AS 'intro'

#, (SELECT f.intro FROM prefix_forum AS f WHERE f.id = cm.instance) AS 'f intro'

, CASE gi.itemmodule 
WHEN 'assign' THEN (SELECT asg.intro FROM prefix_assign AS asg WHERE asg.id = gi.iteminstance) 
WHEN 'forum' THEN (SELECT f.intro FROM prefix_forum AS f WHERE f.id = gi.iteminstance) 
WHEN 'quiz' THEN (SELECT q.intro FROM prefix_quiz AS q WHERE q.id = gi.iteminstance) 
END AS 'test case'

#, (SELECT GROUP_CONCAT(CONCAT(' - ',gi.itemname) SEPARATOR '<BR>') FROM  prefix_grade_items AS gi  JOIN prefix_course_modules AS cm ON  gi.iteminstance = cm.instance WHERE gi.gradetype = 1 AND gi.hidden != 1 AND gi.courseid = c.id AND cm.course = c.id AND cm.section = cs.id ) AS 'activities'


FROM
prefix_course AS c 

#get grade sections
LEFT JOIN prefix_course_sections AS cs ON cs.course = c.id  AND cs.section > 0 AND cs.section <=14
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id

#LEFT JOIN prefix_assign AS asg ON asg.id = cm.instance

JOIN prefix_grade_items AS gi  ON  gi.iteminstance = cm.instance AND gi.gradetype = 1 AND gi.hidden != 1 AND gi.courseid = c.id AND cm.course = c.id AND cm.section = cs.id

WHERE
c.id = %%COURSEID%%
AND cs.visible = 1

ORDER BY gi.itemmodule, cs.section

Grade and Course Completion Reports

Site-Wide Grade Report with All Items

Shows grades for all course items along with course totals for each student. Works with ad-hoc reports or Configurable Reports

SELECT u.firstname AS 'First' , u.lastname AS 'Last', 
u.firstname + ' ' + u.lastname AS 'Display Name', 
c.fullname AS 'Course', 
cc.name AS 'Category',

CASE 
  WHEN gi.itemtype = 'course' 
   THEN c.fullname + ' Course Total'
  ELSE gi.itemname
END AS 'Item Name',

ROUND(gg.finalgrade,2) AS Grade,
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time

FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories as cc ON cc.id = c.category

WHERE  gi.courseid = c.id 
ORDER BY lastname

For MySQL users, you'll need to use the MySQL DATE_ADD function instead of DATEADD. Replace the line:

DATEADD(ss,gg.timemodified,'1970-01-01') AS Time

with:

FROM_UNIXTIME(gg.timemodified) AS Time

And:

u.firstname + ' ' + u.lastname AS 'Display Name',

with:

CONCAT(u.firstname,' ',u.lastname) AS 'Display Name',

Site-Wide Grade Report with Just Course Totals

A second site-wide grade report for all students that just shows course totals. Works with ad-hoc reports or Configurable Reports

SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name', 
cc.name AS 'Category',
CASE 
  WHEN gi.itemtype = 'course' 
   THEN c.fullname + ' Course Total'
  ELSE gi.itemname
END AS 'Item Name',

ROUND(gg.finalgrade,2) AS Grade,
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time

FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories as cc ON cc.id = c.category

WHERE  gi.courseid = c.id AND gi.itemtype = 'course'

ORDER BY lastname

For MySQL users:

SELECT u.firstname AS 'First' , u.lastname AS 'Last', CONCAT(u.firstname , ' ' , u.lastname) AS 'Display Name', 
c.fullname AS 'Course', 
cc.name AS 'Category',
CASE 
  WHEN gi.itemtype = 'course' 
   THEN CONCAT(c.fullname, ' - Total')
  ELSE gi.itemname
END AS 'Item Name',

ROUND(gg.finalgrade,2) AS Grade,
FROM_UNIXTIME(gg.timemodified) AS TIME
 
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category
 
WHERE  gi.courseid = c.id AND gi.itemtype = 'course'
ORDER BY lastname

Learner report by Learner with grades

Which Learners in which course and what are the grades

SELECT u.firstname AS 'Name' , u.lastname AS 'Surname', c.fullname AS 'Course', cc.name AS 'Category', 
CASE WHEN gi.itemtype = 'Course'    
THEN c.fullname + ' Course Total'  
ELSE gi.itemname 
END AS 'Item Name', ROUND(gg.finalgrade,2) AS Score,ROUND(gg.rawgrademax,2) AS Max, ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) as Percentage,

if (ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) > 79,'Yes' , 'No') as Pass

FROM prefix_course AS c 
JOIN prefix_context AS ctx ON c.id = ctx.instanceid 
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id 
JOIN prefix_user AS u ON u.id = ra.userid 
JOIN prefix_grade_grades AS gg ON gg.userid = u.id 
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid 
JOIN prefix_course_categories AS cc ON cc.id = c.category 
WHERE  gi.courseid = c.id and gi.itemname != 'Attendance'
ORDER BY `Name` ASC

User Course Completion

Contributed by: Randy Thornton

A very simple report with a list of course completion status by username. Completions are noted by date, blank otherwise.

SELECT 
  u.username, 
  c.shortname,  
 DATE_FORMAT(FROM_UNIXTIME(p.timecompleted),'%Y-%m-%d') AS completed
FROM prefix_course_completions AS p
JOIN prefix_course AS c ON p.course = c.id
JOIN prefix_user AS u ON p.userid = u.id
WHERE c.enablecompletion = 1
ORDER BY u.username

User Course Completion with Criteria

Contributed by: Randy Thornton

A report with course completions by username, with Aggregation method, Criteria types, and Criteria detail where available.

SELECT u.username AS user, 
c.shortname AS course,
DATE_FORMAT(FROM_UNIXTIME(t.timecompleted),'%Y-%m-%d') AS completed,
CASE
WHEN (SELECT a.method FROM prefix_course_completion_aggr_methd AS a  WHERE (a.course = c.id AND a.criteriatype IS NULL) = 1) THEN "Any"
ELSE "All"
END AS aggregation,
CASE 
WHEN p.criteriatype = 1 THEN "Self"
WHEN p.criteriatype = 2 THEN "By Date"
WHEN p.criteriatype = 3 THEN "Unenrol Status"
WHEN p.criteriatype = 4 THEN "Activity"
WHEN p.criteriatype = 5 THEN "Duration"
WHEN p.criteriatype = 6 THEN "Course Grade"
WHEN p.criteriatype = 7 THEN "Approve by Role"
WHEN p.criteriatype = 8 THEN "Previous Course"
END AS criteriatype,
CASE 
WHEN p.criteriatype = 1 THEN "*"
WHEN p.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(p.timeend),'%Y-%m-%d')
WHEN p.criteriatype = 3 THEN t.unenroled
WHEN p.criteriatype = 4 THEN 
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',p.module,'/view.php?id=',p.moduleinstance,'">',p.module,'</a>')
WHEN p.criteriatype = 5 THEN p.enrolperiod
WHEN p.criteriatype = 6 THEN CONCAT('Needed: ',ROUND(p.gradepass,2),' Achieved: ',ROUND(t.gradefinal,2)) 
WHEN p.criteriatype = 7 THEN p.role
WHEN p.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = p.courseinstance)
END AS criteriadetail 
FROM prefix_course_completion_crit_compl AS t
JOIN prefix_user AS u ON t.userid = u.id
JOIN prefix_course AS c ON t.course = c.id
JOIN prefix_course_completion_criteria AS p ON t.criteriaid = p.id

Courses with Completion Enabled and their settings

Contributed by: Randy Thornton

List of all courses with completion enabled and their Aggregation setting, Criteria types, and Criteria details.

SELECT c.shortname AS Course, 
CASE
WHEN (SELECT a.method FROM prefix_course_completion_aggr_methd AS a  WHERE (a.course = t.course AND a.criteriatype IS NULL)) = 2 THEN "All"
ELSE "Any"
END AS Course_Aggregation,
CASE
WHEN t.criteriatype = 1 THEN "Self completion"
WHEN t.criteriatype = 2 THEN "Date done by" 
WHEN t.criteriatype = 3 THEN "Unenrolement" 
WHEN t.criteriatype = 4 THEN "Activity completion"   
WHEN t.criteriatype = 5 THEN "Duration in days" 
WHEN t.criteriatype = 6 THEN "Final grade"     
WHEN t.criteriatype = 7 THEN "Approve by role" 
WHEN t.criteriatype = 8 THEN "Previous course"
END AS Criteria_type,
CASE
WHEN t.criteriatype = 1 THEN "On"
WHEN t.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(t.timeend),'%Y-%m-%d')
WHEN t.criteriatype = 3 THEN "On"
WHEN t.criteriatype = 4 THEN
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',t.module,'/view.php?id=',t.moduleinstance,'">',t.module,'</a>')
WHEN t.criteriatype = 5 THEN ROUND(t.enrolperiod/86400)
WHEN t.criteriatype = 6 THEN ROUND(t.gradepass,2)
WHEN t.criteriatype = 7 THEN (SELECT r.shortname FROM prefix_role AS r WHERE r.id = t.role)
WHEN t.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = t.courseinstance)
END AS Criteria_detail
FROM prefix_course_completion_criteria as t
JOIN prefix_course AS c ON t.course = c.id
WHERE c.enablecompletion = 1
ORDER BY course

Course Completion Report with custom dates

List of users who completed multiple or single course/s from a start date to end date chosen by the user. The output gives username, name, course name, completion date and score

SELECT u.username AS 'User Name',
CONCAT(u.firstname , ' ' , u.lastname) AS 'Name',
c.shortname AS 'Course Name', 
DATE_FORMAT(FROM_UNIXTIME(p.timecompleted),'%W %e %M, %Y') AS 'Completed Date',
ROUND(c4.gradefinal,2) AS 'Score'
FROM prefix_course_completions AS p
JOIN prefix_course AS c ON p.course = c.id
JOIN prefix_user AS u ON p.userid = u.id
JOIN prefix_course_completion_crit_compl AS c4 ON u.id = c4.userid
WHERE c.enablecompletion = 1  AND (p.timecompleted IS NOT NULL OR p.timecompleted !='') 
AND (p.timecompleted>= :start_date AND p.timecompleted<=:end_date)
GROUP BY u.username
ORDER BY c.shortname

Scales used in activities

SELECT scale.name
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',gi.itemmodule,'/view.php?id=',cm.id,'">',gi.itemname,'</a>') AS "Module View"
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/modedit.php?up','date=',cm.id,'">',gi.itemname,'</a>') AS "Module Settings"

FROM prefix_grade_items AS gi
JOIN prefix_course AS c ON c.id = gi.courseid
JOIN prefix_course_modules AS cm ON cm.course = gi.courseid AND cm.instance = gi.iteminstance
JOIN prefix_scale AS scale ON scale.id = gi.scaleid
WHERE gi.scaleid IS NOT NULL


Extra Credit Items by Name Only

Contributed by Eric Strom

This query identifies grade items in visible courses with student enrollment that have "extra credit" in the name of the item but set as extra credit in the grade settings. Includes the defined course start date, count of students and instructors, and a clickable email link of instructor (first found record if more than one).

SELECT DATE(FROM_UNIXTIME(c.startdate)) AS StartDate, 
concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php',CHAR(63),'id=',
c.id,'">',c.idnumber,'</a>') AS Course_ID, gi.itemname AS Item_Name

,(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students

,(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Instructors

,(SELECT DISTINCT concat('<a href="mailto:',u.email,'">',u.email,'</a>')
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS 'Instructor_Email'

,now() AS Report_Timestamp

FROM prefix_grade_items AS gi
JOIN prefix_course AS c ON gi.courseid = c.id

WHERE gi.itemname LIKE '%extra credit%' 
	AND gi.gradetype = '1' 
	AND gi.hidden = '0' 
	AND gi.aggregationcoef = '0' 
	AND c.visible = 1
	AND (SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id WHERE ra.roleid = 5 AND ctx.instanceid = c.id) > 0

GROUP BY Course_ID, gi.id
ORDER BY StartDate, Course_ID
 
%%FILTER_SEARCHTEXT:Course_ID:~%%

Site Wide Number of Courses Completed by User

Contributed by Ken St. John

Simple report that shows the number of completed courses for all users site wide

SELECT u.lastname, u.firstname,
COUNT(p.timecompleted) AS TotalCompletions
FROM prefix_course_completions AS p
JOIN prefix_user AS u ON p.userid = u.id
GROUP BY p.userid
ORDER BY u.lastname

Activity Module Reports

User activity completions with dates

Contributed by: Randy Thornton

This report shows the users completion status of activities across all courses. It is intended to be uses with Configurable Reports filters for user, start and end times, and also to be able to search the Module names. It includes the new core H5P module in 3.10. Add any third party activity modules you may have in your site as you need. Also, thanks to Tim Hunt for improvements to this query.


SELECT
u.username As 'User',
c.shortname AS 'Course',
m.name AS Activitytype, 
CASE 
    WHEN m.name = 'assign'  THEN (SELECT name FROM prefix_assign WHERE id = cm.instance)
    WHEN m.name = 'assignment'  THEN (SELECT name FROM prefix_assignment WHERE id = cm.instance)
    WHEN m.name = 'book'  THEN (SELECT name FROM prefix_book WHERE id = cm.instance)
    WHEN m.name = 'chat'  THEN (SELECT name FROM prefix_chat WHERE id = cm.instance)
    WHEN m.name = 'choice'  THEN (SELECT name FROM prefix_choice WHERE id = cm.instance)
    WHEN m.name = 'data'  THEN (SELECT name FROM prefix_data WHERE id = cm.instance)
    WHEN m.name = 'feedback'  THEN (SELECT name FROM prefix_feedback WHERE id = cm.instance)
    WHEN m.name = 'folder'  THEN (SELECT name FROM prefix_folder WHERE id = cm.instance)
    WHEN m.name = 'forum' THEN (SELECT name FROM prefix_forum WHERE id = cm.instance)
    WHEN m.name = 'glossary' THEN (SELECT name FROM prefix_glossary WHERE id = cm.instance)
    WHEN m.name = 'h5pactivity' THEN (SELECT name FROM prefix_h5pactivity WHERE id = cm.instance)
    WHEN m.name = 'imscp' THEN (SELECT name FROM prefix_imscp WHERE id = cm.instance)
    WHEN m.name = 'label'  THEN (SELECT name FROM prefix_label WHERE id = cm.instance)
    WHEN m.name = 'lesson'  THEN (SELECT name FROM prefix_lesson WHERE id = cm.instance)
    WHEN m.name = 'lti'  THEN (SELECT name FROM prefix_lti  WHERE id = cm.instance)
    WHEN m.name = 'page'  THEN (SELECT name FROM prefix_page WHERE id = cm.instance)
    WHEN m.name = 'quiz'  THEN (SELECT name FROM prefix_quiz WHERE id = cm.instance)
    WHEN m.name = 'resource'  THEN (SELECT name FROM prefix_resource WHERE id = cm.instance)
    WHEN m.name = 'scorm'  THEN (SELECT name FROM prefix_scorm WHERE id = cm.instance)
    WHEN m.name = 'survey'  THEN (SELECT name FROM prefix_survey WHERE id = cm.instance)
    WHEN m.name = 'url'  THEN (SELECT name FROM prefix_url  WHERE id = cm.instance)
    WHEN m.name = 'wiki' THEN (SELECT name FROM prefix_wiki  WHERE id = cm.instance)
    WHEN m.name = 'workshop' THEN (SELECT name FROM prefix_workshop  WHERE id = cm.instance)
   ELSE "Other activity"
END AS Actvityname,
# cm.section AS Coursesection,
CASE
    WHEN cm.completion = 0 THEN '0 None'
    WHEN cm.completion = 1 THEN '1 Self'
    WHEN cm.completion = 2 THEN '2 Auto'
END AS Activtycompletiontype, 
CASE
   WHEN cmc.completionstate = 0 THEN 'In Progress'
   WHEN cmc.completionstate = 1 THEN 'Completed'
   WHEN cmc.completionstate = 2 THEN 'Completed with Pass'
   WHEN cmc.completionstate = 3 THEN 'Completed with Fail'
   ELSE 'Unknown'
END AS 'Progress', 
DATE_FORMAT(FROM_UNIXTIME(cmc.timemodified), '%Y-%m-%d %H:%i') AS 'When'
FROM prefix_course_modules_completion cmc 
JOIN prefix_user u ON cmc.userid = u.id
JOIN prefix_course_modules cm ON cmc.coursemoduleid = cm.id
JOIN prefix_course c ON cm.course = c.id
JOIN prefix_modules m ON cm.module = m.id
# skip the predefined admin and guest user
WHERE u.id > 2
# config reports filters
%%FILTER_USERS:u.username%%
%%FILTER_SEARCHTEXT:m.name:~%%
%%FILTER_STARTTIME:cmc.timemodified:>%% %%FILTER_ENDTIME:cmc.timemodified:<%%

ORDER BY u.username

How many SCORM activities are used in each Course

SELECT cm.course,c.fullname ,m.name 
,concat('<a target="_new" href="%%WWWROOT%%/mod/scorm/index.php?id=',c.id,'">',count(cm.id),'</a>') AS Counter
 
FROM `prefix_course_modules` as cm 
  JOIN prefix_modules as m ON cm.module=m.id 
  JOIN prefix_course as c ON cm.course = c.id 
WHERE m.name LIKE '%scorm%' 
GROUP BY cm.course,cm.module 
ORDER BY count(cm.id) desc

SCORM Usage by Course Start Date

Contributed by Elizabeth Dalton, Granite State College

Report of number of inclusions of SCORM activities in courses, filtered by course start date.

SELECT 

CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'course'

, cc.name AS 'Category'
, scm.name AS 'Sample Activity Name'
, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
, COUNT(DISTINCT cm.id) AS 'Resources Used'
#, FROM_UNIXTIME(cm.added) AS 'resource added'


FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id AND m.name LIKE 'SCO%'

JOIN prefix_course AS c ON c.id = cm.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
JOIN prefix_scorm AS scm ON scm.id = cm.instance

WHERE
1

%%FILTER_STARTTIME:c.startdate:>%%
%%FILTER_ENDTIME:c.startdate:<%%

GROUP BY c.shortname, m.name
ORDER BY c.startdate, c.shortname

LTI (External Tool) Usage by Course Start Date

Contributed by Elizabeth Dalton, Granite State College

Report of number of inclusions of LTI (External Tool) Usage activities in courses, filtered by course start date.

SELECT 

CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'course'

, cc.name AS 'Category'
, lti.name AS 'Sample Activity Name'
, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
, COUNT(DISTINCT cm.id) AS 'Resources Used'
#, FROM_UNIXTIME(cm.added) AS 'resource added'


FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id AND m.name LIKE 'lti'

JOIN prefix_course AS c ON c.id = cm.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
JOIN prefix_lti AS lti ON lti.id = cm.instance
WHERE
1

%%FILTER_STARTTIME:c.startdate:>%%
%%FILTER_ENDTIME:c.startdate:<%%

GROUP BY c.shortname, m.name
ORDER BY c.startdate, c.shortname

Detailed ACTIONs for each MODULE

SELECT module,action,count(id) as counter
FROM prefix_log
GROUP BY module,action
ORDER BY module,counter desc

Most popular ACTIVITY

SELECT COUNT(l.id) hits, module
FROM prefix_log l
WHERE module != 'login' AND module != 'course' AND module != 'role'
GROUP BY module
ORDER BY hits DESC

System wide use of ACTIVITIES and RESOURCES

SELECT count( cm.id ) AS counter, m.name
FROM `prefix_course_modules` AS cm
JOIN prefix_modules AS m ON cm.module = m.id
GROUP BY cm.module
ORDER BY counter DESC

LOG file ACTIONS per MODULE per COURSE (IDs)

select course,module,action,count(action) as summa from prefix_log
where action <> 'new'
group by course,action,module
order by course,module,action

System Wide usage count of various course Activities

(Tested and works fine in Moodle 2.x) Like: Forum, Wiki, Blog, Assignment, Database,

  1. Within specific category
  2. Teacher name in course
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course

,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher 

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%forum%') AS Forums

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%data%') AS Databses

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%assignment%') AS Assignments

,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students

FROM prefix_course AS c
WHERE c.category IN ( 18)
ORDER BY Wikis DESC,Blogs DESC, Forums DESC

Course wiki usage/activity over the last 6 semesters

SELECT "Courses with Wikis"

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
 and c.fullname LIKE CONCAT('%','2010','%') and c.fullname LIKE '%Semester A%') AS '2010 <br/> Semester A'

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
 and c.fullname LIKE CONCAT('%','2010','%') and c.fullname LIKE '%Semester B%') AS '2010 <br/> Semester B'

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
 and c.fullname LIKE CONCAT('%','תשעא','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעא <br/> סמסטר א'

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
 and c.fullname LIKE CONCAT('%','תשעא','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעא <br/> סמסטר ב'

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
 and c.fullname LIKE CONCAT('%','תשעב','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעב <br/> סמסטר א'

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
 and c.fullname LIKE CONCAT('%','תשעב','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעב <br/> סמסטר ב'

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
 and c.fullname LIKE CONCAT('%','תשעג','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעג <br/> סמסטר א'

,(SELECT count( m.name ) AS count FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
 and c.fullname LIKE CONCAT('%','תשעג','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעג <br/> סמסטר ב'

Detailed WIKI activity (per wiki per course)

Including Number of Students in course (for reference)

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID  
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id ) AS Students
,m.name
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%updat%' ) as 'UPDAT E'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%annotate%' ) as ANNOTATE
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%comment%' ) as COMMENT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%add%' ) as 'A DD'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%edit%' ) as EDIT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action NOT LIKE '%view%' ) as 'All (NO View)'
FROM `prefix_course_modules` as cm 
JOIN prefix_modules as m ON cm.module=m.id 
JOIN prefix_course as c ON cm.course = c.id 
WHERE m.name LIKE '%wiki%'
GROUP BY cm.course,cm.module
ORDER BY 'All (NO View)' DESC

Wiki usage, system wide

(you can filter the output by selecting some specific course categories : "WHERE c.category IN ( 8,13,15)")

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%') AS 'WikiActivity<br/>ALL'

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%add%' ) AS 'WikiActivity<br/>ADD'

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%edit%' ) AS 'WikiActivity<br/>EDIT'

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%annotate%' ) AS 'WikiActivity<br/>ANNOTATE'

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%comments%' ) AS 'WikiActivity<br/>Comments'

,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students

,(SELECT count(*) FROM prefix_ouwiki_pages as ouwp
JOIN prefix_ouwiki as ouw ON ouw.id = ouwp.subwikiid
WHERE ouw.course = c.id GROUP BY ouw.course  ) as OUWikiPages

,(SELECT count( DISTINCT nwp.pagename ) FROM prefix_wiki_pages AS nwp
JOIN prefix_wiki AS nw ON nw.id = nwp.dfwiki WHERE nw.course = c.id ) As NWikiPages

FROM prefix_course AS c
WHERE c.category IN ( 8,13,15)
HAVING Wikis > 0
ORDER BY 'WikiActivity<br/>ALL' DESC

Aggregated Teacher activity by "WEB2" Modules

(Tested and works fine in Moodle 2.x) The NV column shows activity without VIEW log activity

SELECT ra.userid, u.firstname,u.lastname
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%') AS Wiki
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%' AND l.action NOT LIKE '%view%') AS Wiki_NV
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%') AS Forum
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%' AND l.action NOT LIKE '%view%') AS Forum_NV
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%') AS Blog
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%' AND l.action NOT LIKE '%view%') AS Blog_NV
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%') AS Assignment
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%' AND l.action NOT LIKE '%view%') AS Assignment_NV
FROM prefix_role_assignments AS ra 
JOIN prefix_user AS u ON u.id = ra.userid 
WHERE ra.roleid = 3 
GROUP BY ra.userid

List all the certificates issued, sort by variables in the custom profile fields

Note: The SQL queries look intimidating at first, but isn't really that difficult to learn. I've seen in the forums that users wanted to do 'site-wide' groups in 1.9x. This is sort of the idea. It pulls all the certificates issued to all users sorted by the custom profile fields, which in my case is the Units or Depts (i.e. my site wide groups). Why certificates? I've explored with both grades and quizzes, the course admins are not really interested in the actual grades but whether the learner received a certificate (i.e. passed the course with x, y, z activities). It also saves me from creating groups and assigning them into the right groups. Even assigning in bulk is not efficient, since I have upward of 25 groups per course and constantly new learners enrolling in courses. The limitation is something to do with the server? as it only pull 5000 rows of data. If anyone figured out how to change this, please let me know. In the meantime, the work around is to pull only a few units/depts at a time to limit the number of rows. This is fine at the moment, since each course admin are only responsible for certain units/depts.

SELECT
DATE_FORMAT( FROM_UNIXTIME(prefix_certificate_issues.timecreated), '%Y-%m-%d' ) AS Date,
prefix_certificate_issues.classname AS Topic,
prefix_certificate.name AS Certificate,
prefix_certificate_issues.studentname as Name,
prefix_user_info_data.data AS Units

FROM
prefix_certificate_issues

INNER JOIN prefix_user_info_data
on prefix_certificate_issues.userid = prefix_user_info_data.userid

INNER JOIN prefix_certificate
on prefix_certificate_issues.certificateid = prefix_certificate.id

WHERE prefix_user_info_data.data='Unit 1'
OR prefix_user_info_data.data='Unit 2'
OR prefix_user_info_data.data='Unit 3'

ORDER BY Units, Name, Topic ASC


All Simple Certificates Earned in the Site

Contributed by: Randy Thornton

Basic report of all certificates earned with the Simple Certificate plugin module in the whole site, sorted by most recent first. (Note: this uses the MySQL DATE_FORMAT function.)

SELECT
CONCAT (u.firstname, ' ',u.lastname) As 'User',
c.fullname AS 'Course',
sc.name AS 'Certificate',
DATE_FORMAT( FROM_UNIXTIME(sci.timecreated), '%Y-%m-%d' ) As 'Date Awarded'
# sci.code 'CertificateId'
FROM prefix_simplecertificate_issues sci
JOIN prefix_user u ON sci.userid = u.id
JOIN prefix_simplecertificate sc ON sci.certificateid = sc.id
JOIN prefix_course AS c ON sc.course = c.id
ORDER BY sci.timecreated DESC

If you want to limit this to the most recent ones, you can add a condition to limit it to a certain number of days past. For example, adding this WHERE clause (above the ORDER BY) will show only those earned in the last 30 days:

WHERE DATEDIFF(NOW(),FROM_UNIXTIME(sci.timecreated) ) < 30

Counter Blog usage in Courses,system wide

What teachers in what courses, uses blogs and how many + student count in that course.

SELECT ( @counter := @counter+1) as counter, 
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course

,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs

,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students

FROM prefix_course AS c, (SELECT @counter := 0) as s_init
WHERE c.category IN ( 8,13,15)
HAVING Blogs > 0
ORDER BY Blogs DESC

Elluminate (Blackboard Collaborate) - system wide usage

SELECT e.name As Session ,er.recordingsize
,c.fullname As Course
,u.firstname,u.lastname 
,DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%d-%m-%Y') AS dTimeStart
,concat('<a target="_new" href="%%WWWROOT%%/moodle/mod/elluminate/loadrecording.php?id=',er.id,'">Show</a>') AS RecordedSession

FROM prefix_elluminate_recordings AS er
JOIN prefix_elluminate AS e ON e.meetingid = er.meetingid
JOIN prefix_course as c ON c.id = e.course
JOIN prefix_user AS u ON u.id = e.creator 
ORDER BY er.recordingsize DESC


Choice

Contributed by: Randy Thornton

Results of the Choice activity. For all courses, shows course shortname, username, the Choice text, and the answer chosen by the user.

SELECT c.shortname AS course, u.username, h.name as question, o.text AS answer
FROM prefix_choice AS h
JOIN prefix_course AS c ON h.course = c.id
JOIN prefix_choice_answers AS a ON h.id = a.choiceid
JOIN prefix_user AS u ON a.userid = u.id
JOIN prefix_choice_options AS o ON a.optionid = o.id

Assignment type usage in courses

SELECT 

CONCAT('<a target="_new" href="%%WWWROOT%%/mod/assign/index.php?id=',c.id,'">',c.fullname,'</a>') AS "List assignments"

,(SELECT COUNT(*) FROM prefix_assign WHERE c.id = course) AS Assignments

,(SELECT COUNT(*) 
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment 
WHERE iassign.course = c.id AND apc.plugin = 'file' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
#GROUP BY apc.plugin
) AS "File Assignments"

,(SELECT COUNT(*) 
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment 
WHERE iassign.course = c.id AND apc.plugin = 'onlinetext' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "Online Assignments"

,(SELECT COUNT(*) 
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment 
WHERE iassign.course = c.id AND apc.plugin = 'pdf' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "PDF Assignments"

,(SELECT COUNT(*) 
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment 
WHERE iassign.course = c.id AND apc.plugin = 'offline' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "Offline Assignments"

,(SELECT COUNT(*) 
FROM prefix_assign_plugin_config AS apc
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment 
WHERE iassign.course = c.id AND apc.plugin = 'comments' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
) AS "Assignments Comments"

FROM prefix_assign AS assign
JOIN prefix_course AS c ON c.id = assign.course
GROUP BY c.id

Assignment Module Reports

All Ungraded Assignments

NOTE: This query is for the deprecated old Assignment module from Moodle 2.2, not the new Assignments module. Please update this query if you are the author or it will be removed as the 2.2 Assignment module is no longer supported since release 2.7. See: [1]

Returns all the submitted assignments that still need grading

select 
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment"

from prefix_assignment_submissions as asb
join prefix_assignment as a ON a.id = asb.assignment
join prefix_user as u ON u.id = asb.userid
join prefix_course as c ON c.id = a.course
join prefix_course_modules as cm ON c.id = cm.course

where asb.grade < 0 and cm.instance = a.id
and cm.module = 1

order by c.fullname, a.name, u.lastname

All Ungraded Assignments w/ Link

Returns all assignments submitted by those with the student role that have the status of 'submitted', along with a link that goes directly to the submission to grade it. The links work if you view the report within Moodle.

This query is updated for use with Moodle 2.2 or later. Contributed by Carly J. Born, Carleton College

SELECT 
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment",
 
concat('<a target="_new" href="%%WWWROOT%%/mod/assign/view.php?id=', 
cm.id, 
'&rownum=0&action=grader&userid=', 
u.id,
'">Grade</a>') 
AS "Assignment link"
 
FROM prefix_assign_submission sub
JOIN prefix_assign a ON a.id = sub.assignment
JOIN prefix_user u ON u.id = sub.userid
JOIN prefix_course c ON c.id = a.course AND c.id = %%COURSEID%%
JOIN prefix_course_modules cm ON c.id = cm.course 
JOIN prefix_context cxt ON c.id=cxt.instanceid AND cxt.contextlevel=50
JOIN prefix_role_assignments ra ON cxt.id = ra.contextid AND ra.roleid=5 AND ra.userid=u.id
 
WHERE cm.instance = a.id AND cm.module = 22 AND sub.status='submitted'
 
ORDER BY c.fullname, a.name, u.lastname


NOTE: This query is for the deprecated old Assignment module from Moodle 2.2, not the new Assignments module. Please update this query if you are the author or it will be removed as the 2.2 Assignment module is no longer supported since release 2.7. See: [2]


Returns all the submitted assignments that still need grading, along with a link that goes directly to the submission to grade it. The links work if you view the report within Moodle.

select 
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment",

'<a href="http://education.varonis.com/mod/assignment/submissions.php' + char(63) +
+ 'id=' + cast(cm.id as varchar) + '&userid=' + cast(u.id as varchar) 
+ '&mode=single&filter=0&offset=2">' + a.name + '</a>'
AS "Assignmentlink"


from prefix_assignment_submissions as asb
join prefix_assignment as a ON a.id = asb.assignment
join prefix_user as u ON u.id = asb.userid
join prefix_course as c ON c.id = a.course
join prefix_course_modules as cm ON c.id = cm.course

where asb.grade < 0 and cm.instance = a.id and cm.module = 1

order by c.fullname, a.name, u.lastname

Assignments (and Quizzes) waiting to be graded

NOTE: This query is for the deprecated old Assignment module from Moodle 2.2, not the new Assignments module. Please update this query if you are the author or it will be removed as the 2.2 Assignment module is no longer supported since release 2.7. See: [3]


This report requires a YEAR filter to be added (Available when using the latest block/configurable_reports)

Which you can always remove, to make this query work on earlier versions.

The report includes:

  • number of quizzes
  • unFinished Quiz attempts
  • Finished Quiz attempts
  • number of students
  • number of Assignments
  • number of submitted answers by students
  • number of unchecked assignments (waiting for the Teacher) in a Course.
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course

,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher 
 
,concat('<a target="_new" href="%%WWWROOT%%/mod/assignment/index.php?id=',c.id,'">מטלות</a>') AS Assignments

,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">בחנים</a>') AS 'Quizzes'

,(SELECT COUNT(*) 
FROM prefix_course_modules cm 
JOIN prefix_modules as m ON m.id = cm.module 
WHERE m.name LIKE 'quiz' AND cm.course = c.id 
GROUP BY cm.course 
) AS 'nQuizzes'

,(SELECT COUNT(*)
FROM prefix_quiz_attempts AS qa
JOIN prefix_quiz AS q ON q.id = qa.quiz
WHERE q.course = c.id
AND qa.timefinish = 0
GROUP BY q.course) AS 'unFinished Quiz attempts'

,(SELECT COUNT(*)
FROM prefix_quiz_attempts AS qa
JOIN prefix_quiz AS q ON q.id = qa.quiz
WHERE q.course = c.id
AND qa.timefinish > 0
GROUP BY q.course) AS 'finished quiz attempts'

,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5
AND ctx.instanceid = c.id
) AS nStudents
 

,(
SELECT count(a.id)
FROM prefix_assignment AS a 
JOIN prefix_course_modules AS cm ON a.course = cm.course 
WHERE cm.instance = a.id AND cm.module = 1 AND a.course = c.id
) nAssignments

,(
SELECT count(*)
FROM prefix_assignment AS a 
WHERE a.course = c.id AND FROM_UNIXTIME(a.timedue) > NOW()
GROUP BY a.course
) 'Open <br/>Assignments'

, CONCAT(ROUND( (100 / iAssignments ) * iOpenAssignments ) ,'%') 'unFinished <br/>Assignments <br/>(percent)'
 
,(
SELECT count(asb.id)
FROM prefix_assignment_submissions AS asb
JOIN prefix_assignment AS a ON a.id = asb.assignment
JOIN prefix_course_modules AS cm ON a.course = cm.course 
WHERE asb.grade < 0 AND cm.instance = a.id AND cm.module = 1 AND a.course = c.id
) 'unChecked  <br/>Submissions' 
 
,(
SELECT count(asb.id)
FROM prefix_assignment_submissions AS asb
JOIN prefix_assignment AS a ON a.id = asb.assignment
JOIN prefix_course_modules AS cm ON a.course = cm.course 
WHERE cm.instance = a.id AND cm.module = 1 AND a.course = c.id
) 'Submitted  <br/>Assignments'
 
FROM prefix_course AS c
LEFT JOIN (
SELECT course, count(*) AS iAssignments
FROM prefix_assignment AS a 
GROUP BY a.course 
) AS tblAssignmentsCount ON tblAssignmentsCount.course = c.id

LEFT JOIN (
SELECT course, count(*) AS iOpenAssignments
FROM prefix_assignment AS a 
WHERE FROM_UNIXTIME(a.timedue) > NOW()
GROUP BY a.course 
) AS tblOpenAssignmentsCount ON tblOpenAssignmentsCount.course = c.id

WHERE 1=1  
#AND c.fullname LIKE '%תשעג%'
%%FILTER_YEARS:c.fullname%%
## You can enable the SEMESTER filter as well, 
## by uncommenting the following line:
## %%FILTER_SEMESTERS:c.fullname%%
ORDER BY 'Open <br/>Assignments' DESC

Rubrics without zero values in criteria

Contributed by Eric Strom

Rubric calculations in Moodle can fail to align with instructors expectations if they lack a zero value for each criterion used in the assessment. From documentation at https://docs.moodle.org/32/en/Rubrics#Grade_calculation:

"For example, when the teacher in the previous example chose both levels with 1 point, the plain sum would be 2 points. But that is actually the lowest possible score so it maps to the grade 0 in Moodle. TIP: To avoid confusion from this sort of thing, we recommend including a level with 0 points in every rubric criterion."

This report identifies rubrics having criteria without a zero value level and the courses they live in. This also refines to only assignments with active rubrics that are visible to students in the course. Links to the each rubric id is the direct link to edit the rubric. Fix by adding a zero level for each criteria that is missing it. In general, the grading changes that result will be in the students' favor.

Includes search filter of course idnumber.

SELECT cat.name AS Department, concat('<a target="_new" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',
c.id,'">',c.idnumber,'</a>') AS Course_ID, 
c.fullname AS Course_Name, 
concat('<a target="_new" href="%%WWWROOT%%/grade/grading/form/rubric/edit.php',CHAR(63),'areaid=',gd.areaid,'">',gd.areaid,'</a>') AS Rubric
FROM prefix_course AS c
JOIN prefix_course_categories AS cat 
ON cat.id = c.category
JOIN prefix_course_modules AS cm 
ON c.id=cm.course
JOIN prefix_context AS ctx 
ON cm.id = ctx.instanceid
JOIN prefix_grading_areas AS garea 
ON ctx.id = garea.contextid
JOIN prefix_grading_definitions AS gd 
ON garea.id = gd.areaid
JOIN prefix_gradingform_rubric_criteria AS crit 
ON gd.id = crit.definitionid
JOIN prefix_gradingform_rubric_levels AS levels 
ON levels.criterionid = crit.id
WHERE cm.visible='1' AND garea.activemethod = 'rubric' AND (crit.id NOT IN
(SELECT crit.id
FROM prefix_gradingform_rubric_criteria AS crit
JOIN prefix_gradingform_rubric_levels AS levels 
ON levels.criterionid = crit.id WHERE levels.score = '0'))

GROUP BY Rubric
ORDER BY Course_ID, Rubric

%%FILTER_SEARCHTEXT:c.idnumber:~%%

Who is using "Single File Upload" assignment

SELECT 
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
 
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher 

,ass.name as "Assignment Name"

FROM 
prefix_assignment as ass

JOIN 
prefix_course as c ON c.id = ass.course

WHERE `assignmenttype` LIKE 'uploadsingle'

Feedback Module Reports

List the answers to all the Feedback activities within the current course, submitted by the current user

SELECT /* crs.fullname as "Course name", f.name AS "Journal name", CONCAT(u.firstname,' ',UPPER(u.lastname)) as "Participant", */ /* include these fields if you want to check the composition of the recordset */
DATE_FORMAT(FROM_UNIXTIME(c.timemodified),'%W %e %M, %Y') as "Answer Date",
CASE i.typ WHEN 'label' THEN i.presentation ELSE i.name END as "Topic",  /* usually labels are used as section titles, so you'd want them present in the recordset */
v.value as "My Answer"

FROM prefix_feedback AS f
INNER JOIN prefix_course as crs on crs.id=f.course %%FILTER_COURSES:f.course%% 
INNER JOIN prefix_feedback_item AS i ON f.id=i.feedback
INNER JOIN prefix_feedback_completed AS c on f.id=c.feedback %%FILTER_COURSEUSER:c.userid%% 
LEFT JOIN prefix_feedback_value AS v on v.completed=c.id AND v.item=i.id
INNER JOIN prefix_user AS u on c.userid=u.id

WHERE c.id = %%COURSEID%% AND u.id = %%USERID%%  AND c.anonymous_response = 1  /* This clause limits the recordset to the current course and the current user and includes/ excludes the anonymous responses as needed */

ORDER BY f.id, c.timemodified, i.id

Show all Feedbacks from all courses for all users including showing names of anonymous users

Contributed by: Randy Thornton

Shows all Feedbacks in all Courses with all multi-choice questions and answers of all users including showing the username of anonymous users. Also shows truly anonymous users on the front page as 'Not-logged-in' users. This is a rough report, not a pretty report, and is limited to multiple-choice type questions, but is shows the answer number and the list of possible answers in raw form. I post it here as a basis for further reports, and also as away to get the identities of anonymous users if needed.

SELECT 
c.shortname AS Course, 
f.name AS Feedback,
# i.id AS Itemid,
i.name AS Itemname,
i.label AS Itemlabel,
CASE 
 WHEN f.anonymous = 1 AND u.id != 0 THEN CONCAT(u.username, ' :ANON')
 WHEN fc.userid = 0 THEN 'Not-logged-in'
 ELSE u.username
END AS 'User',
DATE_FORMAT(FROM_UNIXTIME(fc.timemodified),'%Y-%m-%d %H:%i') AS "Completed",
v.value AS "Choice",
CASE 
 WHEN i.typ = 'multichoice' THEN
     IF (  SUBSTRING(i.presentation,1,6)='d>>>>>',
	       SUBSTRING(i.presentation,7),
		   i.presentation)
 ELSE i.presentation
END AS "Answers",
i.typ,
i.dependitem,
i.dependvalue

FROM prefix_feedback f
JOIN prefix_course c ON c.id=f.course 
JOIN prefix_feedback_item AS i ON f.id=i.feedback
JOIN prefix_feedback_completed fc ON f.id=fc.feedback
LEFT JOIN prefix_feedback_value v ON v.completed=fc.id AND v.item=i.id
LEFT JOIN prefix_user AS u ON fc.userid=u.id
WHERE i.typ != 'pagebreak'


Show all Feedbacks from all courses for all users with their answers

Contributed by: Randy Thornton

Shows all Feedbacks in all Courses with all multi-choice questions and answers of all users for multi-choice questions. It shows the possible answers, the number of the chosen answer and the text of the chosen answer by the user. As always, I disavow any prettiness here and you should update the fields as you need.

Known to work in Moodle 3.5 to 3.10.

SELECT 
c.fullname as "Course", 
f.name AS "Feedback", 
CONCAT(u.firstname,'  ',u.lastname) as "User",
DATE_FORMAT(FROM_UNIXTIME(fc.timemodified), '%Y-%m-%d %H:%i') AS "When",
IF(i.typ = 'label', i.presentation, i.name) AS "Question", 
# answers presentation string starts with these 6 characters:  r>>>>>
CASE WHEN i.typ = 'multichoice' THEN SUBSTRING(i.presentation,7) END AS "Possible Answers",

CASE i.typ WHEN 'multichoice' THEN v.value ELSE '-' END AS "Chosen Answer Num",
CASE v.value
  WHEN 1 THEN SUBSTRING(i.presentation, 7, POSITION('|' IN i.presentation) - 7) 
  WHEN 2 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',2), '|',-1)
  WHEN 3 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',3), '|',-1)
  WHEN 4 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',4), '|',-1)
  WHEN 5 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',5), '|',-1)
  WHEN 6 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',6), '|',-1)
  WHEN 7 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',7), '|',-1)
  WHEN 8 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',8), '|',-1)
  WHEN 9 THEN SUBSTRING_INDEX(SUBSTRING_INDEX(i.presentation, '|',9), '|',-1) 
  ELSE CONCAT("More:", v.value)
END AS "Chosen Answer Text"
 
FROM prefix_feedback AS f
JOIN prefix_course AS c ON c.id=f.course
JOIN prefix_feedback_item AS i ON f.id=i.feedback
JOIN prefix_feedback_completed AS fc ON f.id=fc.feedback 
LEFT JOIN prefix_feedback_value AS v ON v.completed=fc.id AND v.item=i.id
JOIN prefix_user AS u ON fc.userid=u.id

WHERE i.typ IN ('label', 'multichoice')

Resource Module Reports

List "Recently uploaded files"

see what users are uploading

SELECT FROM_UNIXTIME(time,'%Y %M %D %h:%i:%s') as time ,ip,userid,url,info  
FROM `prefix_log` 
WHERE `action` LIKE 'upload' 
ORDER BY `prefix_log`.`time`  DESC

List Courses that loaded a specific file: "X"

Did the Teacher (probably) uploaded course's Syllabus ?

SELECT c.id, c.fullname  FROM `prefix_log` as l 
JOIN prefix_course as c ON c.id = l.course 
WHERE `action` LIKE '%upload%' AND ( info LIKE '%Syllabus%' OR info LIKE '%Sylabus%' ) GROUP BY c.id

All resources that link to some specific external website

+ link to course + who's the teacher + link to external resource

SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,c.shortname,r.name
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
,concat('<a target="_new" href="%%WWWROOT%%/mod/resource/view.php?id=',r.id,'">',r.name,'</a>') AS Resource
FROM prefix_resource AS r 
JOIN prefix_course AS c ON r.course = c.id
WHERE r.reference LIKE 'http://info.oranim.ac.il/home%'

"Compose Web Page" RESOURCE count

SELECT course,prefix_course.fullname, COUNT(*) AS Total
FROM `prefix_resource`
JOIN `prefix_course` ON prefix_course.id = prefix_resource.course
WHERE type='html'
GROUP BY course

Resource count in courses

+ (First)Teacher name + Where course is inside some specific Categories

SELECT 
COUNT(*) AS count
,r.course 
,c.shortname shortname
,c.fullname coursename
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user as u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = r.course AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
FROM prefix_resource r 
JOIN prefix_course c ON r.course = c.id
WHERE c.category IN (10,13,28,18,26)
GROUP BY r.course
ORDER BY COUNT(*) DESC

Delete all the automated backup files

Prepare bash cli script to delete all the automated backup files on the file system. (clean up some disk space)

SELECT CONCAT( 'rm -f /var/moodledatanew/filedir/', SUBSTRING( contenthash, 1, 2 ) , '/', SUBSTRING( contenthash, 3, 2 ) , '/', contenthash ) 
FROM `mdl_files` 
WHERE `filename` LIKE '%mbz%'
AND filearea = 'automated'

Find out how much disk space is used by all automated backup files:

SELECT SUM(filesize)/(1024*1024*1024) FROM `mdl_files` WHERE  `filename` LIKE '%mbz%' AND filearea =  'automated'

Forum Module Reports

print all User's post in course Forums

%%COURSEID%% is a variable the is replace by the current CourseID you are running the sql report from. if you are using the latest block/configurable_reports ! (You can always change it to a fixed course or remove it to display all courses.)

SELECT 
concat('<a target="_new" href="%%WWWROOT%%/mod/forum/user.php?course=',c.id,'&id=',u.id,'&mode=posts">',CONCAT(u.firstname,' ', u.lastname),'</a>') As Fullname
,concat('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',fd.forum,'">',f.name,'</a>') AS Forum
,count(*) as Posts
,(SELECT count(*) FROM prefix_forum_discussions AS ifd JOIN prefix_forum as iforum ON iforum.id = ifd.forum  WHERE ifd.userid = fp.userid AND iforum.id = f.id) AS cAllDiscussion

FROM prefix_forum_posts AS fp 
JOIN prefix_user as u ON u.id = fp.userid 
JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id 
JOIN prefix_forum AS f ON f.id = fd.forum 
JOIN prefix_course as c ON c.id = fd.course 
WHERE fd.course = %%COURSEID%% 
GROUP BY f.id,u.id
ORDER BY u.id

FORUM use Count per COURSE -- not including NEWS Forum!

SELECT prefix_course.fullname, prefix_forum.course, count(*) as total FROM prefix_forum
INNER JOIN prefix_course
ON prefix_course.id = prefix_forum.course
WHERE NOT(prefix_forum.type = 'news')
GROUP BY prefix_forum.course
ORDER BY total desc

FORUM use Count per COURSE by type -- not including NEWS Forum!

SELECT prefix_course.fullname, prefix_forum.course, prefix_forum.type, count(*) as total FROM prefix_forum
INNER JOIN prefix_course
ON prefix_course.id = prefix_forum.course
WHERE NOT(prefix_forum.type = 'news')
GROUP BY prefix_forum.course,prefix_forum.type
ORDER BY total desc

Forum activity - system wide

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS CourseID
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
,c.fullname as Course
,f.type
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
, fd.forum, f.name,count(*) AS cPostAndDisc
,(SELECT count(*) FROM prefix_forum_discussions AS ifd WHERE ifd.forum = f.id) AS cDiscussion
FROM prefix_forum_posts AS fp
JOIN prefix_forum_discussions AS fd ON fd.id = fp.discussion
JOIN prefix_forum AS f ON f.id = fd.forum
JOIN prefix_course AS c ON c.id = f.course
WHERE f.type != 'news' AND c.fullname LIKE '%2013%'
## WHERE 1=1 
## %%FILTER_YEARS:c.fullname%%
## You can enable the SEMESTER filter as well, 
## by uncommenting the following line:
## %%FILTER_SEMESTERS:c.fullname%%

GROUP BY fd.forum
ORDER BY count( * ) DESC

Activity In Forums

Trying to figure out how much real activity we have in Forums by aggregating: Users in Course, Number of Posts, Number of Discussions, Unique student post, Unique student discussions, Number of Teachers , Number of Students, ratio between unique Student posts and the number of students in the Course...

SELECT c.fullname,f.name,f.type 
,(SELECT count(id) FROM prefix_forum_discussions as fd WHERE f.id = fd.forum) as Discussions
,(SELECT count(distinct fd.userid) FROM prefix_forum_discussions as fd WHERE fd.forum = f.id) as UniqueUsersDiscussions
,(SELECT count(fp.id) FROM prefix_forum_discussions fd JOIN prefix_forum_posts as fp ON fd.id = fp.discussion WHERE f.id = fd.forum) as Posts
,(SELECT count(distinct fp.userid) FROM prefix_forum_discussions fd JOIN prefix_forum_posts as fp ON fd.id = fp.discussion WHERE f.id = fd.forum) as UniqueUsersPosts
,(SELECT Count( ra.userid ) AS Students
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid =5
AND ctx.instanceid = c.id
) AS StudentsCount
,(SELECT Count( ra.userid ) AS Teachers
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid =3
AND ctx.instanceid = c.id
) AS 'Teacher<br/>Count'
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid IN (3,5)
AND ctx.instanceid = c.id
) AS UserCount
, (SELECT (UniqueUsersDiscussions / StudentsCount )) as StudentDissUsage
, (SELECT (UniqueUsersPosts /StudentsCount)) as StudentPostUsage
FROM prefix_forum as f 
JOIN prefix_course as c ON f.course = c.id
WHERE `type` != 'news'
ORDER BY StudentPostUsage DESC

All Forum type:NEWS

SELECT f.id, f.name
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_forum AS f ON cm.instance = f.id
WHERE m.name = 'forum'
AND f.type = 'news'

All new forum NEWS items (discussions) from all my Courses

change "userid = 26" and "id = 26" to a new user id

SELECT c.shortname,f.name,fd.name,FROM_UNIXTIME(fd.timemodified ,"%d %M %Y ") as Date
FROM prefix_forum_discussions as fd 
JOIN prefix_forum as f ON f.id = fd.forum 
JOIN prefix_course as c ON c.id = f.course 
JOIN prefix_user_lastaccess as ul ON (c.id = ul.courseid AND ul.userid = 26)
WHERE fd.timemodified > ul.timeaccess  
 AND fd.forum IN (SELECT f.id
 FROM prefix_course_modules AS cm
 JOIN prefix_modules AS m ON cm.module = m.id
 JOIN prefix_forum AS f ON cm.instance = f.id
 WHERE m.name = 'forum'
 AND f.type = 'news')
  AND c.id IN (SELECT c.id
   FROM prefix_course AS c
   JOIN prefix_context AS ctx ON c.id = ctx.instanceid
   JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
   JOIN prefix_user AS u ON u.id = ra.userid
   WHERE u.id = 26) ORDER BY `fd`.`timemodified` DESC


News Forum - Discussions COUNT

Which is actually... How much instructions students get from their teachers

SELECT c.shortname ,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
,concat('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',fd.forum,'">',count(fd.id),'</a>') AS DiscussionsSum
FROM prefix_forum_discussions AS fd
INNER JOIN prefix_forum AS f ON f.id = fd.forum
INNER JOIN prefix_course AS c ON c.id = f.course
WHERE f.type = 'news' AND c.category IN (10,13,28,18,26)
GROUP BY fd.forum
ORDER BY count(fd.id) DESC

Cantidad de foros que han sido posteados por profesor

(Number of forums that have been posted by teacher/Google translator)

Queriamos saber cuales son las acciones del profesor dentro de los foros de cada curso, por ello se hizo este informe.

(We wanted to know what the teacher's actions are in the forums of each course, so this report was made. /Google translator)

SELECT 
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS curso,
CONCAT(u.firstname ,' ',u.lastname) AS Facilitador,

(SELECT COUNT( m.name ) AS COUNT FROM 
prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%forum%') AS foros,

COUNT(*) AS Posts

FROM prefix_forum_posts AS fp 
JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id 
JOIN prefix_forum AS f ON f.id = fd.forum 
JOIN prefix_course AS c ON c.id = fd.course
JOIN prefix_user AS u ON u.id = fp.userid 

WHERE fp.userid =
(
select distinct prefix_user.id
from prefix_user 
join prefix_role_assignments as ra on ra.userid = prefix_user.id 
where ra.roleid = 3 
and userid = fp.userid
limit 1
)

and c.shortname like '%2014-2-1%'
GROUP BY c.id, u.id


List all the Posts in all the Forums that got high rating

We setup a scale that let teachers and students Rate forum post with "Important, interesting, valuable, not rated" scale And then add a link to the following report at the begining of the course "Link to all interesting posts"

SELECT 
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',f.id,'">',f.name,'</a>') AS 'Forum name,
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/discuss.php?d=',fd.id,'#p',fp.id,'">',fp.subject,'</a>') AS 'Post link',
SUM(r.rating) AS 'Rating'
FROM mdl_rating AS r
  JOIN mdl_forum_posts AS fp ON fp.id = r.itemid
  JOIN mdl_forum_discussions AS fd ON fd.id = fp.discussion
  JOIN mdl_forum AS f ON f.id = fd.forum
WHERE r.component = 'mod_forum' AND r.ratingarea = 'post' AND f.course = %%COURSEID%%
GROUP BY r.itemid
ORDER BY SUM(r.rating) DESC

List all the Posts in all Discussions of a single Forum

This report is used to help export all the student's posts and discussions of a single forum, by passing the course module id as a parameter to the report using "&filter_var=cmid"

SELECT 
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=', f.id, '">', f.name, '</a>') AS 'Forum name',
fd.name AS 'Discussion', 
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/discuss.php?d=', fd.id, '#p', fp.id, '">', fp.subject, '</a>') AS 'Post (link)',
fp.message

FROM mdl_forum_posts AS fp 
  JOIN mdl_forum_discussions AS fd ON fd.id = fp.discussion
  JOIN mdl_forum AS f ON f.id = fd.forum
  JOIN mdl_course_modules AS cm ON cm.module = 9 AND cm.instance = f.id
WHERE cm.id = %%FILTER_VAR%%
ORDER BY f.id, fd.id

Quiz Module Reports

Generate a list of instructors and their email addresses for those courses that has "essay questions" in their quizzes

SELECT qu.id AS quiz_id, qu.course AS course_id, qu.questions,
                co.fullname AS course_fullname, co.shortname AS course_shortname,
                qu.name AS quiz_name, FROM_UNIXTIME(qu.timeopen) AS quiz_timeopen, FROM_UNIXTIME(qu.timeclose) AS quiz_timeclose,
                u.firstname, u.lastname, u.email,
FROM prefix_quiz qu, prefix_course co, prefix_role re, prefix_context ct, prefix_role_assignments ra, prefix_user u
WHERE FROM_UNIXTIME(timeopen) > '2008-05-14' AND
                qu.course = co.id AND
                co.id = ct.instanceid AND
                ra.roleid = re.id AND
                re.name = 'Teacher' AND
                ra.contextid = ct.id AND
                ra.userid = u.id
 
SELECT Count('x') As NumOfStudents
                                FROM prefix_role_assignments a
                                JOIN prefix_user u ON userid = u.id
                                WHERE roleid = 5 AND contextid = (SELECT id FROM prefix_context WHERE instanceid = 668 AND contextlevel = 50)

Number of Quizes per Course

SELECT count(*)
,concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">Link</a>') AS Quizes

FROM prefix_course_modules cm
JOIN prefix_course c ON c.id = cm.course
JOIN prefix_modules as m ON m.id = cm.module
WHERE m.name LIKE 'quiz'
GROUP BY c.id

List all MultiAnswer (Cloze) Questions

SELECT concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/attempt.php?q=', quiz.id, '">', quiz.name, '</a>') AS Quiz
,question.id question_id, question.questiontext 
FROM  prefix_question question
JOIN prefix_quiz_question_instances qqi ON question.id = qqi.question
JOIN prefix_quiz quiz ON qqi.quiz = quiz.id
WHERE  `qtype` LIKE  'multianswer'

List courses with MANUAL grades

Which is basically and indication to teachers using Moodle to hold offline grades inside Moodle's Gradebook, So grades could be uploaded into an administrative SIS. Use with Configurable Reports.

SELECT COUNT( * )
,concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php?showadvanced=1&id=',c.id,'">',c.fullname,'</a>') AS Course
FROM  prefix_grade_items AS gi
JOIN prefix_course as c ON c.id = gi.courseid
WHERE  `itemtype` =  'manual'
GROUP BY courseid

List the users that did not take the Quiz

Do not forget to change "c.id = 14" and q.name LIKE '%quiz name goes here%'

SELECT
user2.id AS ID,
ul.timeaccess,
user2.firstname AS Firstname,
user2.lastname AS Lastname,
user2.email AS Email,
user2.username AS IDNumber,
user2.institution AS Institution,
 
IF (user2.lastaccess = 0,'never',
DATE_FORMAT(FROM_UNIXTIME(user2.lastaccess),'%Y-%m-%d')) AS dLastAccess
 
,(SELECT DATE_FORMAT(FROM_UNIXTIME(timeaccess),'%Y-%m-%d') FROM prefix_user_lastaccess WHERE userid=user2.id AND courseid=c.id) AS CourseLastAccess
 
,(SELECT r.name
FROM  prefix_user_enrolments AS uenrol
JOIN prefix_enrol AS e ON e.id = uenrol.enrolid
JOIN prefix_role AS r ON e.id = r.id
WHERE uenrol.userid=user2.id AND e.courseid = c.id) AS RoleName
 
FROM prefix_user_enrolments AS ue
JOIN prefix_enrol AS e ON e.id = ue.enrolid
JOIN prefix_course AS c ON c.id = e.courseid
JOIN prefix_user AS user2 ON user2 .id = ue.userid
LEFT JOIN prefix_user_lastaccess AS ul ON ul.userid = user2.id
WHERE c.id=14 and ue.userid NOT IN (SELECT qa.userid FROM prefix_quiz_attempts AS qa
JOIN prefix_quiz AS q ON qa.quiz = q.id
JOIN prefix_course AS c ON q.course = c.id
WHERE c.id = 14 AND q.name LIKE '%quiz name goes here%')

List Questions in each Quiz

SELECT quiz.id,quiz.name, q.id, q.name
FROM mdl_quiz AS quiz
JOIN mdl_question AS q ON FIND_IN_SET(q.id, quiz.questions)
WHERE quiz.course = %%COURSEID%%
ORDER BY quiz.id ASC

Note: this query does not work in Moodle 2.8+. There is no mdl_quiz.questions field. It will need to be rewritten to use the usage/contextid organization.

Here is a version for Moodle 3.x

SELECT cm.id 'cmid', quiz.id 'quiz id'
,CONCAT('<a target="_new" href="%%WWWROOT%%/mod/quiz/edit.php?cmid=', 
	   cm.id, '">', quiz.name, '</a>') AS 'edit quiz'
,q.id 'qid', q.name 'question name'
FROM mdl_quiz AS quiz
JOIN mdl_course_modules cm ON cm.instance = quiz.id AND cm.module = 33 # 33=quiz mdl_modules
JOIN mdl_quiz_slots qs ON qs.quizid = quiz.id 
JOIN mdl_question AS q ON q.id = qs.questionid
WHERE quiz.course = %%COURSEID%%
ORDER BY quiz.id ASC

Quiz activity research

This report was made to extract student full activity in quizzes for an academic research about adapting instructional design teaching methods in online learning. The students do not use the Quiz module as a standard quiz but more as Study booklets or mini courses with embedded questions and hints to assist students evaluate their progress (Similar to what you expect to find in a SCORM activity)

SELECT 
cm.course "course_id", cm.id "moduel_id", q.id "quiz_id", q.name "quiz_name",
 
CASE q.grademethod
      WHEN 1 THEN "GRADEHIGHEST"
      WHEN 2 THEN "GRADEAVERAGE"
      WHEN 3 THEN "ATTEMPTFIRST"
      WHEN 4 THEN "ATTEMPTLAST"
END "grade method"
   
, q.attempts "quiz_attempts_allowed", cm.groupmode "group_mode"
, qa.id "attempt_id", qa.state "attempt_state", qa.sumgrades "attempt_grade", qg.grade "user_final_grade", q.grade "quiz_max_grade"
,(SELECT GROUP_CONCAT(g.name) FROM mdl_groups AS g
JOIN mdl_groups_members AS m ON g.id = m.groupid WHERE g.courseid = q.course AND m.userid = u.id) "user_groups",
DATE_FORMAT(FROM_UNIXTIME(qa.timestart), '%d-%m-%Y %h:%k') "attempt_start",
DATE_FORMAT(FROM_UNIXTIME(qa.timefinish), '%d-%m-%Y %h:%k') "attempt_finish",
u.id "user_id", u.firstname, u.lastname,
question.id "question_id", question.name "question_name",
qas.state "question_step_state",qas.fraction "question_grade", qh.hint, question.qtype "question_type"

FROM mdl_quiz as q
JOIN mdl_course_modules as cm ON cm.instance = q.id and cm.module = 14 
JOIN mdl_quiz_attempts qa ON q.id = qa.quiz
LEFT JOIN mdl_quiz_grades as qg ON qg.quiz = q.id and qg.userid = qa.userid
JOIN mdl_user as u ON u.id = qa.userid
JOIN mdl_question_usages as qu ON qu.id = qa.uniqueid
JOIN mdl_question_attempts as qatt ON qatt.questionusageid = qu.id
JOIN mdl_question as question ON question.id = qatt.questionid
JOIN mdl_question_attempt_steps as qas ON qas.questionattemptid = qatt.id
LEFT JOIN mdl_question_hints as qh ON qh.questionid = q.id
#WHERE q.id = "SOME QUIZ ID"
WHERE cm.course = "SOME COURSE ID"

Quiz Usage in Courses by Date

Contributed by Elizabeth Dalton, Granite State College

This report lists the courses containing quizzes with the course start date between the two values, and provides a summary of the types of questions in the quizzes in each course and whether question randomization and answer randomization functions were used.

"Multiple Choice" questions include true/false and matching question types.

"Short Answer" are questions that accept a single phrase.

"Other" questions include fixed numerical, calculated, essay, and various drag and drop types.

"Min Quiz Age" and "Max Quiz Age" provide data about the last modified date for the quizzes in the course, compared to the course start date. The values are expressed in units of days. A negative value indicates that a quiz was edited after the start of the course. A value greater than 90 days indicates that the quiz may have been used in an earlier term (cohort) without modification.

Note: In Configurable Reports, the Date Filter is not applied until the "Apply" button is clicked.

SELECT 

c.shortname AS 'Course'
#, u.lastname AS 'Instructor'
, COUNT(DISTINCT q.id) AS 'Quizzes'
, COUNT(DISTINCT qu.id) AS 'Questions'
, SUM(IF (qu.qtype = 'multichoice', 1, 0 )) + SUM(IF (qu.qtype = 'truefalse', 1, 0 )) + SUM(IF (qu.qtype = 'match', 1, 0 ))  AS 'multichoice'

, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'

, COUNT( qu.id) - SUM(IF (qu.qtype = 'multichoice', 1, 0 )) - SUM(IF (qu.qtype = 'truefalse', 1, 0 )) - SUM(IF (qu.qtype = 'match', 1, 0 )) - SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'Other'

, (SUM(IF (qu.qtype = 'multichoice', 1, 0 )) + SUM(IF (qu.qtype = 'truefalse', 1, 0 )) + SUM(IF (qu.qtype = 'match', 1, 0 )))/COUNT( qu.id) AS 'Percent MC'

#, SUM(IF (qu.qtype = 'numerical', 1, 0 )) AS 'numerical'
#, SUM(IF (qu.qtype LIKE 'calc%', 1, 0 )) AS 'calculated'
#, SUM(IF (qu.qtype = 'random', 1, 0 )) AS 'random'
#, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'
#, SUM(IF (qu.qtype = 'essay', 1, 0 )) AS 'essay'


, IF(q.shufflequestions > 0,'Yes','No') AS 'Randomized Questions'
, IF(q.shuffleanswers > 0,'Yes','No') AS 'Randomized Answers'
 
#, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
#, FROM_UNIXTIME(MIN(q.timemodified)) AS 'Last Modified'

#, DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(MIN(q.timemodified))) AS 'Quiz age'

, MIN(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Min Quiz Age' 
, MAX(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Max Quiz Age' 

#, SUM(IF (DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified)) < 90, 1,0)) AS 'new quizzes'

FROM prefix_quiz AS q
JOIN prefix_course AS c on c.id = q.course
JOIN prefix_quiz_question_instances AS qqi ON qqi.quiz = q.id
LEFT JOIN prefix_question AS qu ON qu.id = qqi.question

WHERE
1
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.startdate:<%%

GROUP BY c.id

ORDER BY c.shortname

Student responses (answers) to quiz questions

(Contributed by Juan F with help from Tim hunt and fellow Moodlers on the forums) A report that targets a specific quiz for all of our Biology courses, a summary of all questions and how many students get them right/wrong.

SELECT
    concat( u.firstname, " ", u.lastname ) AS "Student Name",
    u.id,
    quiza.userid,
    q.course,
    q.name,
    quiza.attempt,
    qa.slot,
    que.questiontext AS 'Question',
    qa.rightanswer AS 'Correct Answer',
    qa.responsesummary AS 'Student Answer'

FROM mdl_quiz_attempts quiza
JOIN mdl_quiz q ON q.id=quiza.quiz
JOIN mdl_question_usages qu ON qu.id = quiza.uniqueid
JOIN mdl_question_attempts qa ON qa.questionusageid = qu.id
JOIN mdl_question que ON que.id = qa.questionid
JOIN mdl_user u ON u.id = quiza.userid

WHERE q.name = "BIO 208 Post Test Assessment"
AND q.course = "17926"

ORDER BY quiza.userid, quiza.attempt, qa.slot

Questions which are tagged within a course/quiz

Calculates subgrades for tags in the each of the quizzes in a course. Contributed by Daniel Thies in https://moodle.org/mod/forum/discuss.php?d=324314#p1346542

SELECT 
    quiz.name AS quiz,
    t.rawname AS tag,
    CONCAT('<a target="_new" href="%%WWWROOT%%/mod/quiz/review.php?attempt=',
            MAX(quiza.id),'">',u.firstname,' ',u.lastname,'</a>') AS student,
    CAST(SUM(qas.fraction) as decimal(12,1)) AS correct,
    CAST(SUM(qa.maxmark) as decimal(12,1)) AS maximum,
    CAST(SUM(qas.fraction)/SUM(qa.maxmark)*100 as decimal(4,2)) AS score
FROM prefix_quiz_attempts quiza
JOIN prefix_user u ON quiza.userid = u.id
JOIN prefix_question_usages qu ON qu.id = quiza.uniqueid
JOIN prefix_question_attempts qa ON qa.questionusageid = qu.id
JOIN prefix_quiz quiz ON quiz.id = quiza.quiz
JOIN prefix_tag_instance ti ON qa.questionid = ti.itemid
JOIN prefix_tag t ON t.id = ti.tagid
JOIN (SELECT MAX(fraction) AS fraction, questionattemptid
        FROM prefix_question_attempt_steps
        GROUP BY questionattemptid) qas ON qas.questionattemptid = qa.id 
WHERE quiz.course = %%COURSEID%%
GROUP BY quiza.userid,
    quiza.quiz,
    quiz.name,
    u.firstname,
    u.lastname,
    ti.tagid,
    t.rawname
ORDER BY quiza.quiz, t.rawname, u.lastname, u.firstname, score

SCORM Activity Reports

Lists All completed SCORM activites by Course name

This report will list all completed attempts for all SCORM activities. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. Please note: the FROM_UNIXTIME command is for MySQL.

SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date 
FROM prefix_scorm_scoes_track AS st 
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
WHERE st.value='completed' 
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt

Lists SCORM status for all enrolled users by Course name

This report will list the SCORM status for all users enrolled in the course. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. This can be limited to individual courses by adding to the where clause the course id to report on.

SELECT
u.firstname AS First,
u.lastname AS Last, 
u.idnumber AS Employee_ID,  
u.city AS City,
uid.data AS State,
u.country AS Country,
g.name AS Group_name,
c.fullname AS Course, 
st.attempt AS Attempt,
st.value AS Status,
FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") AS Date 

FROM prefix_scorm_scoes_track AS st 
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_user_info_data AS uid ON uid.userid = u.id 
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_groups_members AS m ON g.id = m.groupid

WHERE st.element='cmi.core.lesson_status' AND m.userid=u.id

UNION

SELECT
user2.firstname AS First,
user2.lastname AS Last,
user2. idnumber AS Employee_ID,
user2.city AS City,
uid.data AS State,
user2.country AS Country,
g.name AS Group_name,
c.fullname AS Course,
"-" AS Attempt,
"not_started" AS Status,
"-" AS Date

FROM prefix_user_enrolments AS ue
JOIN prefix_enrol AS e ON e.id = ue.enrolid
JOIN prefix_course AS c ON c.id = e.courseid
JOIN prefix_user AS user2 ON user2 .id = ue.userid
JOIN prefix_user_info_data AS uid ON uid.userid = user2.id 
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_groups_members AS m ON g.id = m.groupid
JOIN prefix_scorm AS sc ON sc.course=c.id
Left Join prefix_scorm_scoes_track AS st on st.scormid=sc.id AND st.userid=user2.id

WHERE  st.timemodified IS NULL AND m.userid=user2.id

ORDER BY  Course, Last, First, Attempt

Badges

All badges issued, by User

Contributed by: Randy Thornton

This report will show you all the badges on a site that have been issued, both site and all courses, by the username of each user issued a badge. Includes the type of criteria passed (activity, course completion, manual), date issued, date expires, and a direct link to that issued badge page so you can see all the other details for that badge.

SELECT u.username, b.name AS badgename, 
CASE
WHEN b.courseid IS NOT NULL THEN
(SELECT c.shortname
    FROM prefix_course AS c
    WHERE c.id = b.courseid)
WHEN b.courseid IS NULL THEN "*"
END AS Context,
CASE 
  WHEN t.criteriatype = 1 AND t.method = 1 THEN "Activity Completion (All)"
  WHEN t.criteriatype = 1 AND t.method = 2 THEN "Activity Completion (Any)"
  WHEN t.criteriatype = 2 AND t.method = 2 THEN "Manual Award"
  WHEN t.criteriatype = 4 AND t.method = 1 THEN "Course Completion (All)"
  WHEN t.criteriatype = 4 AND t.method = 2 THEN "Course Completion (Any)"
  ELSE CONCAT ('Other: ', t.criteriatype)
END AS Criteriatype,
DATE_FORMAT( FROM_UNIXTIME( d.dateissued ) , '%Y-%m-%d' ) AS dateissued,
DATE_FORMAT( FROM_UNIXTIME( d.dateexpire ), '%Y-%m-%d' ) AS dateexpires,
CONCAT ('<a target="_new" href="%%WWWROOT%%/badges/badge.php?hash=',d.uniquehash,'">link</a>') AS Details
FROM prefix_badge_issued AS d 
JOIN prefix_badge AS b ON d.badgeid = b.id
JOIN prefix_user AS u ON d.userid = u.id
JOIN prefix_badge_criteria AS t on b.id = t.badgeid 
WHERE t.criteriatype <> 0
ORDER BY u.username

Please note: the FROM_UNIXTIME command is for MySQL.

All badges available in the system, with Earned count

Contributed by: Randy Thornton

Report of all badges in the system, with badge name and description, context, course shortname if a course badge, whether it is active and available, and a count of how many users have been issued that badge.

SELECT b.id, b.name, b.description,
CASE
WHEN b.type = 1 THEN "System"
WHEN b.type = 2 THEN "Course"
END AS Context, 
CASE
WHEN b.courseid IS NOT NULL THEN 
(SELECT c.shortname 
    FROM prefix_course AS c 
    WHERE c.id = b.courseid)
WHEN b.courseid IS NULL THEN "*"
END AS Course, 
CASE
WHEN b.status = 0 OR b.status = 2 THEN "No"
WHEN b.status = 1 OR b.status = 3 THEN "Yes"
WHEN b.status = 4 THEN "x"
END AS Available,
CASE
WHEN b.status = 0 OR b.status = 1 THEN "0"
WHEN b.status = 2 OR b.status = 3 OR b.status = 4 THEN 
 (SELECT COUNT(*) 
   FROM prefix_badge_issued AS d
   WHERE d.badgeid = b.id
 )
END AS Earned
FROM prefix_badge AS b

Badges Leaderboard

Contributed by: Randy Thornton

A simple list of usernames and how many badges they have earned overall.

SELECT u.username, (SELECT COUNT(*) FROM prefix_badge_issued AS d WHERE d.userid = u.id) AS earned
FROM prefix_user AS u
ORDER BY earned DESC, u.username ASC

Manage badges (System & Course)

List system wide badges, course and system level badges + a link to relevant "manage badges" page.

SELECT b.id, b.name, b.description 
,CASE 
  WHEN b.type = 1 THEN 'System'
  WHEN b.type = 2 THEN 'Course'
END AS Level
,CONCAT('<a target="_new" href="%%WWWROOT%%/badges/index.php?type=', b.type, '&id=',
			  c.id, '">Manage badges in: ', c.fullname, '</a>') AS Manage 
FROM prefix_badge AS b
JOIN prefix_course AS c ON c.id = b.courseid

Administrator Reports

Config changes in Export friendly form

Contributed by: Randy Thornton

The Administrative report Config changes is very useful but it would be nice to have it in a format that could be easily exported in one listing. Here is code to do that.

SELECT 
DATE_FORMAT( FROM_UNIXTIME( g.timemodified ) , '%Y-%m-%d' ) AS date, 
u.username AS user, 
g.name AS setting, 
CASE 
 WHEN g.plugin IS NULL THEN "core"
 ELSE g.plugin
END AS plugin, 
g.value AS new_value, 
g.oldvalue AS original_value
FROM prefix_config_log  AS g
JOIN prefix_user AS u ON g.userid = u.id
ORDER BY date DESC

Cohorts by user

Contributed by: Randy Thornton

How to get a list of all users and which cohorts they belong to.

SELECT u.firstname, u.lastname, h.idnumber, h.name
FROM prefix_cohort AS h
JOIN prefix_cohort_members AS hm ON h.id = hm.cohortid
JOIN prefix_user AS u ON hm.userid = u.id
ORDER BY u.firstname

Cohorts with Courses

Contributed by: Randy Thornton

List of all cohorts with name, id, visibility, and which courses they are enrolled in.

SELECT
# h.id,
# e.customint1,
h.name AS Cohort,
h.idnumber AS Cohortid,
CASE 
 WHEN h.visible = 1 THEN 'Yes'
 ELSE '-'
END AS Cohortvisible,
CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php', CHAR(63),'id=',c.id,'">',c.fullname,'</a>') AS Course
FROM prefix_cohort h
JOIN prefix_enrol e ON h.id = e.customint1
JOIN prefix_course c ON c.id = e.courseid %%FILTER_COURSES:e.courseid%% 
WHERE e.enrol = 'cohort' AND e.roleid = 5

Courses created And Active courses by Year

Active courses is counting course that have at least one Hit, And "Active_MoreThan100Hits" counts courses that have at least 100 Hits

SELECT 

YEAR( FROM_UNIXTIME( `timecreated` ) ) AS YEAR, COUNT( * ) AS Counter

, (SELECT COUNT( DISTINCT course ) 
FROM prefix_log AS l
WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
) AS "Active"

,(SELECT COUNT(*) FROM ( 
SELECT COUNT( * ),time 
FROM prefix_log AS l 
GROUP BY course 
HAVING COUNT(*) > 100) AS courses_log
WHERE YEAR( FROM_UNIXTIME( courses_log.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
) AS "Active_MoreThan100Hits"

FROM `prefix_course` 
GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )

Users created And Active users by Year

Active users is counting users that have at least one Hit, And "Active_MoreThan500Hits" counts users that have at least 500 Hits

SELECT 

YEAR( FROM_UNIXTIME( `firstaccess` ) ) AS YEAR, COUNT( * ) AS Counter

, (SELECT COUNT( DISTINCT userid ) 
FROM prefix_log AS l
WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `firstaccess` ) )
) AS "Active"

,(SELECT COUNT(*) FROM ( 
SELECT COUNT( * ),time 
FROM prefix_log AS l 
GROUP BY userid 
HAVING COUNT(*) > 500) AS users_log
WHERE YEAR( FROM_UNIXTIME( users_log.`time` ) ) = YEAR( FROM_UNIXTIME( `firstaccess` ) )
) AS "Active_MoreThan500Hits"

FROM `prefix_user` 
GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )

Course Aggregation Report

Contributed by Elizabeth Dalton, Granite State College

If you are considering upgrading from Moodle 2.6 to 2.8 or later, your grades may be changed. This report can help quantify and identify the courses at risk of changes.

In particular, be on the lookout for any courses with the following combinations of parameters, which are known to cause changes in calculations:

  1. mean of grades set with aggregate with subcategory.
  2. Simple weighted mean of grades with aggregate with sub category and drop the lowest
  3. Sum of grades drop the lowest

Also review: https://tracker.moodle.org/browse/MDL-48618 https://tracker.moodle.org/browse/MDL-48634 https://tracker.moodle.org/browse/MDL-49257 https://tracker.moodle.org/browse/MDL-50089 https://tracker.moodle.org/browse/MDL-50062

SELECT

COUNT(c.shortname) AS 'Count of Courses'

# If you want to display all the courses for each aggregation type, uncomment the next line and change GROUP BY settings
#, c.shortname AS 'course name'

# If you need to display grade categories for each aggregation type, uncomment the next line and change GROUP BY settings
#, gc.fullname AS 'grade category name'

, gc.aggregation AS 'aggregation method'

#These aggregation text strings appear to be hard-coded. I couldn't find a table for them. If you have aggregation types I haven't included here, they'll be blank in your report results.
, CASE gc.aggregation
  WHEN 0 THEN 'Mean of Grades'
  WHEN 2 THEN 'Median of Grades'
  WHEN 6 THEN 'Highest Grade'
  WHEN 8 THEN 'Mode of Grades'
  WHEN 10 THEN 'Weighted Mean of Grades'
  WHEN 11 THEN 'Simple Weighted Mean of Grades'
  WHEN 12 THEN 'Mean of Grades (with extra credits)'
  WHEN 13 THEN 'Sum of Grades'
END AS 'aggregation name'

# Note that gc.aggregatesubcats column is eliminated in 2.8 and later per MDL-47503, so comment that line on updated systems or you'll get an error
, gc.keephigh AS 'keep high'
, gc.droplow AS 'dr0p low'
, gc.aggregateonlygraded AS 'Aggregate only graded'
, gc.aggregateoutcomes AS 'aggregate outcomes'
, gc.aggregatesubcats AS 'aggregate subcategories'

# If you are displaying data about individual courses, you may want to know how old they are
#, FROM_UNIXTIME(c.startdate) AS 'course start date'

# If you are trying to use this report to check to see if final grades have changed after an upgrade, you might want these data items, but calculations can still change later when the courses are actually viewed. Also, you'll need to uncomment the necessary JOINs below
#, gi.itemname AS 'grade item'
#, gg.finalgrade AS 'final grade'

FROM

prefix_course AS c
JOIN prefix_grade_categories AS gc ON gc.courseid = c.id
JOIN prefix_course_categories AS cc ON cc.id = c.category

#LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id #AND gi.categoryid=gc.id
#LEFT JOIN prefix_grade_grades AS gg ON gg.itemid = gi.id AND gg.userid = u.id

WHERE
1
#AND gc.aggregation = 13 #only the dreaded Sum of Grades aggregations
#AND gc.depth = 1 # if for some reason you only want course aggregations, not subcategories


GROUP BY gc.aggregation, gc.keephigh, gc.droplow, gc.aggregateonlygraded, gc.aggregateoutcomes, gc.aggregatesubcats

Running Cron jobs (task_scheduled)

SELECT classname
  ,DATE_FORMAT(FROM_UNIXTIME(lastruntime), '%H:%i [%d]') AS 'last'
  ,DATE_FORMAT(now(), '%H:%i') AS 'now'
  ,DATE_FORMAT(FROM_UNIXTIME(nextruntime), '%H:%i [%d]') AS 'next'
  ,DATE_FORMAT(FROM_UNIXTIME(UNIX_TIMESTAMP()-nextruntime), '%i') AS 'next in min'
FROM mdl_task_scheduled
WHERE now() > FROM_UNIXTIME(nextruntime)

Flat file enrollments waiting for processing

Contributed by: Randy Thornton

This lists all enrolments uploaded by the Flat file enrolment method that are currently waiting to be processed. When the optional enrolment start date is set for a user in the file, and this start date is in the future, the enrolment information is held in the database until the time for the actual enrolment to start at which time the user is actually enroled. This report allows you to see any and all such enrolments that are waiting to be done.

SELECT
u.username,
c.fullname AS "Course",
ef.action,
r.shortname AS "Role",
DATE_FORMAT(FROM_UNIXTIME(ef.timestart),'%Y-%m-%d %H:%i')  AS "Enrolment Start",
DATE_FORMAT(FROM_UNIXTIME(ef.timeend),'%Y-%m-%d %H:%i')  AS "Enrolment End",
DATE_FORMAT(FROM_UNIXTIME(ef.timemodified),'%Y-%m-%d %H:%i') AS "Uploaded Date"

FROM prefix_enrol_flatfile ef
JOIN prefix_user u ON u.id = ef.userid
JOIN prefix_course c ON c.id = ef.courseid
JOIN prefix_role r ON r.id = ef.roleid

ORDER BY u.username

All Meta courses with Parent and Child course relationships

Contributed by: Randy Thornton

This shows the list of courses with Meta course link enrollments in them ('Parent course'), and the courses which are connected to them to provide enrollments ('Child courses').

SELECT 
c.fullname AS 'Parent course name',
c.shortname AS 'Parent course shortname',
en.courseid AS 'Parent course id',
(SELECT fullname FROM prefix_course WHERE prefix_course.id = en.customint1) As 'Child course name',
(SELECT shortname FROM prefix_course WHERE prefix_course.id = en.customint1) As 'Child course shortname',
en.customint1 AS 'Child course id'
FROM prefix_enrol en
JOIN prefix_course c ON c.id = en.courseid
WHERE en.enrol = 'meta'
ORDER BY c.fullname

All Private Files by User

Contributed by: Randy Thornton

Lists all files by all users in the Private Files repository, with the file path location and name in the moodledata/filedir directory structure, and time created.

SELECT 
u.username, 
f.filename, 
CONCAT('/', LEFT(f.contenthash,2), '/', MID(f.contenthash,3,2), '/', f.contenthash) AS "Filedir_Location",
DATE_FORMAT(FROM_UNIXTIME(f.timecreated),'%Y-%m-%d %H:%i') AS "Created"
FROM prefix_files f 
JOIN prefix_user u ON u.id = f.userid
WHERE f.component = 'user' 
AND f.filearea = 'private' 
AND f.filesize > 0 
ORDER BY u.username, f.filename

All Tags in use in Courses and Activities

Contributed by: Randy Thornton

Shows all tags that are in use in Courses and in Activities. Shows the tag name, which course it is used in, whether it is a course level tag or an activity level tag, along with handy links to the course and activity. If it is an tag in an activity, it shows the activity type and its name. Also shows you if the tag is a Standard tag or not in the system, and if not, which user created the tag.

Note: this version includes the new H5P core activity in its list of modules.

SELECT
t.name AS "Tag",
CASE ti.itemtype
  WHEN 'course' THEN 'Course'
  ELSE "Activity"
END AS "Tag_Type",

# get the course name
CASE ti.itemtype
  WHEN 'course' THEN 
   (SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',id,'">',shortname,'</a>') FROM prefix_course WHERE id = ti.itemid)
  ELSE 
   (SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',id,'">',shortname,'</a>') FROM prefix_course WHERE id = cm.course)
END AS "Course",

# get the activity type
CASE ti.itemtype
  WHEN 'course' THEN '-'
  ELSE 
     # (SELECT CONCAT(name, ' (',cm.module,')') FROM prefix_modules WHERE id = cm.module)
	 m.name
END AS "Activity_Type",

# get the activity name
CASE ti.itemtype
  WHEN 'course' THEN '-'
  ELSE 
    CASE
    WHEN m.name = 'assign' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_assign WHERE id = cm.instance)
     WHEN m.name = 'assignment' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_assignment WHERE id = cm.instance)
     WHEN m.name = 'book' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_book WHERE id = cm.instance)
     WHEN m.name = 'chat' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_chat WHERE id = cm.instance)
     WHEN m.name = 'choice' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_choice WHERE id = cm.instance)
     WHEN m.name = 'data' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_data WHERE id = cm.instance)
     WHEN m.name = 'feedback' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_feedback WHERE id = cm.instance)
     WHEN m.name = 'folder' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_folder WHERE id = cm.instance)
     WHEN m.name = 'forum' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_forum  WHERE id = cm.instance)
     WHEN m.name = 'glossary' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_glossary WHERE id = cm.instance)
     WHEN m.name = 'h5pactivity' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_h5pactivity WHERE id = cm.instance)
     WHEN m.name = 'imscp' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_imscp WHERE id = cm.instance)
     WHEN m.name = 'label' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_label WHERE id = cm.instance)
     WHEN m.name = 'lesson' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_lesson WHERE id = cm.instance)
     WHEN m.name = 'lti' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_lti WHERE id = cm.instance)
     WHEN m.name = 'page' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_page WHERE id = cm.instance)
     WHEN m.name = 'quiz' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_quiz WHERE id = cm.instance)
     WHEN m.name = 'resource' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_resource WHERE id = cm.instance)
     WHEN m.name = 'scorm' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_scorm WHERE id = cm.instance)
     WHEN m.name = 'survey' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_survey WHERE id = cm.instance)
     WHEN m.name = 'url' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_url WHERE id = cm.instance)
     WHEN m.name = 'wiki' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_wiki WHERE id = cm.instance)
     WHEN m.name = 'workshop' THEN (SELECT CONCAT('<a target="_new" href="%%WWWROOT%%//mod/',m.name,'/view.php',CHAR(63),'id=',cm.id,'">',name,'</a>') FROM prefix_workshop WHERE id = cm.instance)
     # add any others you have installed here with their id number
     ELSE CONCAT("Unknown_mod_id: ", cm.module)
     END
END AS "Activity_name",

# get tag standard 
CASE t.isstandard
  WHEN 1 THEN 'Yes'
  ELSE CONCAT('No (', (SELECT username FROM prefix_user WHERE id = t.userid),')')
END AS "Standard"

FROM prefix_tag_instance ti
JOIN prefix_tag t ON t.id = ti.tagid
JOIN prefix_tag_coll tc ON tc.id = t.tagcollid
JOIN prefix_course_modules cm ON cm.id = ti.itemid
JOIN prefix_modules m ON m.id = cm.module

WHERE ti.component = 'core' 
AND (ti.itemtype = 'course' OR ti.itemtype = 'course_modules') 

ORDER BY 1,2,3,4,5

Learning Analytics Reports

(Moodle v. 3.4 and later)

Learning Analytics Model Summary

This report provides a list of the learning analytics models on your site, whether enabled or not, and several details about them.

(Note: this report was created on a system using PostgreSQL. Some changes may be needed for other forms of SQL.) Contributed by Elizabeth Dalton, Moodle HQ

SELECT
am.id AS "model id",	 
split_part(am.target,'\',5) AS "target",
CASE WHEN am.enabled=1 THEN 'YES' ELSE 'NO' END AS "enabled",	 
CASE WHEN am.trained=1 THEN 'YES' ELSE 'NO' END AS "trained",
am.name,	 
/* indicators,*/
char_length(am.indicators) - char_length(REPLACE(am.indicators,',',''))+1 AS "indicator count",
split_part(am.timesplitting,'\',5) AS "interval",
/*
to_timestamp(am.version) AS "version",	 
to_timestamp(am.timecreated) AS "time created",	 
to_timestamp(am.timemodified) AS "time modified",	
*/
COUNT(DISTINCT ap.contextid) AS "contexts",
COUNT(ap.sampleid) AS "samples",
/* AVG(ap.prediction) AS "avg prediction", */
ROUND(ap.prediction,1) AS "prediction",		   
ROUND(AVG(aml.score),3) AS "model accuracy (avg)",
apa.actionname AS "action",
COUNT(apa.id) AS "number actions taken"
		   
FROM prefix_analytics_models AS am
JOIN prefix_analytics_predictions AS ap ON am.id = ap.modelid
LEFT JOIN prefix_analytics_models_log AS aml ON aml.modelid = am.id
LEFT JOIN prefix_analytics_prediction_actions AS apa ON apa.predictionid = ap.id
GROUP BY am.id, ap.prediction, apa.actionname

Analytics Indicator Calculations

Pulls calculations from the "analytics_indicator_calc" table consisting of all calculations made for each indicator for each sample within each context for every model. In most cases you will want to limit this per context or sample, or at least group by context and sample.

SELECT 
id,	 
to_timestamp(starttime) AS "start time",	 
to_timestamp(endtime) AS "end time",	 
contextid,	 
sampleorigin,	 
sampleid,	 
/*indicator, */
split_part(indicator,'\',2) AS "module",
split_part(indicator,'\',5) AS "indicator type",
value,	 
to_timestamp(timecreated) AS "time created"

FROM prefix_analytics_indicator_calc
WHERE id = 1

Analytics Models

Pulls data from the "analytics_models" table consisting of one row per model. See the "Learning Analytics Model Summary" report, above, for an expanded report that JOINs model data from different tables to provide a more comprehensive view. Contributed by Elizabeth Dalton, Moodle HQ

SELECT
id,	 
enabled,	 
trained, 
name,	 
split_part(target,'\',5) AS "target",
/* indicators,*/
char_length(indicators) - char_length(REPLACE(indicators,',',''))+1 AS "indicator count",
split_part(timesplitting,'\',5) AS "interval",
predictionsprocessor, 
to_timestamp(version) AS "version",	 
to_timestamp(timecreated) AS "time created",	 
to_timestamp(timemodified) AS "time modified",	 
usermodified

FROM prefix_analytics_models


Analytics Models Log

Pulls data from the "analytics_models_log" table consisting of evaluation calculations per model. If model evaluations have not been manually executed on the system from the command line, there will be no contents in this table. Contributed by Elizabeth Dalton, Moodle HQ


SELECT
id,	 
modelid,	 
to_timestamp(version) AS "version",	 
evaluationmode,	 
split_part(target,'\',5) AS "target",	 
/* indicators,*/
char_length(indicators) - char_length(REPLACE(indicators,',',''))+1 AS "indicator count",
split_part(timesplitting,'\',5) AS "interval",	 
score,	 
info,	 
dir,	 
to_timestamp(timecreated) AS "time created",	 
usermodified

FROM prefix_analytics_models_log

Analytics Predictions

Pulls data from the "analytics_predictions" table consisting of one row per prediction per model. Counts the number of indicators calculated for each prediction, but does not list them. If a model has not yet been trained, the system cannot make predictions and this table will not include rows for that model ID. See the "Learning Analytics Model Summary" report, above, for an expanded report that JOINs model data from different tables to provide a more comprehensive view. Contributed by Elizabeth Dalton, Moodle HQ

SELECT 
id,	 
modelid,	 
contextid,	 
sampleid,	 
rangeindex,	 
prediction,	 
predictionscore,	 
char_length(calculations) - char_length(REPLACE(calculations,',',''))+1 AS "indicators calculated",
to_timestamp(timecreated) AS "time created",	 
to_timestamp(timestart) AS "time start",	 
to_timestamp(timeend) AS "time end"

from prefix_analytics_predictions

Analytics Prediction Actions

Pulls data from the "analytics_prediction_actions" table consisting of one row per action taken per prediction (e.g. a teacher viewing the outline report for a student at risk). If the model has not yet made predictions, there can be no prediction actions. See the "Learning Analytics Model Summary" report, above, for an expanded report that JOINs model data from different tables to provide a more comprehensive view. Contributed by Elizabeth Dalton, Moodle HQ

SELECT
id,	 
predictionid,	 
userid,	 
actionname,	 
to_timestamp(timecreated) AS "time created"

FROM prefix_analytics_prediction_actions


Analytics Predictions with All Indicators

Pulls data from the "analytics_predictions" table consisting of one row per prediction per model. Lists the indicators calculated for each prediction. If a model has not yet been trained, the system cannot make predictions and this table will not include rows for that model ID. Contributed by Elizabeth Dalton, Moodle HQ

SELECT 
id AS "Prediction ID",	 
modelid AS "Model ID",	 
contextid AS "Context ID",	 
sampleid AS "Sample ID",	 
rangeindex AS "Analysis Interval",	 
prediction AS "Prediction value",	 
predictionscore,	 
calculations,
char_length(calculations) - char_length(REPLACE(calculations,',',''))+1 AS "indicators calculated",
to_timestamp(timecreated) AS "time created",	 
to_timestamp(timestart) AS "time start",	 
to_timestamp(timeend) AS "time end"

from prefix_analytics_predictions

Analytics Predict Samples

Pulls data from the "analytics_predict_samples" table consisting of one row per analysis interval per model, with a count of the samples used for each prediction. Sample details are not included here, but the report can be modified to list samples by IDs if needed by parsing the contents of the sampleids field. For example, this counts the number of student enrolments for which the system has generated predictions for a given model and analysis interval. Contributed by Elizabeth Dalton, Moodle HQ

SELECT 
id,	 
modelid,	 
analysableid,	 
split_part(timesplitting,'\',5) AS "interval",	 
rangeindex,	 
/* sampleids, */	 
char_length(sampleids) - char_length(REPLACE(sampleids,',',''))+1 AS "samples used",
to_timestamp(timecreated) AS "time created",	 
to_timestamp(timemodified) AS "time modified"

FROM prefix_analytics_predict_samples

Analytics Train Samples

Pulls data from the "analytics_train_samples" table consisting of one row per analysis interval per model, with a count of the samples used for each training calculation. Contributed by Elizabeth Dalton, Moodle HQ

SELECT 
id,	 
modelid,	 
analysableid,	 
split_part(timesplitting,'\',5) AS "interval",
/* sampleids,	*/
char_length(sampleids) - char_length(REPLACE(sampleids,',',''))+1 AS "samples used",
to_timestamp(timecreated) AS "time created"

FROM prefix_analytics_train_samples

Analytics Used Analysables

Pulls data from the "analytics_used_analysables" table consisting of one row per context per model, noting whether the analysable was used to train the model or to make a prediction. This data is used to control the training and prediction processes. Contributed by Elizabeth Dalton, Moodle HQ

SELECT 
id,	 
modelid,	 
action,	 
analysableid,	 
to_timestamp(firstanalysis) AS "first analysis",	 
to_timestamp(timeanalysed) AS "time analysed"

FROM prefix_analytics_used_analysables

Analytics Used Files

Pulls data from the "analytics_used_files" table consisting of one row per file per model, noting whether the file was used to train the model or to make a prediction. This data is used to control the training and prediction processes. Contributed by Elizabeth Dalton, Moodle HQ

SELECT

id,	 
modelid,	 
fileid,	 
action,	 
TO_TIMESTAMP(time) AS Time

FROM prefix_analytics_used_files

Average Cognitive Depth and Social Breadth

Here is a simple SQL snippet to calculate average cognitive depth and social breadth indicators for all students in the system. This one ignores indicator values of 0, as they are nulls as defined in this model. Contributed by Elizabeth Dalton, Moodle HQ

SELECT

i.contextid,
i.sampleid,

TRUNC(AVG(CASE
WHEN i.indicator LIKE '%cognitive%' THEN i.value 
ELSE '0'
END),2) AS "Average Cognitive Depth",

TRUNC(AVG(CASE
WHEN i.indicator LIKE '%social%' THEN i.value 
ELSE '0'
END),2) AS "Average Social Breadth"

FROM prefix_analytics_indicator_calc as i
WHERE
i.value != 0
GROUP BY i.contextid, i.sampleid

Competencies

List of competencies from a framework and the courses including them

Contributed by François Parlant

SELECT 
f.shortname AS 'Framework',
comp.shortname AS 'Competency', 
cccomp.courseid AS 'Course id', 
c.fullname AS 'Course name',
c.shortname AS 'Course code'
FROM 
prefix_competency_coursecomp AS cccomp 
INNER JOIN prefix_competency AS comp ON cccomp.competencyid = comp.id
INNER JOIN prefix_course AS c ON cccomp.courseid = c.id
INNER JOIN prefix_competency_framework AS f ON comp.competencyframeworkid = f.id

Count the courses using each competency from frameworks

Contributed by François Parlant

Unfortunately, there is not a filter by competency framework.

select 
f.shortname AS framework,
comp.shortname AS 'Competency',
COUNT(cccomp.competencyid) AS 'nb course'
FROM prefix_competency AS comp
INNER JOIN prefix_competency_framework AS f ON comp.competencyframeworkid = f.id
LEFT JOIN prefix_competency_coursecomp AS cccomp ON cccomp.competencyid = comp.id
GROUP BY comp.id, comp.shortname


Scale details with ids

Contributed by: Randy Thornton

Competency import and export files include scales with id numbers. However, the management page in Grades > Scales does not have the scale id, nor other useful details that scales store about themselves, like who made them and when, and what context they pertain to. This simple query shows you that information.

SELECT
s.id AS Scaleid,
s.name AS Scale_Name,
s.scale AS Scale,
CASE  
  WHEN s.courseid = 0 THEN 'System'
  ELSE (SELECT shortname FROM prefix_course WHERE id = s.courseid)
END AS Context,
CASE 
  WHEN s.userid = 0 THEN 'System'
  ELSE (SELECT username FROM prefix_user WHERE id = s.userid)
END AS User,
s.description,
DATE_FORMAT( FROM_UNIXTIME(s.timemodified), '%Y-%m-%d %H:%i' ) AS 'Modified'
FROM prefix_scale s

Syllabus

Our school simply asks teachers to drop a file (resource) on their course page and rename this resource (not the file) starting with "syllabus" (case insensitive)

Count the number of resources whose name starts by "Syllabus"

Contributed by François Parlant

Select 
r.name As 'Resource name',
cc.name AS 'Category',
CONCAT('<a href="%%WWWROOT%%/pluginfile.php/', ct.id, '/mod_resource/content/1/', f.filename, '">',f.filename,'</a>') AS 'Clickable filename',

c.fullname AS 'Course name',
c.shortname AS 'Course shortname',

# the date filters are connected to this "last modif" field
# userful to check if the syllabus has been updated this year
DATE_FORMAT(FROM_UNIXTIME(f.timemodified), '%e %b %Y') AS 'last modif', 

# tell if the file is visible by the students or hidden
IF(cm.visible=0,"masqué","visible") AS 'Visibility',

# next line tries to give the real path (local path) if you want to create a zip file using an external script)
# notice that the path is in the column "contenthash" and NOT in the column pathhash
# if the contenthash starts with 9af3... then the file is stored in moodledata/filedir/9a/f3/contenthash
# I try to get the path to moodledata from the value of the geoip variable in the mdl_config table... maybe a bad idea
CONCAT('"',(Select left(value, length(value)-25) from prefix_config where name ="geoip2file"),'/filedir/', left(f.contenthash,2), "/",substring(f.contenthash,3,2),'/', f.contenthash, '"') AS 'link'

FROM prefix_resource AS r
INNER JOIN prefix_course_modules AS cm ON cm.instance = r.id
INNER JOIN prefix_course AS c ON c.id = r.course
INNER JOIN prefix_context AS ct ON ct.instanceid = cm.id
JOIN prefix_course_categories cc ON c.category = cc.id
INNER JOIN prefix_files AS f ON f.contextid = ct.id AND f.mimetype IS NOT NULL AND f.component = 'mod_resource'
WHERE LOWER( r.name) LIKE 'syllabus%'
%%FILTER_STARTTIME:f.timemodified:>%% %%FILTER_ENDTIME:f.timemodified:<%%
%%FILTER_SUBCATEGORIES:cc.path%%

List files which have been tagged "Syllabus"

Contributed by François Parlant

Select 
t.rawname AS 'rawtag',
c.shortname AS 'Cours shortname',
c.fullname AS 'Course name',
r.name As 'Resource name',
CONCAT('<a href="%%WWWROOT%%/pluginfile.php/', ti.contextid, '/mod_resource/content/1/', f.filename, '">cliquez ici</a>') AS 'link',
ti.contextid AS 'Instance for link',
f.id AS 'file id' 
FROM prefix_tag_instance AS ti
INNER JOIN prefix_tag AS t ON ti.tagid = t.id
INNER JOIN prefix_course_modules AS cm ON ti.itemid = cm.id
INNER JOIN prefix_course AS c ON cm.course = c.id
INNER JOIN prefix_resource AS r ON r.id = cm.instance
INNER JOIN prefix_files AS f ON f.contextid = ti.contextid AND f.mimetype IS NOT NULL
WHERE t.rawname = 'Syllabus'

List of courses WITHOUT a resource with a name starting by "syllabus"

Contributed by François Parlant

select c.id, c.shortname,
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', c.id, '">',c.fullname,'</a>') AS 'Course link'
FROM prefix_course AS c
LEFT JOIN (
  Select r.course 
  from prefix_resource AS r
  WHERE LOWER( r.name) LIKE 'syllabus%'
  GROUP BY r.course) AS r ON r.course = c.id
INNER JOIN prefix_course_categories cc ON c.category = cc.id
WHERE r.course IS NULL 
%%FILTER_SUBCATEGORIES:cc.path%%
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.enddate:<%%

List of courses have MULTIPLE resource with a name like "Syllabus%"

Contributed by François Parlant

select 
r.course,
c.shortname,
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', r.id, '">',c.fullname,'</a>') AS 'Course link'
FROM prefix_resource AS r
INNER JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories cc ON c.category = cc.id
WHERE LOWER( r.name) LIKE 'syllabus%'
GROUP BY r.course HAVING count(r.course)>1
%%FILTER_SUBCATEGORIES:cc.path%%

Chat

List the chats

Contributed by François Parlant This report gives the list of all chats with the name of the course and various ids needed for further queries.

The column "participants" is intended to work with an (optional) secondary report. If you don't need it , you can erase it. It produces a direct link to another (optional) report which will give you the current participants list to this chat.

select 
c.shortname,
c.fullname,
ch.course, 
ch.id,
# if you intend to use a secondary report to see the participants of a specific chat
# create the secondary report, check the id of the report in the url, and change the 21 in next line to your participant report's id
CONCAT('<a href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?id=21&filter_courses=', ch.id,'">Chat participants</a>') AS 'Course link',
ch.chattime

FROM
prefix_chat ch
INNER JOIN prefix_course c ON c.id = ch.course

ORDER BY ch.chattime, c.fullname

Participants to a chat (optional secondary report)

This version of the participant list is intended to work with a link given in the previous report.

  • User opens the report listing all the chats on the platform
  • user clicks on the link from the column "chat participant"
  • which open this report with a filter on the chatid

(careful, we are tweaking the coursefilter to carry instead the chatid: the displayed "course filter" will not work! but we need it)

SELECT
c.id AS courseid,
chu.chatid,
chu.userid AS 'chat user userid',
c.fullname,
u.username,
u.firstname,
u.lastname,
u.email
                                
FROM
prefix_user u 
LEFT JOIN prefix_chat_users chu ON chu.userid = u.id
INNER JOIN prefix_course c ON c.id = chu.course

WHERE 1=1
%%FILTER_COURSES:chu.chatid%%
# you can also filter by course
# but don't put comment line between where and filter
# %%FILTER_COURSES:chu.course%%

                                
ORDER BY c.fullname

List current participants to chat

Contributed by François Parlant

SELECT
c.id AS courseid,
chu.chatid,
chu.userid AS 'chat user userid',
c.fullname,
u.username,
u.firstname,
u.lastname,
u.email
                                
FROM
prefix_user u 
LEFT JOIN prefix_chat_users chu ON chu.userid = u.id
INNER JOIN prefix_course c ON c.id = chu.course

WHERE 1=1
%%FILTER_COURSES:chu.course%%
                                
ORDER BY c.fullname

Useful sub queries

IN this section please put any short one purpose sub queries that show how common procedures often useful as part of larger queries.

All teachers in the course

This snippet shows how to get teachers from a course. The contextevel for course objects is 50. And the default Teacher role is role id 3.

,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) ) 
FROM prefix_course ic
JOIN prefix_context con ON con.instanceid = ic.id
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
JOIN prefix_role r ON ra.roleid = r.id
JOIN prefix_user u ON u.id = ra.userid
WHERE r.id = 3 AND ic.id = c.id
GROUP BY ic.id
) AS TeacherNames

Get custom User profile fields for a user

Contributed by: Randy Thornton

This snippet of code shows how to connect a user with their custom profile field data. This will list all users with all custom profile fields and data. Custom profile fields have two tables, one for the definition of the profile field (user_info_field) and its settings, and a separate table to hold the data entered by users (user_info_data).

SELECT u.username, uif.name, uid.data
FROM prefix_user AS u
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
JOIN prefix_user_info_field AS uif ON uid.fieldid = uif.id

If you want to limit it to one of those fields, you can restrict it by shortname of the custom profile field, so:

SELECT u.username, uif.name, uid.data
FROM prefix_user AS u
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
JOIN prefix_user_info_field AS uif ON (uid.fieldid = uif.id AND uif.shortname = 'shortname1')

will show you only the data from the custom profile field with the shortname 'shortname1'.

If you want to do this with two or more custom profile fields, you will need to have a JOIN and table alias for each with a restriction for each profile field shortname. Example:

SELECT u.username, d1.data AS 'Profile One', d2.data As 'Profile Two'
FROM prefix_user u
JOIN prefix_user_info_data d1 ON d1.userid = u.id
JOIN prefix_user_info_field f1 ON d1.fieldid = f1.id AND f1.shortname = 'shortname1'
JOIN prefix_user_info_data d2 ON d2.userid = u.id
JOIN prefix_user_info_field f2 ON d2.fieldid = f2.id AND f2.shortname = 'shortname2'

NOTE: Alternate Method

If you have more than a couple of fields you need to use, then this query may time out or not return data due to too many joins. The limit seems to be around 10 custom profile fields.

Instead you should use an alternate method which uses Subselects for each of the profile fields. Details and sample code are in this forum discussion: https://moodle.org/mod/forum/discuss.php?d=355502#p1434854. A sample of the style is:

SELECT u.username

,(SELECT d1.data FROM prefix_user_info_data d1
 JOIN prefix_user_info_field f1 ON d1.fieldid = f1.id AND f1.shortname = 'shortname1'
 WHERE d1.userid = u.id
) AS thefirstfield

,(SELECT d1.data FROM prefix_user_info_data d1
 JOIN prefix_user_info_field f1 ON d1.fieldid = f1.id AND f1.shortname = 'shortname2'
 WHERE d1.userid = u.id
) AS thesecondfield

FROM prefix_user u

How to use Configurable Reports Date Time Filters

Contributed by: Randy Thornton

In the Configurable Reports block, you can set the Time and Date filter to allow you to pick your report Start date/time and End date/time interactively. This will work on any column in a table that is a timestamp.

Here is a simple example:

SELECT u.username, 
DATE_FORMAT(FROM_UNIXTIME(u.firstaccess),'%Y-%m-%d %H:%i') AS 'FirstAccess',
DATE_FORMAT(FROM_UNIXTIME(u.lastaccess),'%Y-%m-%d %H:%i') AS 'LastAccess'   
FROM prefix_user u

WHERE 1=1
%%FILTER_STARTTIME:u.firstaccess:>%% 
%%FILTER_ENDTIME:u.lastaccess:<%%

1) You will need to replace name of the table and column for the filter to use the time and date column you need for your query. In the example above, it filters on the firstaccess and lastaccess columns in the user table. If you were doing a report on course completion, you might put the timecompleted column, and so forth.

2) You MUST then add the Start / End date filter on the Filters tab of the Report. If you don't, the report will still run, probably, but the filter will be ignored.

Note: the WHERE 1=1 statement is a peculiarity of the filters in Config reports: if you don't have a WHERE statement in your query already, then you must add this dummy WHERE to keep the statement valid. If you already have a WHERE statement in your code, simply add the %%FILTER%% placeholders after it (and before any GROUP or ORDER BY statements.)

See also