Note: You are currently viewing documentation for Moodle 3.11. 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
 
(346 intermediate revisions by 9 users not shown)
Line 1: Line 1:
{{Sitewide reports}}
{{Sitewide reports}}
== Introduction==
=Introduction=


Note: The Moodle Docs wiki software was upgraded substantially in July 2021 and required all query code to be updated for language syntax presentation. I have done that and taken the opportunity to make some updates and cleaning up on this page. For more details, please see the discussion on [https://moodle.org/mod/forum/discuss.php?d=424869 Upgrade of Moodle docs and Ad-hoc reports page]. Thanks, Randy.
===Licensing and Disclaimer===
Disclaimer:
All queries on this page are provided as is. '''You''' are completely responsible for using them and for any and all effects they may have on your site, including any data loss. In the standard wording of the [https://docs.moodle.org/dev/License GNU license] that accompanies all Moodle code, all queries and content here are:
'''distributed in the hope that it will be useful, but WITHOUT ANY WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.'''
Precautions:
* Backup your database before using queries
* Never use a query on a production site, only on a test site
* If you don't know what you are doing, then don't do it
Licensing:
All queries and content here are property of their original copyright holders and are licensed here under the [https://docs.moodle.org/dev/License GNU General Public License].


===Moodle Report Plugins===
===Moodle Report Plugins===
Line 14: Line 35:
You can install and use either of these plugins into your Moodle site for reports. If you are more focused on emailing reports, first look at the Ad-hoc database queries. If you need to share reports with teachers and students in courses, then look at the Configurable Reports plugin.
You can install and use either of these plugins into your Moodle site for reports. If you are more focused on emailing reports, first look at the Ad-hoc database queries. If you need to share reports with teachers and students in courses, then look at the Configurable Reports plugin.


===Table Names and prefix_===
=== Some Technical Notes for Report Users ===
 
====Table Names and prefix_====
 
You will see many of the queries below use "prefix_" to start table names, e.g. prefix_user. This prefix_ is used before table names when you are using either of the two plugins, Ad-hoc reports or Contributed reports. These two plugins replace prefix_ with the actual prefix set in your Moodle configuration config.php file. This is because while the default table prefix is mdl_, when you install Moodle you can designate any prefix you want, so it is customizable.
 
Queries written to be used with either of those two plugins should always have prefix_ to begin all table names instead of the actual prefix.
 
When you use tools outside those two Moodle plugins, such as PhpMyAdmin, Workbench, etc., you have to use the actual table names as they are in the database including the actual prefix set for your own site.
 
Therefore:
* If a query below has "prefix_" in its table names and you want to use that query in a tool such as phpMyAdmin, you will need to replace those with the actual prefix of your site's tables.
* If a query below has "mdl_" or some other prefix in its table names, and you are using that in either of the two Moodle plugins, you will need to replace those explicit prefixes with "prefix_".
 


You will see many of the queries below use "prefix_" to start table names, e.g. prefix_user. This prefix_ is used before table names when you are using either of the two plugins, Ad-hoc reports or Contributed reports. It replaces prefix_ with the actual prefix set in your configuration as it runs.  
You will receive a "'''No explicit prefix'''" error in either of those plugins if you use code with the actual table prefix in it.


This is because while the default table prefix is mdl_, when you install Moodle you can designate any prefix you want and so it is customizable. This value is stored in your site's config.php file. Queries written to be used with either of those two plugins should always have prefix_ to begin all table names instead of the actual prefix. You will receive an "No explicit prefix" error if you use code with the actual table prefix in either of the two plugins.
==== About %%FILTER_ and similar Variables ====


When you use tools outside those two Moodle plugins, such as PhpMyAdmin, Workbench, etc, you have to use the actual table names as they are in the database including the actual prefix set for your own site.
You will see a number of queries with variables in them that start and end with two %% percentage signs, e.g. %%WWWROOT%% and several of them that start with %%FILTER_. Theses variables are specific to one or both of the two Moodle plugins. They are not standard SQL code and will not work in code done in other tools outside of those two plugins.  


Therefore: If a query below has "prefix_" in its table names and you want to use that query in a tool such as phpMyAdmin, you will need to replace those with the actual prefix of your site's tables. If a query below has "mdl_" or some other prefix in its table names, and you are using that in either of the two Moodle plugins, you will need to replace those explicit prefixes with "prefix_".
In addition, while these two plugins do share some of the variable, some only work in one plugin or the other. For example, %%WWWROOT%% works in both; the %%C%%, %%S%% and %%Q%% variables only work in the Ad-hoc database queries plugin; and those starting %%FILTER_ only work in the Configurable Reports plugin. You will receive a syntax error if you use a variable that the plugin does not support.


=== About Dates and Times and DATE_FORMAT() ===
Find more details in the section on Variables below.
 
==== About Date and Time Formatting ====


Dates and times in Moodle are stored internally in the database as [https://en.wikipedia.org/wiki/Unix_time the Unix Epoch timestamp] which is the number of seconds since January 1, 1970 at 00:00 UTC, which in the database will be represented as 0.
Dates and times in Moodle are stored internally in the database as [https://en.wikipedia.org/wiki/Unix_time the Unix Epoch timestamp] which is the number of seconds since January 1, 1970 at 00:00 UTC, which in the database will be represented as 0.


To convert them to "human readable" formats we use everyday, you will need to do that in your query with code. There are numerous examples in the code reports: a search of this page for "FROM_UNIXTIME" will show you how to use and convert the dates. Note that when times are converted into standard date and times from timestamps are in [https://en.wikipedia.org/wiki/Coordinated_Universal_Time UTC format] and you may want to [https://dev.mysql.com/doc/refman/8.0/en/time-zone-support.html convert those to a local time zone]. You use the  
To convert them to "human readable" formats we use everyday, you will need to do that in your query with code. There are numerous examples in the reports on this page: a search of this page for "FROM_UNIXTIME" will show you how to use and convert the dates. Note that when times are converted into standard date and times from timestamps are in [https://en.wikipedia.org/wiki/Coordinated_Universal_Time UTC format] and you may want to [https://dev.mysql.com/doc/refman/8.0/en/time-zone-support.html convert those to a local time zone].
 
The functions [https://dev.mysql.com/doc/refman/8.0/en/date-and-time-functions.html#function_from-unixtime FROM_UNIXTIME] and [https://dev.mysql.com/doc/refman/8.0/en/date-and-time-functions.html#function_date-format DATE_FORMAT] that are common in the reports below are MySQL specific functions, which you can use in MySQL and MariaDB sites.
 
For other version of SQL, you will need to edit such queries to get them to work properly. For Postgres, see the manual page on [https://www.postgresql.org/docs/current/functions-formatting.html Data Type Formatting Functions]. There are a number of examples specific to Postgres among the queries below. For MSSQL, see this documentation at [https://database.guide/how-to-return-the-unix-timestamp-in-sql-server-t-sql/ How to Return the Unix Timestamp in SQL Server]. For Oracle, call Larry Ellison on his yacht and ask why he doesn't have a rocket yet like all the other vainglorious billionaires.
 
There are many [https://en.wikipedia.org/wiki/Date_format_by_country date and time formats used in various countries], but all can be formatted based on the original timestamp value. For a sample in MySQL, you can use the following query to show you the install date of your Moodle site in several formats:
 
<syntaxhighlight lang="sql">
SELECT
l.timecreated AS "Timestamp",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%d/%m/%Y') AS "Common world format",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%m/%d/%Y') AS "US format",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%Y-%m-%d') AS "ISO standard format",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%Y-%m-%d %H:%i') AS "ISO standard format with 24 hour time"
FROM prefix_logstore_standard_log l
WHERE l.id =1
</syntaxhighlight>
 
See the [https://dev.mysql.com/doc/refman/8.0/en/date-and-time-functions.html#function_date-format MySQL documentation for all the possible date formatting options].
 
Note: for timestamps that are 0, this sometimes represents "Never" or "No date" for some fields in Moodle. For example, if a user's first login is 0, that means they have never logged in at all, not that their first log in was January 1, 1970 (since Moodle did not exist yet). If you want to distinguish such dates in your output, you can use a conditional to test for the 0, for example:
 
<syntaxhighlight lang="sql">
IF(u.firstaccess = 0, "Never",DATE_FORMAT(FROM_UNIXTIME(u.firstaccess),'%Y-%m-%d %H:%i')) AS 'FirstAccess',
</syntaxhighlight>
 
which will show "Never" when the timestamp is 0 and the properly formatted date otherwise, allowing you to sort the column easily.
 
==== Standard Logs and Legacy Logs ====
 
The log table is the where events in the system are stored. It is a key table for certain types of reports, especially anything related to system events like logins, accessing pages, creating and deleting objects, changing settings, etc.


The functions FROM_UNIXTIME and DATE_FORMAT are MySQL / MariaDB specific. Many of the queries below are written for MySQL / MariaDB sites and use the [https://dev.mysql.com/doc/refman/8.0/en/date-and-time-functions.html#function_date-format MySQL specific function DATE_FORMAT()].  
Moodle made a major update to the log system in Moodle 2.7 in 2014. The older log format using the table prefix_log are called "Legacy logs" while the current logstore system are called "Standard" logs. Unless your Moodle site was running such logs in the 2.7 and before era, and you for some reason chose not to update to the new log format, then you will be using [https://tracker.moodle.org/browse/MDL-37658 the new log system, with a log table prefix_logstore_standard_log].  


For other version of SQL, you will need to edit such queries to get them to work properly. For Postgres, see the manual page on [https://www.postgresql.org/docs/current/functions-formatting.html Data Type Formatting Functions].
===== Use Standard Log Reports=====
Use [[#LOG_REPORTS|the reports in the Standard Log Reports section below]] for current versions of Moodle unless you are sure you have ancient log data from very old Moodles in your system for some reason.


===Commonly used table aliases===
Since the legacy log table still exists in newer versions of Moodle, these Legacy queries may actually run but will not return results in later versions of Moodle using the new logstore system. You can check this for yourself with the following query on your site, which will show you the 0 count for the empty Legacy log table compared with your active Standard log table:


Over the years, some common conventions have arisen for table aliases. You will see these used often on these pages and if you use them your queries will be easier to read for others. But of course, any legal alias can be used.
<syntaxhighlight lang="sql">
SELECT
(SELECT COUNT(*) FROM prefix_log) AS "Legacy_log",
COUNT(*) AS "Standard log"
FROM prefix_logstore_standard_log
</syntaxhighlight>


* c = prefix_course
=====Finding Old Legacy Log Reports=====
* cat or cc = prefix_course_categories
* cm = prefix_course_modules
* ctx = prefix_context
* e = prefix_enrol
* f = prefix_files
* l or log = prefix_logstore_standard_log
* m = prefix_module
* r = prefix_role
* ra = prefix_role_assignments
* u = prefix_user
* ue = prefix_user_enrolments


===Commonly used constants===
If you wish to find and use queries from this old system, you should search in the Ad-hoc pages for earlier versions of Moodle to find such reports, which will use the table prefix_log or mdl_log. Reports from [https://docs.moodle.org/20/en/ad-hoc_contributed_reports Moodle 2.0] to [https://docs.moodle.org/310/en/ad-hoc_contributed_reports 3.10] will contain such queries.


See the [[#Useful_Constants_and_other_common_items|section below for commonly used constants]] such as role ids, context levels, etc.
All these old queries have been removed from the pages for Moodle 3.11 and newer. If you are the author of one of these old queries, please consider updating your query for current Moodle logstore system and move it into the main Log Reports section of the current Moodle version. Thanks.


===Suggestions for Contributors===
===Suggestions for Contributors===


Everyone and everyone is free to contribute to this page. If you have working queries that you think would be of use to community members, please share them here. The following suggestions would make your contributions more useful.
Everyone is free to contribute to this page. If you have working queries that you think would be of use to community members, please share them here. The following suggestions would make your contributions more useful.


Versioning
====Versioning====


*Only post queries verified to work in the current version of this page for its Moodle version: all Moodle docs pages are specific to one version of Moodle and are rolled over twice yearly at new releases in May and November
*Only post queries verified to work in the current version of this page for its Moodle version: all Moodle docs pages are specific to one version of Moodle and are rolled over twice yearly at new releases in May and November
*Please '''do not''' post versions of queries for old, out-of-support versions (if you want to, use the version page specific to that version, not the current one)
*Please '''do not''' post versions of queries for old, out-of-support versions (if you want to, use the version page specific to that version, not the current one)
*Please remove any query you have written that no longer works in the current version of Moodle: especially in cases of structural changes to tables that render old queries broken (eg changes in the Logs in 2.7, Messaging in 3.6, etc.)
*Please remove any query you have written that no longer works in the current version of Moodle: especially in cases of structural changes to tables that render old queries broken (e.g. changes in the Logs in 2.7, Messaging in 3.6, etc.)


 
====Adding annotations for others====
Considering others


*If you are using a SQL dialect other than MySQL, please note which dialect it is and any specific functions or other quirks present
*If you are using a SQL dialect other than MySQL, please note which dialect it is and any specific functions or other quirks present
Line 73: Line 134:
*If the code includes any non-default, third party plugins, please specifically note that in your description
*If the code includes any non-default, third party plugins, please specifically note that in your description
*If your code includes any domain names, course or user names, or other references specific to your site, consider making those more generic
*If your code includes any domain names, course or user names, or other references specific to your site, consider making those more generic
*Please use English since this is the English version of the Moodle documentation
*If there is a discussion or other information about the query from a forum discussion, feel free to link to that discussion
*If there is a discussion or other information about the query from a forum discussion, feel free to link to that discussion
====Commonly used table aliases====
Over the years, some common conventions have arisen for table aliases. You will see these used often on these reports.
If you use these aliases, then your queries will be easier for others to read. But of course, any legal alias can be used.
* c = prefix_course
* cat or cc = prefix_course_categories
* cm = prefix_course_modules
* ctx or con = prefix_context
* e = prefix_enrol
* f = prefix_files
* l or log = prefix_logstore_standard_log
* m = prefix_module
* r = prefix_role
* ra = prefix_role_assignments
* u = prefix_user
* ue = prefix_user_enrolments
===Other Useful Things===
Please [[ad-hoc_contributed_reports#APPENDIX:_OTHER_USEFUL_THINGS|see the sections at the end of this page]] for other useful things including the database schema, commonly used snippets of code, the Config Reports variables and filters, and other nice things.


----
----


==User and Role Reports==
=The REPORTS=
 
==USER and ENROLMENT Reports==


===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)===
Line 96: Line 185:
</syntaxhighlight>
</syntaxhighlight>


===Detailed ACTIONs for each ROLE (TEACHER, NON-EDITING TEACHER and STUDENT)===
===Student (user) Count in each Course===
<syntaxhighlight lang="sql">
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
</syntaxhighlight>
 
===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).
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
Line 136: Line 214:
</syntaxhighlight>
</syntaxhighlight>


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


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
Line 206: Line 284:
(Replace 123456 near the middle with your courseid)
(Replace 123456 near the middle with your courseid)


===Role assignments on categories===
===Lists "loggedin users" from the last 120 days===
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT id,username,FROM_UNIXTIME(`lastlogin`) as days
concat('<a target="_new" href="%%WWWROOT%%/course/category.php?id=',cc.id,'">',cc.id,'</a>') AS id,
FROM `prefix_user`
concat('<a target="_new" href="%%WWWROOT%%/course/category.php?id=',cc.id,'">',cc.name,'</a>') AS category,
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120
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
</syntaxhighlight>
</syntaxhighlight>


===Permissions Overides on Categories===
''and user count for that same population:''
(By: [http://moodle.org/mod/forum/discuss.php?d=153059#p712834 Séverin Terrier] )
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT rc.id, ct.instanceid, ccat.name, rc.roleid, rc.capability, rc.permission,
SELECT COUNT(id) as Users  FROM `prefix_user`
DATE_FORMAT( FROM_UNIXTIME( rc.timemodified ) , '%Y-%m-%d' ) AS timemodified, rc.modifierid, ct.instanceid, ct.path, ct.depth
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120
FROM `prefix_role_capabilities` AS rc
</syntaxhighlight>
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
</syntaxhighlight>
 
===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] )
<syntaxhighlight lang="sql">
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
</syntaxhighlight>
 
===Lists "loggedin users" from the last 120 days===
<syntaxhighlight lang="sql">
SELECT id,username,FROM_UNIXTIME(`lastlogin`) as days
FROM `prefix_user`
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120
</syntaxhighlight>
 
''and user count for that same population:''
<syntaxhighlight lang="sql">
SELECT COUNT(id) as Users  FROM `prefix_user`
WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120
</syntaxhighlight>


=== Users loggedin within the last 7 days ===
=== Users loggedin within the last 7 days ===
Line 278: Line 316:
AND prefix_user.lastlogin = 0
AND prefix_user.lastlogin = 0
AND prefix_user.lastaccess > 0
AND prefix_user.lastaccess > 0
</syntaxhighlight>
===Log in and Log out history complete for a specific user===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
This query uses the logs to show the complete login and logout history for a particular user. You can use it as the basis for further refining the report. Replace the ## in the WHERE clause below with the id number of the user you wish to see. Warning: as always with queries from the logs, this can take a long time to run and may return more data that the maximum limit allowed.
<syntaxhighlight lang="sql">
SELECT
l.id AS "Log_event_id",
l.timecreated AS "Timestamp",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%Y-%m-%d %H:%i') AS "Time_UTC",
l.action,
u.username,
l.origin,
l.ip
FROM prefix_logstore_standard_log l
JOIN prefix_user u ON u.id = l.userid
WHERE l.action IN ('loggedin','loggedout')
AND l.userid = ##
ORDER BY l.timecreated
</syntaxhighlight>
</syntaxhighlight>


Line 348: Line 408:
</syntaxhighlight>
</syntaxhighlight>


===Special Roles===
===List of users who have been enrolled for more than 4 weeks===
For Moodle 2.2, by  Isuru Madushanka Weerarathna
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT ra.roleid,r.name
SELECT uenr.userid As User, IF(enr.courseid=uenr.courseid ,'Y','N') As Enrolled,
,concat('<a target="_new" href="%%WWWROOT%%/course/user.php?id=1&user=',ra.userid,'">',u.firstname ,' ',u.lastname,'</a>') AS Username
IF(DATEDIFF(NOW(), FROM_UNIXTIME(uenr.timecreated))>=28,'Y','N') As EnrolledMoreThan4Weeks
,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
</syntaxhighlight>
 
===Courses without Teachers===
Actually, shows the number of Teachers in a course.
<syntaxhighlight lang="sql">
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
</syntaxhighlight>
 
===List of users who have been enrolled for more than 4 weeks===
For Moodle 2.2 , by  Isuru Madushanka Weerarathna
<syntaxhighlight lang="sql">
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
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
</syntaxhighlight>
</syntaxhighlight>


=== List of users with language===
=== 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.


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
Uses: current user's id %%USERID%% and current course's id %%COURSEID%%


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.
And also using a date filter (which can be ignored)


This will show you the language setting for all users:
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.
<syntaxhighlight lang="sql">
SELECT username, lang from prefix_user
</syntaxhighlight>
 
 
This code will change the setting from 'en' to 'en_us' for all users:
NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
UPDATE prefix_user SET lang = 'en_us' WHERE lang = 'en'
SELECT
</syntaxhighlight>
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


To do this for only users who have a particular country set, use this as an example:
FROM prefix_logstore_standard_log as l,
<syntaxhighlight lang="sql">
(SELECT @delta := 0) AS s_init
UPDATE prefix_user SET lang = 'en_us' WHERE country = 'US' AND lang = 'en'
# Change UserID
WHERE l.userid = %%USERID%% AND l.courseid = %%COURSEID%%
%%FILTER_STARTTIME:l.timecreated:>%% %%FILTER_ENDTIME:l.timecreated:<%%
</syntaxhighlight>
</syntaxhighlight>


=== List of users with Authentication ===
===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


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
<syntaxhighlight lang="sql">
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


Sometimes you need to do mass changes of authentication methods. A common case is changing default manual to LDAP.
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


This will show you the Authentication setting for all users:
WHERE attst.acronym = "P"
<syntaxhighlight lang="sql">
AND c.category = INSERT YOUR CATEGORY ID HERE
SELECT username, auth from prefix_user
ORDER BY c.fullname
</syntaxhighlight>
</syntaxhighlight>


NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools.
===Courses without Teachers===
 
Actually, shows the number of Teachers in a course.
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.)
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
UPDATE prefix_user SET auth = 'ldap' WHERE auth = 'manual' AND id > 2
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
</syntaxhighlight>
</syntaxhighlight>


=== Compare role capability and permissions ===
===List of deactivated users in a course===
Compatibility: MySQL and PostgreSQL
List of deactivated users in a specific course


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT DISTINCT mrc.capability
SELECT username, idnumber,
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '1' AND rc.contextid = '1') AS Manager
concat('<a target="_new" href="%%WWWROOT%%/user/profile.php?id=',uu.id,'">',uu.id,'</a>') as userid_and_link,
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '2' AND rc.contextid = '1') AS Course_Creator
firstname, lastname, email, suspended as 'suspended/deactivated: 1'
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '3' AND rc.contextid = '1') AS Teacher
FROM prefix_user_enrolments ue
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '4' AND rc.contextid = '1') AS Assistant_Teacher
JOIN prefix_enrol en ON ue.enrolid = en.id
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '5' AND rc.contextid = '1') AS Student
JOIN prefix_user uu ON uu.id = ue.userid
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '6' AND rc.contextid = '1') AS Guest
WHERE en.courseid = 1234567
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '7' AND rc.contextid = '1') AS Authenticated
AND suspended = 1
,(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
</syntaxhighlight>
</syntaxhighlight>


=== 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%%
===All users individual timezone settings===


And also using a date filter (which can be ignored)
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


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.
If you allow users to set their own time zones, this can sometimes lead to confusion about due dates and times for assignments. This shows all active users with their personal time zone settings if any.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT  
l.id,
u.username,  
l.timecreated,
IF(u.timezone=99,"-Site Default-",u.timezone) AS "User Timezone"
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%d-%m-%Y') AS dTime,
FROM prefix_user u
@prevtime := (SELECT max(timecreated) FROM mdl_logstore_standard_log
WHERE u.deleted = 0
WHERE userid = %%USERID%% and id < l.id ORDER BY id ASC LIMIT 1) AS prev_time,
ORDER BY u.timezone DESC
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:<%%
</syntaxhighlight>
</syntaxhighlight>


=== Low-Participation Student Report ===
== ROLES and PERMISSIONS REPORTS==
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.


===Count all Active Users by Role in a course category (including all of its sub-categories)===
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
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
SELECT COUNT(DISTINCT l.userid) as active
 
FROM mdl_course as c
FROM prefix_user AS u
JOIN mdl_context AS ctx ON  ctx.instanceid=c.id
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
JOIN mdl_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN mdl_user_lastaccess as l ON ra.userid = l.userid
JOIN prefix_course AS c ON c.id = ctx.instanceid
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
</syntaxhighlight>


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
===Role assignments on categories===
AND ctx.instanceid = c.id
<syntaxhighlight lang="sql">
AND c.visible=1
SELECT
# This prefix filter allows the exclusion of non-online courses at the original institution. Alter this to fit your institution, or remove it.
concat('<a target="_new" href="%%WWWROOT%%/course/category.php?id=',cc.id,'">',cc.id,'</a>') AS id,
AND c.shortname LIKE '%OL-%'
concat('<a target="_new" href="%%WWWROOT%%/course/category.php?id=',cc.id,'">',cc.name,'</a>') AS category,
%%FILTER_CATEGORIES:c.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,
GROUP BY u.idnumber
usr.firstname, usr.username, usr.email
 
FROM prefix_course_categories cc
HAVING Edits < 2
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
</syntaxhighlight>
</syntaxhighlight>


=== Messages of All Users ===
=== Compare role capability and permissions ===
 
Compatibility: MySQL and PostgreSQL
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton].
 
This version of the query has been updated for Moodle 3.6 and above, when the Messaging database structures were revamped and substantially changed. This is a version of this query that has been tested with Moodle 3.10 back to Moodle 3.6. Huge thank you to [https://moodle.org/user/view.php?id=2247767&course=11 Sandy Noe] for testing!


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT DISTINCT mrc.capability
cv.id AS "Conversation_id",
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '1' AND rc.contextid = '1') AS Manager
DATE_FORMAT(FROM_UNIXTIME(me.timecreated), '%Y-%m-%d %H:%i') AS "At",
,(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 CONCAT(firstname,' ',lastname,' (',username,')') FROM prefix_user WHERE id = me.useridfrom) AS 'From',
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '3' AND rc.contextid = '1') AS Teacher
(SELECT
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '4' AND rc.contextid = '1') AS Assistant_Teacher
GROUP_CONCAT(DISTINCT CONCAT(u.firstname ,' ',lastname,' (',username,')'))
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '5' AND rc.contextid = '1') AS Student
FROM prefix_user u
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '6' AND rc.contextid = '1') AS Guest
JOIN prefix_message_conversation_members cvm ON cvm.userid = u.id
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '7' AND rc.contextid = '1') AS Authenticated
WHERE cvm.conversationid = cv.id
,(SELECT 'X' FROM prefix_role_capabilities AS rc WHERE rc.capability = mrc.capability AND rc.roleid = '8' AND rc.contextid = '1') AS Auth_front
AND u.id != me.useridfrom
FROM prefix_role_capabilities AS mrc
GROUP BY cvm.conversationid
</syntaxhighlight>
) 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


===Special Roles===
<syntaxhighlight lang="sql">
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
</syntaxhighlight>
</syntaxhighlight>


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].
Note: for the meaning of the number 6 see [[#Constants_for_permission_levels|the section on Role ids]] below.


(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)
===Permissions Overrides on Categories===
(By: [http://moodle.org/mod/forum/discuss.php?d=153059#p712834 Séverin Terrier] )
<syntaxhighlight lang="sql">
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
</syntaxhighlight>


===List of attendees/students that were marked present across courses===
===All Role Assignments with contexts===
This report will pull all Present students across a specific category.
Contributed by: Emma Richardson


<syntaxhighlight lang="sql">
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
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
This lists all the roles that have been assigned in the site, along with the role shortname and the type of context where it is assigned, e.g. System, Course, User, etc. The last column, the context instance id, is the id number of the particular object where the assignment has been made. So, if the context is course, then the context instance id means the course id; if a category, then the category id, and so forth. So you can then use that number to locate the particular place where the role is assigned.
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"
<syntaxhighlight lang="sql">
AND c.category = INSERT YOUR CATEGORY ID HERE
SELECT
ORDER BY c.fullname
u.username,
r.shortname AS "Role",
CASE ctx.contextlevel
  WHEN 10 THEN 'System'
  WHEN 20 THEN 'Personal'
  WHEN 30 THEN 'User'
  WHEN 40 THEN 'Course_Category'
  WHEN 50 THEN 'Course'
  WHEN 60 THEN 'Group'
  WHEN 70 THEN 'Course_Module'
  WHEN 80 THEN 'Block'
ELSE CONCAT('Unknown context: ',ctx.contextlevel)
END AS "Context_level",
ctx.instanceid AS "Context instance id"
FROM prefix_role_assignments ra
JOIN prefix_user u ON u.id = ra.userid
JOIN prefix_role r ON r.id = ra.roleid
JOIN prefix_context ctx ON ctx.id = ra.contextid
ORDER BY u.username
</syntaxhighlight>
</syntaxhighlight>


===List of deactivated users in a course===
==COURSE REPORTS==
List of deactivated users in a specific course


===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] )
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT username, idnumber,
SELECT
concat('<a target="_new" href="%%WWWROOT%%/user/profile.php?id=',uu.id,'">',uu.id,'</a>') as userid_and_link,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS id,
firstname, lastname, email, suspended as 'suspended/deactivated: 1'
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS 'Course',
FROM prefix_user_enrolments ue
concat('<a target="_new" href="%%WWWROOT%%/enrol/instances.php?id=',c.id,'">Méthodes inscription</a>') AS 'Enrollment plugins',
JOIN prefix_enrol en ON ue.enrolid = en.id
e.sortorder
JOIN prefix_user uu ON uu.id = ue.userid
FROM prefix_enrol AS e, prefix_course AS c
WHERE en.courseid = 1234567
WHERE e.enrol='guest' AND e.status=0 AND e.password='' AND c.id=e.courseid AND c.visible=1
AND suspended = 1
</syntaxhighlight>
 
===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>
</syntaxhighlight>






===List of all private files of users as alias/shortcut to any activity/course===
===Most Active courses===
Lists all files of users that have been linked as "alias/shortcut" to any activity/course
<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>
 
=== Last access time of users to a course ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
This shows all users and their last access time to courses.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
select f.contextid, f.component, f.filearea, f.filename,
SELECT
concat('<a target="_new" href="%%WWWROOT%%/user/view.php?id=',f.userid,'">',f.userid,'</a>') as 'ID and Link to Userprofile',
u.username,  
u.firstname, u.lastname,
c.shortname AS "Course",
f.filesize, f.mimetype, f.source, f.author, f.referencefileid,
DATE_FORMAT(FROM_UNIXTIME(la.timeaccess), '%Y-%m-%d %H:%i') AS "Last access time"
c.instanceid as 'ID from prefix_context',
FROM prefix_user_lastaccess la
cm.id as 'ID from prefix_course_modules',
JOIN prefix_user u ON u.id = la.userid
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',cm.course,'</a>') as kursid_and_link,
JOIN prefix_course c ON c.id = la.courseid
co.fullname,
ORDER BY u.username, c.shortname
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>
</syntaxhighlight>


==Log Activity Reports==
=== Least active or probably empty courses===


=== Logs: All Log Columns ===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


Contributed by: [https://moodle.org/user/profile.php?id=88992 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.
 
This query contains all the columns in the standard log table (as of Moodle 3.11 anyway). You can use this to uncomment the various fields that you want to have in a report. I have uncommented a few commmon columns (id, action, target, userid, courseid, etc) so you can see how it works as well as adding some useful things such as grabbing user and course names, formatting times, etc. Note also: when commenting and uncomment near the end, be sure to take care with your final commas :)
 
'''WARNING:''' Do NOT use this query as is on the live site unless you are sure you know what you are doing! Logs can get really big and a log query could take a long time to run. Always add something to the WHERE clause or use other means to limit the results to what you really need.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
l.id,
c.fullname,
# l.eventname,
CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'CourseLink',
# l.component,
DATE_FORMAT(FROM_UNIXTIME(c.timecreated), '%Y-%m-%d %H:%i') AS 'Timecreated',
l.action,
DATE_FORMAT(FROM_UNIXTIME(c.timemodified), '%Y-%m-%d %H:%i') AS 'Timemodified',
l.target,
CASE
# l.objecttable,
  WHEN c.timecreated = c.timemodified THEN '-1'
# l.objectid,
  ELSE DATEDIFF(FROM_UNIXTIME(c.timemodified),FROM_UNIXTIME(c.timecreated))
# l.crud,
END AS 'DateDifference',
# l.edulevel,
COUNT(ue.id) AS Enroled
# l.contextid,
FROM prefix_course AS c
# l.contextlevel,
JOIN prefix_enrol AS en ON en.courseid = c.id
# l.contextinstanceid,
LEFT JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
l.userid,
WHERE DATEDIFF(FROM_UNIXTIME(c.timemodified),FROM_UNIXTIME(c.timecreated) ) < 60
# (SELECT username FROM prefix_user WHERE id = l.userid) As "User" ,
GROUP BY c.id
l.courseid,
HAVING COUNT(ue.id) <= 3
# CASE l.courseid
ORDER BY c.fullname
# WHEN 0 THEN 'Not logged in'
#  WHEN 1 THEN 'Front page'
# ELSE (SELECT shortname FROM prefix_course WHERE id = l.courseid)
# END AS "Course_Name" ,
# l.relateduserid,
# (SELECT username FROM prefix_user WHERE id = l.relateduserid) As "Related_User" ,
# l.anonymous,
# l.other,
# l.timecreated,
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%Y-%m-%d %H:%i') AS "Time_UTC"
# l.origin,
# l.ip,
# l.realuserid
 
FROM prefix_logstore_standard_log l
# you really want to add a WHERE clause to limit your results to your specific object to look for eg course, user, time frame etc
# WHERE something = something
 
# Sorting: TIP - time created seems more accurate than id oddly for the actual sequencing due to the way the events are logged
ORDER BY l.timecreated
</syntaxhighlight>
</syntaxhighlight>


===Count all Active Users by ROLE in a course category (including all of its sub-categories)===
===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.
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT COUNT(DISTINCT l.userid) as active
SELECT COUNT(*)
FROM mdl_course as c
FROM (SELECT c.id AS CourseID, c.fullname AS Course, ra.roleid AS RoleID, CONCAT(u.firstname, ' ', u.lastname) AS Teacher
JOIN mdl_context AS ctx ON ctx.instanceid=c.id
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = c.id) AS Modules
JOIN mdl_role_assignments AS ra ON ra.contextid = ctx.id
FROM prefix_course AS c
JOIN mdl_user_lastaccess as l ON ra.userid = l.userid
JOIN prefix_context AS ctx ON c.id = ctx.instanceid AND ctx.contextlevel = 50
JOIN mdl_course_categories AS cats ON c.category = cats.id
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
WHERE c.category=cats.id AND (
JOIN prefix_user AS u ON u.id = ra.userid
cats.path LIKE '%/80/%'
JOIN prefix_course_categories AS cc ON cc.id = c.category
OR cats.path LIKE '%/80'
WHERE ra.roleid = 3
)
GROUP BY u.id
AND ra.roleid=3 AND ctx.contextlevel=50  #ra.roleid= TEACHER 3, NON-EDITING TEACHER 4, STUDENT 5
HAVING Modules > 5) AS ActiveTeachers
AND  l.timeaccess > (unix_timestamp() - ((60*60*24)*NO_OF_DAYS)) #NO_OF_DAYS change to number
</syntaxhighlight>
</syntaxhighlight>


===Detailed "VIEW" ACTION for each ROLE (TEACHER,NONE-EDITING TEACHER and STUDENT)===
===Resource count for each Course===
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT l.action, count( l.userid ) as counter , r.name
SELECT COUNT(l.id) count, l.course, c.fullname coursename
FROM `prefix_log` as l
FROM prefix_resource l INNER JOIN prefix_course c on l.course = c.id
JOIN `prefix_role_assignments` AS ra on l.userid = ra.userid
GROUP BY course
JOIN `prefix_role` AS r ON ra.roleid = r.id
ORDER BY count DESC
WHERE (ra.roleid IN (3,4,5)) AND (l.action LIKE '%view%' )
GROUP BY roleid,l.action
order by r.name,counter desc
</syntaxhighlight>
</syntaxhighlight>


===Total Activity of Roles:"Teacher" and "None-Editing Teacher" by Dates and by Hours===
===Common resource types count for each Category===
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.


<syntaxhighlight lang="sql">
Query but for Moodle2+
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>


===How many LOGINs per user and user's Activity===
+ link username to a user activity graph report
<syntaxhighlight lang="sql">
<syntaxhighlight lang="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
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category,
,count(*) as logins
mcc.path,
,(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]
(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,


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(*)
 
FROM prefix_folder AS f
<syntaxhighlight lang="sql">
JOIN prefix_course AS c ON c.id = f.course
SELECT
JOIN prefix_course_categories AS cc ON cc.id = c.category
COUNT(DISTINCT l.userid) AS 'DistinctUserLogins',
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%M') AS 'Month'
) AS FOLDERs,
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>


===Total activity per course, per unique user on the last 24h===
(SELECT COUNT(*)
<syntaxhighlight lang="sql">
FROM prefix_page AS p
SELECT
JOIN prefix_course AS c ON c.id = p.course
    COUNT(DISTINCT userid) AS countUsers
JOIN prefix_course_categories AS cc ON cc.id = c.category
  , COUNT(l.courseid) AS countVisits
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
  , CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">', c.fullname, '</a>') AS Course
) AS PAGEs,


FROM mdl_logstore_standard_log AS l
(SELECT COUNT(*)
  JOIN mdl_course AS c ON c.id = l.courseid
FROM prefix_book AS b
WHERE l.courseid > 0
JOIN prefix_course AS c ON c.id = b.course
      AND FROM_UNIXTIME(l.timecreated) >= DATE_SUB(NOW(), INTERVAL 1 DAY)
JOIN prefix_course_categories AS cc ON cc.id = c.category
      AND c.fullname LIKE '%תשעו%'
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
GROUP BY l.courseid
) AS BOOKs,
ORDER BY countVisits DESC
</syntaxhighlight>


===Weekly Instructor Online Participation===
(SELECT COUNT(*)
Contributed by Elizabeth Dalton, Granite State College
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,


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 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


* To specify a subject and/or course number, use % as a wildcard, e.g. ARTS% or ARTS501%
FROM prefix_course_categories AS mcc
* To match part of a last name, use %, e.g. Smi% will match "Smith", "Smile", etc.
ORDER BY mcc.path
</syntaxhighlight>


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.
===Detailed Resource Count by Teacher in each course===


'''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.
Including (optional) filter by: year, semester and course id.
 
'''Note''': This version uses legacy (pre-2.7) logs. See below for post-2.7 Standard Logs version.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS CourseID
c.shortname AS CourseID
, c.id
, cc.name AS Category
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor
  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( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
, (CASE
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
WHEN c.fullname LIKE '%תשעב%' THEN '2012'
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students
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


, c.startdate AS Course_Start_Date
FROM `prefix_resource` as r
JOIN `prefix_course` AS c on c.id = r.course
#WHERE type= 'file' and reference NOT LIKE 'http://%'


, c.visible AS Visible
#WHERE 1=1
#%%FILTER_YEARS:c.fullname%%
#AND c.fullname LIKE '%2013%'


COUNT(l.id) AS Edits
GROUP BY course
ORDER BY COUNT(c.id) DESC
</syntaxhighlight>
 
===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...
<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>


, SUM(IF(WEEK(FROM_UNIXTIME(l.time)) - WEEK(FROM_UNIXTIME(c.startdate))<0,1,0)) AS BeforeTerm
===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.


, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=0,1,0)) AS Week1
$s should be the id of the top level category you are interested in.
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=1,1,0)) AS Week2
<syntaxhighlight lang="php">
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=2,1,0)) AS Week3
<?php
, 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
require_once('./config.php');


, 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
$parent_id = $s;


FROM prefix_user AS u
$categories= array();
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%"
$categories = get_categories($parent_id);


WHERE ra.roleid =3
echo '<ol>';
AND ctx.instanceid = c.id
foreach ($categories as $category)
AND c.shortname LIKE :course
        {
AND u.lastname LIKE :last_name
        echo '<li><a href="'.$CFG->wwwroot.'/course/category.php?id='.$category->id.'">'.$category->name.'</a></li>';
        }
echo '</ol>';


GROUP BY u.idnumber, c.id
?>
HAVING students > 0
ORDER BY c.shortname
</syntaxhighlight>
</syntaxhighlight>


'''Note''': Post-2.7 log version:
===All teachers and courses===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
* not taking into account the END DATE


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT  
c.shortname AS CourseID
c.id, c.shortname
, cc.name AS Category
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', c.id, '">',c.fullname,'</a>') AS 'Course link',
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor
u.id as 'prof id',
u.username, u.firstname, u.lastname, r.shortname as 'role'
From prefix_user as u
join prefix_user_enrolments ue on ue.userid=u.id
join prefix_enrol en on ue.enrolid=en.id
join prefix_role_assignments ra on u.id=ra.userid
join prefix_role r on ra.roleid=r.id and (r.shortname ='editingteacher' or r.shortname ='teacher')
join prefix_context cx on cx.id = ra.contextid and cx.contextlevel = 50
JOIN prefix_course c ON c.id = cx.instanceid AND en.courseid = c.id
JOIN prefix_course_categories cc ON c.category = cc.id
WHERE 1=1
%%FILTER_SUBCATEGORIES:cc.path%%
%%FILTER_STARTTIME:c.startdate:>%%
</syntaxhighlight>


, (SELECT COUNT( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
===All courses without an END DATE===
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students


, FROM_UNIXTIME(c.startdate) AS Course_Start_Date
<syntaxhighlight lang="sql">
select c.id, c.fullname, c.shortname,
-- c.startdate, c.enddate,
FROM_UNIXTIME(c.startdate,'%d/%m/%Y') as "Date début",
FROM_UNIXTIME(c.enddate,'%d/%m/%Y') as "Date fin",
CONCAT('<a href="https://pedago-msc.campusonline.me/course/view.php?id=', c.id,'">voir cours</a>') AS 'lien cours',
CONCAT('<a href="https://pedago-msc.campusonline.me/user/index.php?id=', c.id,'">voir participants</a>') AS 'lien participants'
FROM prefix_course  AS c
INNER JOIN prefix_course_categories cc ON c.category = cc.id
WHERE c.enddate = 0
%%FILTER_CATEGORIES:c.path%%
%%FILTER_SUBCATEGORIES:cc.path%%
%%FILTER_STARTTIME:c.startdate:>%%
</syntaxhighlight>


, c.visible AS Visible
===All Courses which uploaded a Syllabus file===
+ under specific Category
+ show first Teacher in that course
+ link Course's fullname to actual course


,  COUNT(DISTINCT l.id) AS Edits


, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
<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>


, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
===List all courses WITHOUT Syllabus===
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
* courses without ressource with name starting by "syllabus" (using upper case or lower case)
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
* display the name as a direct link
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
* shows the name of teacher
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
* category with sub category filter
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
* start date and end date filters
, 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'
<syntaxhighlight lang="sql">
SELECT c.id as 'id cours',
c.shortname, CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', c.id, '">',c.fullname,'</a>') AS 'Course link',
u.id, u.username, u.firstname, u.lastname, r.shortname as 'role'
FROM prefix_user as u
JOIN prefix_user_enrolments ue on ue.userid=u.id
JOIN prefix_enrol en on ue.enrolid=en.id
JOIN prefix_role_assignments ra on u.id=ra.userid
JOIN prefix_role r on ra.roleid=r.id and (r.shortname ='editingteacher' or r.shortname ='teacher')
JOIN prefix_context cx on cx.id = ra.contextid and cx.contextlevel = 50
JOIN prefix_course c ON c.id = cx.instanceid AND en.courseid = c.id
JOIN prefix_course_categories cc ON c.category = cc.id
WHERE c.id Not in (
  SELECT distinct(r.course)
  FROM prefix_resource AS r
  WHERE LOWER( r.name) LIKE 'syllabus%'
  GROUP BY r.course)
%%FILTER_SUBCATEGORIES:cc.path%%
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.enddate:<%%
</syntaxhighlight>


, 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
===Count the number of resources whose name starts by "Syllabus"===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]


FROM prefix_user AS u
Our school simply asks teachers to drop a file (resource) on their course page
LEFT JOIN prefix_role_assignments AS ra ON u.id = ra.userid
and rename this resource (not the file) starting with "syllabus" (case insensitive)
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')
<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',


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


GROUP BY u.idnumber, c.id
# the date filters are connected to this "last modif" field
#HAVING students > 0
# userful to check if the syllabus has been updated this year
ORDER BY RIGHT(c.shortname,2), c.shortname
DATE_FORMAT(FROM_UNIXTIME(f.timemodified), '%e %b %Y') AS 'last modif',
</syntaxhighlight>


===Weekly Student Online Participation===
# tell if the file is visible by the students or hidden
Contributed by Elizabeth Dalton, Granite State College
IF(cm.visible=0,"masqué","visible") AS 'Visibility',


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).
# 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'


Links to three other reports are also provided:
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>


* Logs: complete log entries for the student in the course, organized by date
===List files which have been tagged "Syllabus"===
* Activity Outline: the "Outline Report" from the User Activity Reports, summarizing the student's activity in the course, organized by course content
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
* 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.
<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>


'''Note''': This version of the report uses legacy (pre-2.7) logs. See below for a post-2.7 Standard Logs version.
===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]
* without teachers


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
select c.id, c.shortname,
u.lastname AS 'Last Name'
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', c.id, '">',c.fullname,'</a>') AS 'Course link'
, u.firstname AS 'First Name'
FROM prefix_course AS c
,  COUNT(l.id) AS 'Edits'
INNER JOIN prefix_course_categories cc ON c.category = cc.id
 
WHERE r.course NOT IN (
, SUM(IF((l.time-c.startdate)/7<0,1,0)) AS 'Before Term'
  Select r.course
 
  from prefix_resource AS r
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=0,1,0)) AS 'Week 1'
  WHERE LOWER( r.name) LIKE 'syllabus%'
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=1,1,0)) AS 'Week 2'
  GROUP BY r.course)  
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=2,1,0)) AS 'Week 3'
%%FILTER_SUBCATEGORIES:cc.path%%
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=3,1,0)) AS 'Week 4'
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.enddate:<%%
, SUM(IF(FLOOR((l.time - c.startdate)/(60*60*24*7))=4,1,0)) AS 'Week 5'
</syntaxhighlight>
, 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'
===List of courses have MULTIPLE resource with a name like "Syllabus%"===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]


, 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'
<syntaxhighlight lang="sql">
 
select
, 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'
r.course,
 
c.shortname,
FROM prefix_user AS u
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', r.id, '">',c.fullname,'</a>') AS 'Course link'
JOIN prefix_role_assignments AS ra ON u.id = ra.userid
FROM prefix_resource AS r
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
INNER JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories cc ON c.category = cc.id
JOIN prefix_course_categories as cc ON c.category = cc.id
WHERE LOWER( r.name) LIKE 'syllabus%'
 
GROUP BY r.course HAVING count(r.course)>1
LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id  AND l.action NOT LIKE "view%"
%%FILTER_SUBCATEGORIES:cc.path%%
 
WHERE ra.roleid =5
AND ctx.instanceid = c.id
 
AND c.id = %%COURSEID%%
 
GROUP BY u.idnumber
 
ORDER BY u.lastname, u.firstname
</syntaxhighlight>
</syntaxhighlight>


'''Note''': Post-2.7 (Standard Logs) version
===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">
<syntaxhighlight lang="sql">
SELECT
SELECT
u.lastname AS 'Last Name'
user.firstname AS Firstname,
, u.firstname AS 'First Name'
user.lastname AS Lastname,
, COUNT(l.id) AS 'Edits'
user.idnumber Employee_ID,
course.fullname AS Course


, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
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


, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
WHERE user.id NOT IN (
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
SELECT u.id
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
FROM prefix_course AS c
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=5,l.id,NULL)) AS 'Week 6'
JOIN prefix_role AS r ON r.id = ra.roleid
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=6,l.id,NULL)) AS 'Week 7'
JOIN prefix_user AS u ON u.id = ra.userid
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=7,l.id,NULL)) AS 'Week 8'
WHERE c.id=course.id
, 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'
ORDER BY Course, Lastname, Firstname
, 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'
</syntaxhighlight>


# Our institution stores academic advisor names and emails in custom profile fields
===List course resources accumulative file size and count===
#, CONCAT('<a href="mailto:',uce.data,'">',uid.data, '</a>') AS 'Academic Advisor'
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"


, 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'
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>


, 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'
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.
<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


, 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 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
                          )
                )
</syntaxhighlight>


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


FROM prefix_user AS u
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!)
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
<syntaxhighlight lang="sql">
# LEFT JOIN prefix_user_info_data as uid ON u.id = uid.userid AND uid.fieldid = '2'
SELECT id, format,
# student academic coach email
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">', c.fullname,'</a>') AS Course
# 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')
,(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"


WHERE ra.roleid =5
FROM mdl_course AS c
AND ctx.instanceid = c.id
</syntaxhighlight>
 
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)
<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>


AND c.id = %%COURSEID%%
===Hidden Courses with Students Enrolled===
Contributed by Eric Strom


GROUP BY u.idnumber
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).


ORDER BY u.lastname, u.firstname
<syntaxhighlight lang="sql">
</syntaxhighlight>
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,


===My Weekly Online Participation===
(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
Contributed by Elizabeth Dalton, Granite State College
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students,


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).
(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,


This report uses Standard Logs (post 2.7).
(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',


<syntaxhighlight lang="sql">
now() AS Report_Timestamp
SELECT


l.component AS 'activity'
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
</syntaxhighlight>


, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
=== Course formats used on my system ===


, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
<syntaxhighlight lang="sql">
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
SELECT COUNT(*) 'Count', c.format 'Format'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=2,l.id,NULL)) AS 'Week 3'
FROM prefix_course AS c
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
GROUP BY c.format
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=4,l.id,NULL)) AS 'Week 5'
</syntaxhighlight>
, 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'
=== Course catalogue with future courses  ===


, COUNT(l.id) AS 'Total'
<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>


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')
===Enrolment methods used in all courses===


WHERE 1
List of all the enrolment methods attached to all courses with their type, enabled status, sort order, and custom name if any. Includes a link directly the each course's enrolment methods settings page. Known to work in 3.11 (should work in most earlier version.) This report could serve as the basis and be easily expanded to show the various settings details for the methods if you want.  
AND ctx.instanceid = c.id


AND c.id = %%COURSEID%%
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
AND u.id = %%USERID%%


GROUP BY l.component
<syntaxhighlight lang="sql">
SELECT
CONCAT('<a target="_new" href="%%WWWROOT%%/enrol/instances.php?id=',c.id,'">',c.shortname,'</a>') AS "Course",
e.enrol AS "Method",
CASE e.status
  WHEN 0 THEN 'Enabled'
  WHEN 1 THEN '-'
  ELSE e.status
END AS "Status",
IF(e.name IS NOT NULL,e.name,'-') AS "Custom name"


ORDER BY l.component
FROM prefix_enrol e
JOIN prefix_course c ON c.id = e.courseid
ORDER BY c.shortname,e.sortorder
</syntaxhighlight>
</syntaxhighlight>


===Faculty/Student Interactions===
== GROUP REPORTS==
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.
=== List course group mode settings===


'''Note''': This should be defined as a "Global" report (visible from within all courses).
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


'''Note''': This report can take a long time to run.
Every course has a group mode set in the course settings. The options are stored in prefix_course.groupmode, where
* 0 = No groups
* 1 = Separate groups
* 2 = Visible groups


The Group mode forced setting is in prefix_course.groupmodeforce and is 0 for off and 1 for on. The following query will show you these settings for all courses.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
c.shortname AS "Course",
CASE c.groupmode
WHEN 0 THEN "No groups"
WHEN 1 THEN "Separate groups"
WHEN 2 THEN "Visible groups"
ELSE "This should not happen!"
END AS "Group mode",
IF(c.groupmodeforce=0, "Not forced","Forced") AS "Group mode forced"
FROM prefix_course c
ORDER BY c.shortname
</syntaxhighlight>


# Identify student
===Courses that are defined as using Groups===
CONCAT('<a target="_blank" href="%%WWWROOT%%/message/index.php?id=' , allstu.id , '">' , allstu.firstname , ' ' , allstu.lastname , '</a>' ) AS 'Student - click to send message'
<syntaxhighlight lang="sql">
 
SELECT concat('<a target="_new" href="%%WWWROOT%%/group/index.php?id=',c.id,'">',c.fullname,'</a>') AS Course
, 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'
,(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
</syntaxhighlight>


, 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'
===Courses with Groups===


## Only posts within last 7 days
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


# Count posts by student
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.
, 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
<syntaxhighlight lang="sql">
, COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Instr Replies - 7 days'
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
</syntaxhighlight>


# using link back to student posts on replies, get unique student IDs responded
===Users enrolled in a course with groups but not assigned a group ===
, 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
Displays by course all enrolled users that have not been assigned a group in courses that have groups. NOTE: This needs to be optimized.
, 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
<syntaxhighlight lang="sql">
, COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL)) AS 'Assign Submit - 7 days'
SELECT DISTINCT
, COUNT(DISTINCT IF(asg.timemodified > (UNIX_TIMESTAMP() - (7*24*60*60)),asg.id,NULL)) AS 'Assign Grades - 7 days'
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


# Messages between students and instructors - 7 days
FROM prefix_course AS course
,  (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'
JOIN prefix_enrol AS en ON en.courseid = course.id
, (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'
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


## All posts in course so far
WHERE ue.enrolid NOT IN (select userid from prefix_groups_members WHERE g.id=groupid)
# Count posts by student
, COUNT(DISTINCT fps.id) AS 'Forum Stu Posts - to date'


# Count replies to student posts by instructors
ORDER BY Course, Lastname
, COUNT(DISTINCT fpi.id) AS 'Forum Instr Replies - to date'
</syntaxhighlight>


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


# all replies
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
, COUNT(DISTINCT fpsr.id) AS 'Forum All Replies - to date'


# add in count of graded assignments - whole course
List the groups in a course (replace the # by the course id number) with the members of each group.
, 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
<syntaxhighlight lang="sql">
, (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 c.shortname, g.name AS Groupname, u.username
, (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'
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>


## JOINS
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>


# Start by getting all the students in the course
===All the Groups I am in in all courses===
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
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
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
This will show all the groups in all courses that the user running the report is a member of. It uses the variable %%USERID%% used by the two Moodle plugins to do this.
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
<syntaxhighlight lang="sql">
# This is a left join, because we don't want to eliminate any students from the list
SELECT
LEFT JOIN prefix_forum_posts AS fpi ON fpi.discussion = fd.id AND fpi.userid = instr.id AND fpi.parent = fps.id
c.shortname AS Course,
g.name AS Groupname
FROM (SELECT userid, groupid FROM prefix_groups_members WHERE userid = %%USERID%%) AS GRU
JOIN prefix_user u ON u.id = GRU.userid
JOIN prefix_groups g ON g.id = GRU.groupid
JOIN prefix_course c ON c.id = g.courseid
# uncomment to limit it to only the current course
WHERE g.courseid = %%COURSEID%%
ORDER BY c.shortname, g.name
</syntaxhighlight>


# To get identities of only those students who were replied to:
===Group Export===
# 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
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
# 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
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.
LEFT JOIN prefix_course_modules AS cm ON c.id = cm.course


# get the assignments
<syntaxhighlight lang="sql">
LEFT JOIN prefix_assign AS a ON  cm.instance = a.id
SELECT g.name AS groupname, g.description, g.enrolmentkey
LEFT JOIN prefix_assign_submission AS asb ON a.id = asb.assignment AND asb.userid=allstu.id
FROM prefix_groups AS g
LEFT JOIN prefix_assign_grades AS asg ON asg.assignment = a.id AND asg.userid = allstu.id AND asg.assignment = asb.assignment
JOIN prefix_course as c ON g.courseid = c.id
WHERE c.id = #
</syntaxhighlight>


# We care about messages that involve both the instructor and students of this course
==COURSE DESIGN REPORTS==
# 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
These are reports which summarize course design aspects, such as activity and resource modules per section, types of activities used, etc.
c.id = %%COURSEID%%


# GROUP BY c.shortname , allstu.id
===Course Content/Week===
GROUP BY allstu.id
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)


ORDER BY allstu.lastname
Totals of each of these types of content elements per section are provided.
</syntaxhighlight>


'''Note''': Post-2.7 Standard Logs version
'''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.


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


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


, 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((gi.id IS NULL) AND (m.name NOT LIKE 'label'),cm.id,NULL)) AS 'Ungraded Resources'


, 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(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'


## Only posts within last 7 days
, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Graded Activities'


# Count posts by student
FROM prefix_course AS c
, COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL)) AS 'Forum Stu Posts - 7 days'
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


# Count replies to student posts by instructors
WHERE
, COUNT(DISTINCT IF(fpi.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpi.id,NULL) ) AS 'Forum Instr Replies - 7 days'
cs.visible = 1
AND cm.visible = 1
AND c.id = %%COURSEID%%


# using link back to student posts on replies, get unique student IDs responded
GROUP BY cs.section
, 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'
ORDER BY cs.section


# all replies
</syntaxhighlight>
, 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
===Assignments and Weights===
, COUNT(DISTINCT IF(asb.timemodified > (UNIX_TIMESTAMP()  - (7*24*60*60)),asb.id,NULL)) AS 'Assign Submit - 7 days'
Contributed by Elizabeth Dalton, Granite State College
, 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
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.
, (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
Categories with weights of 0 are not included in this report.
# Count posts by student
, COUNT(DISTINCT fps.id) AS 'Forum Stu Posts - to date'


# Count replies to student posts by instructors
Only visible activities are included in this report.
, COUNT(DISTINCT fpi.id) AS 'Forum Instr Replies - to date'


# using link back to student posts on replies, get unique student IDs responded
'''Note''': This is designed to be a "Global" report in Configurable Reports.
, COUNT(DISTINCT fpsr.id) - COUNT(DISTINCT fpi.id) AS 'Forum Stu Replies - to date'
<syntaxhighlight lang="sql">
SELECT


# all replies
IF(gc.parent IS NOT NULL, gc.fullname, 'None') AS 'Grade Book Category'
, COUNT(DISTINCT fpsr.id) AS 'Forum All Replies - to date'
, 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'


# add in count of graded assignments - whole course
, CONCAT_WS(', ',GROUP_CONCAT(DISTINCT gi.itemmodule SEPARATOR ', '), IF(mgi.id, 'manual',NULL)) AS 'Activity Types'
, COUNT(DISTINCT asb.id) AS 'Assign Submit - to date'
, COUNT(DISTINCT gi.itemmodule) + IF(mgi.id,1,0) AS 'Different Activity Types'
, COUNT(DISTINCT asg.id) AS 'Assign Grades - to date'
, 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'


# Messages between students and instructors - to date
FROM prefix_course AS c
,  (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
#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))


# Start by getting all the students in the course
# attach activities to course
FROM prefix_user AS allstu
JOIN prefix_course_modules AS cm ON cm.course = c.id
JOIN prefix_role_assignments AS ras ON allstu.id = ras.userid AND ras.roleid = 5
# attach grade items to activities
JOIN prefix_context AS ctx  ON ras.contextid = ctx.id
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
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
# attach manual grade items to course-- they don't have modules
JOIN prefix_forum AS frm ON frm.course = c.id AND c.id = %%COURSEID%%
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual' AND mgi.categoryid = gc.id
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
WHERE
c.id = %%COURSEID%%
cm.visible = 1
AND c.id = %%COURSEID%%


# GROUP BY c.shortname , allstu.id
GROUP BY gc.id
GROUP BY allstu.id
ORDER BY gc.id


ORDER BY allstu.lastname
</syntaxhighlight>
</syntaxhighlight>


===Student Resource Usage===
===Pre-Term Course Review===
Contributed by Elizabeth Dalton, Granite State College
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+.
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:


'''Note''': This should be defined as a "Global" report (visible from within all courses).
#  "Required blocks" include Instructor Block (mooprofile), Activities, and the Research block.
#    "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.
#    All courses should be in the "Collapsed Topics" format with the "Weeks" structure.
#    "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.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS Course
cs.section AS 'Week'
 
, cs.name AS 'Section Name'
#,RIGHT(c.idnumber,2) AS Type # Specific to GSC "Instructional Method" storage
, m.name AS 'item type'
 
#, 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'


, CONCAT(
,(SELECT IF(u3.picture > 0,'YES','NO')
COALESCE(a.name, ''),
FROM prefix_role_assignments AS ra
COALESCE(b.name,''),
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
COALESCE(cert.name,''),
JOIN prefix_user AS u3 ON u3.id = ra.userid
COALESCE(chat.name,''),
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Profile Has Picture'
COALESCE(choice.name,''),
 
COALESCE(data.name,''),
, 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'
COALESCE(feedback.name,''),
#, IF((bpm.visible IS NULL) OR (bpm.visible !=0),'YES','NO') AS 'Messages block visible'
COALESCE(folder.name,''),
#, IF((bpa.visible IS NULL) OR (bpa.visible !=0),'YES','NO') AS 'activities block visible'
COALESCE(forum.name,''),
#, IF((bpr.visible IS NULL) OR (bpr.visible !=0),'YES','NO') AS 'research block visible'
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'


#, 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


, SUM(IF(l.crud IN ('r'),1,0)) AS 'total views'
#, IF(bi.configdata LIKE '%ZGl0IHRoaXMgYmxvY2s%','NO','') AS 'Instructor Details Block Updated' # HTML block has string 'dit this block'
, 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
#, 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
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
, IF(c.format='topcoll','YES', c.format) AS 'Collapsed Topics course format' # change this if you want to test for a different format
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
, IF(cfo.value = 2, 'YES','NO') AS 'weeks structure'
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'
, cfw.value AS 'weeks defined in course settings'
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
, 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'


WHERE ra.roleid =5
, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Activities'
AND ctx.instanceid = c.id
, COUNT(DISTINCT IF(gi.id, cs.id, NULL)) AS 'Weeks with Activities'
AND cs.visible = 1
, COUNT(DISTINCT mgi.id) AS 'Manual Grade Items'
AND cm.visible = 1


AND c.id = %%COURSEID%%
, 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'


GROUP BY cm.id
# 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


ORDER BY cs.section
#,(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
</syntaxhighlight>


===Module activity (Hits) between dates===
#,(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
<syntaxhighlight lang="sql">
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
</syntaxhighlight>


===Module activity (Instances and Hits) for each academic year===
#,(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
<syntaxhighlight lang="sql">
SELECT name


,(SELECT COUNT(*)
#,(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
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(*)
,(SELECT FROM_UNIXTIME(MAX(prefix_resource.timemodified))
FROM prefix_logstore_standard_log AS l
FROM prefix_resource
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2017-10-01 00:00:00' AND '2018-09-31 00:00:00')
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS SyllabusDate
AND l.module = m.name
) AS "Used 2017"


,(SELECT COUNT(*)
,(SELECT TO_DAYS(NOW())-TO_DAYS(FROM_UNIXTIME(MAX(prefix_resource.timemodified)))
FROM prefix_logstore_standard_log AS l
FROM prefix_resource
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2018-10-01 00:00:00' AND '2019-09-31 00:00:00')
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS DaysAgo
AND l.module = m.name AND l.action = 'add'
) AS "Added 2018"


,(SELECT COUNT(*)
, IF(COUNT(DISTINCT IF(f.type LIKE 'news', f.id,NULL)),'YES','NO' ) AS 'Announcement Forum Visible'
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(*)
, IF(COUNT(DISTINCT IF(f.type LIKE 'news', fd.id,NULL)),'YES','NO' ) AS 'Announcement posted'
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')
FROM prefix_course AS c
AND l.module = m.name AND l.action = 'add'
LEFT JOIN prefix_course_categories as cc ON c.category = cc.id
) AS "Added 2019"
LEFT JOIN prefix_context AS ctxx ON c.id = ctxx.instanceid


,(SELECT COUNT(*)
LEFT JOIN prefix_block_positions AS bpi ON bpi.contextid = ctxx.id AND bpi.blockinstanceid = '43692' # mooprofile
FROM prefix_logstore_standard_log AS l
LEFT JOIN prefix_block_positions AS bpm ON bpm.contextid = ctxx.id AND bpm.blockinstanceid = '43962' # messages
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2019-10-01 00:00:00' AND '2020-09-31 00:00:00')
LEFT JOIN prefix_block_positions AS bpa ON bpa.contextid = ctxx.id AND bpa.blockinstanceid = '43963' # activities
AND l.module = m.name
LEFT JOIN prefix_block_positions AS bpr ON bpr.contextid = ctxx.id AND bpr.blockinstanceid = '38368' # html research help
) AS "Used 2019"


FROM mdl_modules AS m
LEFT JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.visible = 1 AND cs.sequence IS NOT NULL
</syntaxhighlight>
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


===Unique user sessions per day and month + graph===
LEFT JOIN prefix_forum AS f ON f.course = c.id AND cm.instance = f.id AND cm.visible = 1
The "graph" column is used when displaying a graph (which needs at least three columns to pick from)
LEFT JOIN prefix_forum_discussions AS fd ON fd.forum = f.id
<syntaxhighlight lang="sql">
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))
</syntaxhighlight>


And...
# 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'


Counting user's global and unique hits per day + counting individual usage of specific activities and resources (on that day),
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'


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_block_instances AS bi ON bi.parentcontextid = ctxx.id AND bi.blockname = 'html' AND (bi.configdata LIKE '%SW5zdHJ1Y3Rvc%' or bi.configdata LIKE '%bnN0cnVjdG9y%')
<syntaxhighlight lang="sql">
LEFT JOIN prefix_block_positions AS bip ON bip.blockinstanceid = bi.id
SELECT DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y-%m-%d") AS "Datez"
 
,COUNT(DISTINCT userid) AS "Unique Users"
WHERE RIGHT(c.idnumber,2) IN ('OL', 'BL', 'HY')
,ROUND(COUNT(*)/10) "User Hits (K)"
# AND substring(cc.path,2,2) IN ('26') # Staging
,SUM(IF(component='mod_quiz',1,0)) "Quizzes"
#AND substring(cc.path,2,3) IN ('158') # UG
,SUM(IF(component='mod_forum' or component='mod_forumng',1,0)) "Forums"
AND cc.idnumber LIKE '%staging%'
,SUM(IF(component='mod_assign',1,0)) "Assignments"
AND ctxx.contextlevel = 50
,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`
GROUP BY c.shortname
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))
</syntaxhighlight>
</syntaxhighlight>


===System wide, daily unique user hits for the last 7 days===
===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.
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
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
c.fullname AS 'fullname'
WHERE l.courseid > 1
, ec.idnumber AS 'elis-id'
      AND FROM_UNIXTIME(l.timecreated) >= DATE_SUB(NOW(), INTERVAL 7 DAY)
, DATE_FORMAT(FROM_UNIXTIME(ec.startdate), '%b %e, %Y') AS 'start'
GROUP BY DAY(FROM_UNIXTIME(timecreated))
, DATE_FORMAT(FROM_UNIXTIME(ec.enddate), '%b %e, %Y') AS 'end'
</syntaxhighlight>
, ecd.name AS 'longname'
, ecd.code AS 'coursecode'
, ecd.credits AS 'coursecredits'
, ecd.syllabus AS 'description'


===User detailed activity in course modules===
, (SELECT  eft.data
Considering only several modules: url, resource, forum, quiz, questionnaire.
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'


<syntaxhighlight lang="sql">
,(SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/user/view.php',CHAR(63),'id=',u.id,'">',u.firstname,' ', u.lastname,'</a> ', u.email)
SELECT u.id, ra.roleid,
FROM prefix_role_assignments AS ra
CONCAT(u.lastname, ' ', u.firstname) AS 'Student'
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
,COUNT(l.id) AS 'Actions'
JOIN prefix_user AS u ON u.id = ra.userid
,l.component "Module type"
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Instructor'
,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
, (SELECT efc.data
JOIN prefix_groups_members AS m ON g.id = m.groupid WHERE g.courseid = l.courseid AND m.userid = u.id) "user_groups"
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 s.name
, (SELECT eft.data
  FROM prefix_course_modules AS cm
FROM prefix_local_eliscore_fld_data_text AS eft
  JOIN prefix_course_sections AS s ON s.course = cm.course AND s.id = cm.section
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'prerequisites'
  WHERE cm.id = l.contextinstanceid) AS "Section name"
WHERE ctxecd.id = eft.contextid) AS 'prerequisites'


FROM prefix_logstore_standard_log AS l
, (SELECT  eft.data
JOIN prefix_user AS u ON u.id = l.userid
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'textbooks'
  AND ra.contextid = (SELECT id FROM prefix_context WHERE instanceid = l.courseid AND contextlevel = 50)
WHERE ctxci.id = eft.contextid) AS 'textbooks'
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
, (SELECT  eft.data
ORDER BY u.lastname, u.firstname
FROM prefix_local_eliscore_fld_data_text AS eft
</syntaxhighlight>
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'


===What teachers and courses considered active?===
, (SELECT  eft.data
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.
FROM prefix_local_eliscore_fld_data_text AS eft
<syntaxhighlight lang="sql">
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'course-policies'
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',
WHERE ctxci.id = eft.contextid) AS 'course-policies'
  course.id,'">',course.fullname,'</a>') AS Course


#,course.shortname
, (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'


,CASE
, (SELECT  eft.data
  WHEN course.fullname LIKE '%2012%' THEN '2012'
FROM prefix_local_eliscore_fld_data_text AS eft
  WHEN course.fullname LIKE '%2013%' THEN '2013'
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'course-methods'
  WHEN course.fullname LIKE '%2014%' THEN '2014'
WHERE ctxci.id = eft.contextid) AS 'course-methods'
  WHEN course.fullname LIKE '%2015%' THEN '2015'
END AS Year


,CASE
,(SELECT u2.description
  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
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 = course.id
JOIN prefix_user AS u2 ON u2.id = ra.userid
) AS Students
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Bio'
 
,(SELECT


,(SELECT COUNT( ra.userid ) AS Users
GROUP_CONCAT(DISTINCT CONCAT(
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
'<tr><td style="border: solid #000 .5px">',IF(gc.parent IS NOT NULL, gc.fullname, 'None')
FROM prefix_role_assignments AS ra
, ' </td><td style="border: solid #000 .5px"> '
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
,IF(gc.parent IS NOT NULL, ROUND(gic.aggregationcoef, 2), ROUND( gi.aggregationcoef, 2)+ROUND(mgi.aggregationcoef, 2))
WHERE ra.roleid = 3 AND ctx.instanceid = course.id
) AS Teachers


# Uncomment to use the new Moodle 2.8+ logstore
) SEPARATOR '</td></tr>')
#,(SELECT COUNT(*) FROM mdl_logstore_standard_log AS l WHERE l.courseid = course.id) AS Hits
#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'


#,(SELECT COUNT(*)
, '<table width = "50%" >' AS 'table start'
#FROM mdl_logstore_standard_log AS l
, '<table width = "100%" >' AS 'table start 2'
#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)
, '</table>' AS 'table end'
#WHERE l.courseid = course.id ) AS "Student HITs"


#,(SELECT COUNT(*)
, (SELECT eft.data
#FROM mdl_logstore_standard_log AS l
FROM prefix_local_eliscore_fld_data_text AS eft
#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)
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'activities-schedule'
#WHERE l.courseid = course.id ) AS "Teacher HITs"
WHERE ctxci.id = eft.contextid) AS 'activities'


,(SELECT COUNT(*) FROM mdl_log AS l WHERE l.course = course.id) AS Hits


,(SELECT COUNT(*)
, (SELECT eft.data
FROM mdl_log AS l
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'schedule'
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 5
WHERE ctxci.id = eft.contextid) AS 'schedule'
WHERE l.course = course.id) AS "Students HITs"


,(SELECT COUNT(*)
, (SELECT eft.data
FROM mdl_log AS l
FROM prefix_local_eliscore_fld_data_text AS eft
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'grading-scale'
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3
WHERE ctxepm.id = eft.contextid) AS 'gradescale'
WHERE l.course = course.id) AS "Teachers HITs"


,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) )
FROM
FROM prefix_course c
prefix_course AS 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
# 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'


,(SELECT COUNT(DISTINCT cm.module) FROM prefix_course_modules cm
# connect ELIS class instance to ELIS course description
  WHERE cm.course = course.id) UniqueModules
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'


,(SELECT GROUP_CONCAT(DISTINCT m.name)
#connect ELIS program to ELIS Course Description
  FROM prefix_course_modules cm
LEFT JOIN prefix_local_elisprogram_pgm_crs AS epc ON epc.courseid = ecd.id
  JOIN mdl_modules as m ON m.id = cm.module
LEFT JOIN prefix_local_elisprogram_pgm AS epm ON epm.id = epc.curriculumid
  WHERE cm.course = course.id) UniqueModuleNames
# course program context
LEFT JOIN prefix_context AS ctxepm ON ctxepm.instanceid = epm.id AND ctxepm.contextlevel = '11'


,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
WHERE
  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
c.id = %%COURSEID%%
  WHERE cm.course = course.id AND m.name IN ( 'oublog') ) "Num Blogs"
</syntaxhighlight>


,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
===Course Activities Helper===
  WHERE cm.course = course.id AND m.name IN ( 'forum', 'forumng') ) "Num Forums"
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.


,(SELECT COUNT(*) FROM prefix_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 ('resource', 'folder', 'url', 'tab', 'file', 'book', 'page') ) Resources
# 303 Course Activities Helper


,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
SELECT
  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
gi.itemmodule AS 'activity type'
  WHERE cm.course = course.id AND m.name IN ('advmindmap', 'assign', 'attendance', 'book', 'choice', 'folder', 'tab', 'glossary', 'questionnaire', 'quiz', 'label' ) ) "Avarage Activities"
# cs.section AS 'section number'


,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
# Calculation assumes each section lasts one week
  WHERE cm.course = course.id AND m.name IN ('elluminate', 'game', 'workshop') ) "Advanced Activities"
, 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'


FROM prefix_course AS course
, gi.itemname AS 'activity name'


#WHERE course.shortname LIKE '%2015%'
#, (SELECT asg.intro FROM prefix_assign AS asg WHERE asg.id = cm.instance) AS 'intro'
#WHERE 1=1
#%%FILTER_SEARCHTEXT:course.shortname:~%%


WHERE course.fullname LIKE '%2015%'
#, (SELECT f.intro FROM prefix_forum AS f WHERE f.id = cm.instance) AS 'f intro'


HAVING Modules > 2
, CASE gi.itemmodule
ORDER BY UniqueModules DESC
WHEN 'assign' THEN (SELECT asg.intro FROM prefix_assign AS asg WHERE asg.id = gi.iteminstance)
</syntaxhighlight>
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'


===Weekly attendance report===
#, (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'
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


WHERE (((arsess.logout) BETWEEN UNIX_TIMESTAMP(DATE_SUB(CURDATE(), INTERVAL 7 DAY)) AND UNIX_TIMESTAMP(CURDATE())))


GROUP BY arsess.userid
FROM
</syntaxhighlight>
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


===How many distinct users connected to Moodle using the app by month===
WHERE
https://moodle.org/mod/forum/discuss.php?d=336086#p1354194 by
c.id = %%COURSEID%%
Iñigo Zendegi Urzelai
AND cs.visible = 1
<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


FROM prefix_logstore_standard_log l
ORDER BY gi.itemmodule, cs.section
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');
</syntaxhighlight>
</syntaxhighlight>


==Course Reports==
==COURSE COMPLETION and GRADE REPORTS==
===Most Active courses===
===Site-Wide Grade Report with All Items===
<syntaxhighlight lang="sql">
Shows grades for all course items along with course totals for each student. Works with ad-hoc reports or Configurable Reports.
SELECT count(l.userid) AS Views
 
FROM `mdl_logstore_standard_log` l, `mdl_user` u, `mdl_role_assignments` r
''Editor Note: This version is for MSSQL server. For MySQL, see below.''
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">
<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
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 CONCAT(u.firstname,' ', u.lastname) AS Teacher
CASE
FROM prefix_role_assignments AS ra
  WHEN gi.itemtype = 'course'
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
  THEN c.fullname + ' Course Total'
JOIN prefix_user AS u ON u.id = ra.userid
  ELSE gi.itemname
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
END AS 'Item Name',


,CASE
ROUND(gg.finalgrade,2) AS Grade,
  WHEN c.fullname LIKE '%תשע' THEN 'תשע'
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
  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
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


,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
WHERE gi.courseid = c.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
ORDER BY lastname
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
</syntaxhighlight>
 
For MySQL users, you'll need to use the MySQL DATE_ADD function instead of DATEADD. Replace the line:
FROM prefix_log l
<syntaxhighlight lang="sql">
INNER JOIN prefix_course c ON l.course = c.id
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
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
</syntaxhighlight>
</syntaxhighlight>
 
with:
=== Least active or probably empty courses===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 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.
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
FROM_UNIXTIME(gg.timemodified) AS Time
c.fullname,
</syntaxhighlight>
CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'CourseLink',
And:
DATE_FORMAT(FROM_UNIXTIME(c.timecreated), '%Y-%m-%d %H:%i') AS 'Timecreated',
<syntaxhighlight lang="sql">
DATE_FORMAT(FROM_UNIXTIME(c.timemodified), '%Y-%m-%d %H:%i') AS 'Timemodified',
u.firstname + ' ' + u.lastname AS 'Display Name',
CASE
</syntaxhighlight>
WHEN c.timecreated = c.timemodified THEN '-1'
with:
ELSE DATEDIFF(FROM_UNIXTIME(c.timemodified),FROM_UNIXTIME(c.timecreated))
<syntaxhighlight lang="sql">
END AS 'DateDifference',
CONCAT(u.firstname,' ',u.lastname) AS 'Display Name',
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>
</syntaxhighlight>
 
And:
===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.
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT COUNT(*)
THEN c.fullname + ' Course Total'
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
</syntaxhighlight>
</syntaxhighlight>
 
with:
===Resource count for each Course===
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT COUNT(l.id) count, l.course, c.fullname coursename
THEN CONCAT(c.fullname,' Course Total')
FROM prefix_resource l INNER JOIN prefix_course c on l.course = c.id
GROUP BY course
ORDER BY count DESC
</syntaxhighlight>
</syntaxhighlight>


===Common resource types count for each Category (Moodle19)===
''Editor Note by Randy Thornton: or in full the MySQL version is:''
Including sub-categories in total count.
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category
SELECT u.firstname AS 'First' ,  
,(SELECT COUNT( * )
u.lastname AS 'Last',
FROM prefix_resource AS r
CONCAT(u.firstname, ' ', u.lastname) AS 'Display Name',
JOIN prefix_course AS c ON c.id = r.course
c.fullname AS 'Course',
JOIN prefix_course_categories AS cc ON cc.id = c.category
cc.name AS '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( * )
CASE
FROM prefix_resource AS r
  WHEN gi.itemtype = 'course'
JOIN prefix_course AS c ON c.id = r.course
  THEN CONCAT(c.fullname, ' Course Total')
JOIN prefix_course_categories AS cc ON cc.id = c.category
  ELSE gi.itemname
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'directory'
END AS 'Item Name',
) AS Folders


,(SELECT COUNT( * )
ROUND(gg.finalgrade,2) AS Grade,
FROM prefix_resource AS r
DATE_FORMAT(FROM_UNIXTIME(gg.timemodified),'%Y-%m-%d') AS Time
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 prefix_course AS c
FROM stats_log_context_role_course
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
WHERE roleid = 5 AND module = 'resource' AND category = mcc.id
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
) AS Hits
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


FROM prefix_course_categories AS mcc
WHERE  gi.courseid = c.id
ORDER BY mcc.path
ORDER BY u.lastname
</syntaxhighlight>
</syntaxhighlight>
Where "stats_log_context_role_course" (in the above SQL query) is a VIEW generated by:
 
===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
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
CREATE VIEW stats_log_context_role_course AS
SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name',
SELECT l.course, c.category, cc.path, l.module, l.action, ra.userid, ra.roleid
cc.name AS 'Category',
FROM prefix_log AS l
CASE
JOIN prefix_context AS context ON context.instanceid = l.course AND context.contextlevel = 50
  WHEN gi.itemtype = 'course'
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid AND ra.contextid = context.id
  THEN c.fullname + ' Course Total'
JOIN prefix_course AS c ON c.id = l.course
  ELSE gi.itemname
JOIN prefix_course_categories AS cc ON cc.id = c.category
END AS 'Item Name',
</syntaxhighlight>


Same query but for Moodle2+
ROUND(gg.finalgrade,2) AS Grade,
<syntaxhighlight lang="sql">
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category,
mcc.path,


(SELECT COUNT(*)
FROM prefix_course AS c
FROM prefix_url AS u
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_course AS c ON c.id = u.course
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_course_categories AS cc ON cc.id = c.category
JOIN prefix_user AS u ON u.id = ra.userid
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
) AS URLs,
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'


(SELECT COUNT(*)
ORDER BY lastname
FROM prefix_folder AS f
</syntaxhighlight>
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(*)
For MySQL users:
FROM prefix_page AS p
<syntaxhighlight lang="sql">
JOIN prefix_course AS c ON c.id = p.course
SELECT u.firstname AS 'First' , u.lastname AS 'Last', CONCAT(u.firstname , ' ' , u.lastname) AS 'Display Name',
JOIN prefix_course_categories AS cc ON cc.id = c.category
c.fullname AS 'Course',
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
cc.name AS 'Category',
) AS PAGEs,
CASE
  WHEN gi.itemtype = 'course'
  THEN CONCAT(c.fullname, ' - Total')
  ELSE gi.itemname
END AS 'Item Name',


(SELECT COUNT(*)
ROUND(gg.finalgrade,2) AS Grade,
FROM prefix_book AS b
FROM_UNIXTIME(gg.timemodified) AS TIME
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 c
FROM prefix_label AS l
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_course AS c ON c.id = l.course
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
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS LABELs,


(SELECT COUNT(*)
WHERE  gi.courseid = c.id AND gi.itemtype = 'course'
FROM prefix_tab AS t
ORDER BY lastname
JOIN prefix_course AS c ON c.id = t.course
</syntaxhighlight>
 
===Learner report by Learner with grades===
Which Learners in which course and what are the grades
<syntaxhighlight lang="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
 
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
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
WHERE gi.courseid = c.id and gi.itemname != 'Attendance'
) AS TABs
ORDER BY `Name` ASC
</syntaxhighlight>
 


FROM prefix_course_categories AS mcc
=== Grades for all students in all courses ===
ORDER BY mcc.path
</syntaxhighlight>


===Detailed Resource COUNT by Teacher in each course===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


Including (optional) filter by: year, semester and course id.
A basic report showing grades for Students in all courses. It has only four columns: username, course shortname, grade, and date, restricted to the standard role of Student. You can use this as the basis for more complex reports.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS CourseID
SELECT  
, c.id
u.username,  
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
c.shortname AS "Course",
  FROM prefix_role_assignments AS ra
ROUND(gg.finalgrade,2) AS "Grade",
  JOIN prefix_user AS u ON ra.userid = u.id
DATE_FORMAT(FROM_UNIXTIME(gg.timemodified), '%Y-%m-%d') AS "Date"
  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
FROM prefix_course AS c
WHEN c.fullname LIKE '%תשעב%' THEN '2012'
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
WHEN c.fullname LIKE '%תשעא%' THEN '2011'
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
END ) as Year
JOIN prefix_user AS u ON u.id = ra.userid
, (CASE
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
WHEN c.fullname LIKE '%סמסטר א%' THEN 'Semester A'
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
WHEN c.fullname LIKE '%סמסטר ב%' THEN 'Semester B'
WHERE gi.courseid = c.id
WHEN c.fullname LIKE '%סמסטר ק%' THEN 'Semester C'
AND gi.itemtype = 'course'
END ) as Semester
# students only role id is 5
,COUNT(c.id) AS Total
AND ra.roleid = 5
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 20) AS TABs
ORDER BY u.username, c.shortname
,(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
</syntaxhighlight>
</syntaxhighlight>


===Users who have not completed a course===


By DKeeler


===List all Courses in and below a certain category===
Reference: https://stackoverflow.com/questions/69544738/sql-ad-hoc-report-of-all-users-not-completed-a-course
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...
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT prefix_course. * , prefix_course_categories. *
SELECT
FROM prefix_course, prefix_course_categories
    u.id AS userid,
WHERE prefix_course.category = prefix_course_categories.id
    u.firstname,
AND (
    u.lastname,
prefix_course_categories.path LIKE '%/$s/%'
    u.idnumber,
OR prefix_course_categories.path LIKE '%/$s'
    u.email
FROM mdl_user u
WHERE u.deleted = 0
AND u.suspended = 0
AND firstname NOT LIKE "Guest user"
AND NOT EXISTS (
    SELECT ue.userid
    FROM mdl_user_enrolments ue
    JOIN mdl_enrol e ON e.id = ue.enrolid AND e.courseid = 123
    WHERE ue.userid = u.id
)
)
ORDER BY
    lastname,
    firstname
</syntaxhighlight>
</syntaxhighlight>


===List all Categories in one level below a certain category===
===Course Completion sitewide for all Users===
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.
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
<syntaxhighlight lang="php">
<?php


require_once('./config.php');
A very simple report with a list of course completion status by username. Completions are noted by date, blank otherwise.


$parent_id = $s;
<syntaxhighlight lang="sql">
SELECT
  u.username,
  c.shortname,
DATE_FORMAT(FROM_UNIXTIME(cp.timecompleted),'%Y-%m-%d') AS completed
FROM prefix_course_completions AS cp
JOIN prefix_course AS c ON cp.course = c.id
JOIN prefix_user AS u ON cp.userid = u.id
WHERE c.enablecompletion = 1
ORDER BY u.username
</syntaxhighlight>


$categories= array();
Another version which includes the start and completed times.
 
$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>';
 
?>
</syntaxhighlight>


===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">
<syntaxhighlight lang="sql">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID
SELECT  
,m.name ,count(cm.id) as counter
u.firstname,
,(SELECT Count( ra.userid ) AS Users
u.lastname,
FROM prefix_role_assignments AS ra
c.shortname AS 'Course',
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
CASE
WHERE ra.roleid = 5
  WHEN cp.timestarted = 0 THEN DATE_FORMAT(FROM_UNIXTIME(cp.timeenrolled),'%Y-%m-%d')
AND ctx.instanceid = c.id
  ELSE DATE_FORMAT(FROM_UNIXTIME(cp.timestarted),'%Y-%m-%d')
) AS Students
END AS 'Started',
, ( SELECT count(id) FROM prefix_log WHERE `module` LIKE '%blog%' AND course = c.id AND action NOT LIKE '%view%' ) as BlogActivity
FROM_UNIXTIME(cp.timecompleted) AS 'Complete'
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)
FROM prefix_user AS u
GROUP BY cm.course,cm.module order by counter desc
JOIN prefix_course_completions AS cp ON cp.userid = u.id
</syntaxhighlight>
JOIN prefix_course c ON c.id = cp.course


===All Courses which uploaded a Syllabus file===
+ under specific Category
+ show first Teacher in that course
+ 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>
</syntaxhighlight>


===User Course Completion with Criteria===


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


 
A report with course completions by username, with Aggregation method, Criteria types, and Criteria detail where available.
===Count the number of resources whose name starts by "Syllabus"===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
 
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)


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
Select
SELECT u.username AS user,
r.name As 'Resource name',
c.shortname AS course,
cc.name AS 'Category',
DATE_FORMAT(FROM_UNIXTIME(t.timecompleted),'%Y-%m-%d') AS completed,
CONCAT('<a href="%%WWWROOT%%/pluginfile.php/', ct.id, '/mod_resource/content/1/', f.filename, '">',f.filename,'</a>') AS 'Clickable filename',
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
 
</syntaxhighlight>


c.fullname AS 'Course name',
===Courses with Completion Enabled and their settings===
c.shortname AS 'Course shortname',


# the date filters are connected to this "last modif" field
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
# 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
List of all courses with completion enabled and their Aggregation setting, Criteria types, and Criteria details.
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)
<syntaxhighlight lang="sql">
# 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
SELECT c.shortname AS Course,
INNER JOIN prefix_course_modules AS cm ON cm.instance = r.id
CASE
INNER JOIN prefix_course AS c ON c.id = r.course
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"
INNER JOIN prefix_context AS ct ON ct.instanceid = cm.id
ELSE "Any"
JOIN prefix_course_categories cc ON c.category = cc.id
END AS Course_Aggregation,
INNER JOIN prefix_files AS f ON f.contextid = ct.id AND f.mimetype IS NOT NULL AND f.component = 'mod_resource'
CASE
WHERE LOWER( r.name) LIKE 'syllabus%'
WHEN t.criteriatype = 1 THEN "Self completion"
%%FILTER_STARTTIME:f.timemodified:>%% %%FILTER_ENDTIME:f.timemodified:<%%
WHEN t.criteriatype = 2 THEN "Date done by"
%%FILTER_SUBCATEGORIES:cc.path%%
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
</syntaxhighlight>
</syntaxhighlight>


===List files which have been tagged "Syllabus"===
===Course Completion Report with custom dates===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
 
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


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
Select
 
t.rawname AS 'rawtag',
SELECT u.username AS 'User Name',
c.shortname AS 'Cours shortname',
CONCAT(u.firstname , ' ' , u.lastname) AS 'Name',
c.fullname AS 'Course name',
c.shortname AS 'Course Name',
r.name As 'Resource name',
DATE_FORMAT(FROM_UNIXTIME(p.timecompleted),'%W %e %M, %Y') AS 'Completed Date',
CONCAT('<a href="%%WWWROOT%%/pluginfile.php/', ti.contextid, '/mod_resource/content/1/', f.filename, '">cliquez ici</a>') AS 'link',
ROUND(c4.gradefinal,2) AS 'Score'
ti.contextid AS 'Instance for link',
FROM prefix_course_completions AS p
f.id AS 'file id'
JOIN prefix_course AS c ON p.course = c.id
FROM prefix_tag_instance AS ti
JOIN prefix_user AS u ON p.userid = u.id
INNER JOIN prefix_tag AS t ON ti.tagid = t.id
JOIN prefix_course_completion_crit_compl AS c4 ON u.id = c4.userid
INNER JOIN prefix_course_modules AS cm ON ti.itemid = cm.id
WHERE c.enablecompletion = AND (p.timecompleted IS NOT NULL OR p.timecompleted !='')
INNER JOIN prefix_course AS c ON cm.course = c.id
AND (p.timecompleted>= :start_date AND p.timecompleted<=:end_date)
INNER JOIN prefix_resource AS r ON r.id = cm.instance
GROUP BY u.username
INNER JOIN prefix_files AS f ON f.contextid = ti.contextid AND f.mimetype IS NOT NULL
ORDER BY c.shortname
WHERE t.rawname = 'Syllabus'
 
</syntaxhighlight>
</syntaxhighlight>


===List of courses WITHOUT a resource with a name starting by "syllabus"===
===Scales used in activities===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
select c.id, c.shortname,
SELECT scale.name
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', c.id, '">',c.fullname,'</a>') AS 'Course link'
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
FROM prefix_course AS c
,CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',gi.itemmodule,'/view.php?id=',cm.id,'">',gi.itemname,'</a>') AS "Module View"
LEFT JOIN (
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/modedit.php?up','date=',cm.id,'">',gi.itemname,'</a>') AS "Module Settings"
  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%"===
FROM prefix_grade_items AS gi
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
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
<syntaxhighlight lang="sql">
JOIN prefix_scale AS scale ON scale.id = gi.scaleid
select
WHERE gi.scaleid IS NOT NULL
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>
</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


FROM prefix_course AS course
===Extra Credit Items by Name Only===
JOIN prefix_enrol AS en ON en.courseid = course.id
Contributed by Eric Strom
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 (
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 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


</syntaxhighlight>
<syntaxhighlight lang="sql">
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


===List course resources accumulative file size and count===
,(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
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.
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
<syntaxhighlight lang="sql">
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
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
,(SELECT COUNT( ra.userid ) FROM prefix_role_assignments AS ra
JOIN mdl_context AS context ON context.id = f.contextid
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN mdl_course AS c ON c.id = (
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Instructors
  SELECT instanceid
  FROM mdl_context
  WHERE id = SUBSTRING_INDEX( SUBSTRING_INDEX( context.path, '/' , -2 ) , '/', 1 ) )
WHERE filesize >0
GROUP BY c.id
</syntaxhighlight>


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.
,(SELECT DISTINCT concat('<a href="mailto:',u.email,'">',u.email,'</a>')
And also setup (add) a FILTER_COURSES filter.
  FROM prefix_role_assignments AS ra
<syntaxhighlight lang="sql">
  JOIN prefix_user AS u ON ra.userid = u.id
SELECT
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
id ,CONCAT('<a target="_new" href="%%WWWROOT%%/pluginfile.php/', contextid, '/', component, '/', filearea, '/', itemid, '/', filename, '">', filename,'</a>') AS "File"
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS 'Instructor_Email'
,filesize, mimetype ,author, license, timecreated, component, filearea, filepath


FROM mdl_files AS f
,now() AS Report_Timestamp
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
                          )
                )
</syntaxhighlight>


===Which courses has redundant topics===
FROM prefix_grade_items AS gi
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).
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


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!)
GROUP BY Course_ID, gi.id
ORDER BY StartDate, Course_ID


<syntaxhighlight lang="sql">
%%FILTER_SEARCHTEXT:Course_ID:~%%
SELECT id, format,
</syntaxhighlight>
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"
===Site Wide Number of Courses Completed by User===
,(SELECT COUNT(*) FROM  `mdl_course_sections` WHERE  `course` = c.id AND `sequence` != '' ) AS "Non empty sections count"
Contributed by Ken St. John
,(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
Simple report that shows the number of completed courses for all users site wide
</syntaxhighlight>


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)
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
REPLACE INTO `mdl_course_format_options` (`id`, `courseid`, `format`, `sectionid`, `name`, `value`)
SELECT u.lastname, u.firstname,
SELECT NULL, c.id, 'onetopic', '0', 'numsections', (SELECT COUNT(*) FROM `mdl_course_sections` WHERE `course` = c.id AND name != '')
COUNT(p.timecompleted) AS TotalCompletions
FROM `mdl_course` c where format = 'onetopic'
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>
</syntaxhighlight>


===Hidden Courses with Students Enrolled===
==ACTIVITY MODULE REPORTS==
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).
Note that specific activity modules each have their own section below, with the Resource modules - book, file, folder, page and url all in one section together. At the end is a section for all third party additional activity modules.


<syntaxhighlight lang="sql">
===General or Multiple Activities===
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
Reports covering multiple or all course modules.  
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
==== User activity completions with dates====
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
WHERE ra.roleid = 3 AND ctx.instanceid = c.id) AS Instructors,


(SELECT DISTINCT concat('<a href="mailto:',u.email,'">',u.email,'</a>')
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_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
</syntaxhighlight>


=== Course formats used on my system ===


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT COUNT(*) 'Count', c.format 'Format'
SELECT
FROM prefix_course AS c
u.username As 'User',
GROUP BY c.format
c.shortname AS 'Course',
</syntaxhighlight>
m.name AS Activitytype,
 
CASE
=== Course catalogue with future courses ===
    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)
<syntaxhighlight lang="sql">
    WHEN m.name = 'book'  THEN (SELECT name FROM prefix_book WHERE id = cm.instance)
SELECT CONCAT('<a href="%%WWWROOT%%/course/info.php?id=',course.id,'">',course.fullname,'</a>') AS Kurs, FROM_UNIXTIME(startdate, '%Y/%m/%d') AS Beginn
    WHEN m.name = 'chat'  THEN (SELECT name FROM prefix_chat WHERE id = cm.instance)
FROM prefix_course AS course
    WHEN m.name = 'choice' THEN (SELECT name FROM prefix_choice WHERE id = cm.instance)
WHERE DATEDIFF(NOW(),FROM_UNIXTIME(startdate)) < 0
    WHEN m.name = 'data'  THEN (SELECT name FROM prefix_data WHERE id = cm.instance)
ORDER BY startdate
    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 Activityname,
# 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
 
</syntaxhighlight>
</syntaxhighlight>


== Course Group Reports==
====System wide use of activities and resources====
 
===Courses that are defined as using Groups===
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT concat('<a target="_new" href="%%WWWROOT%%/group/index.php?id=',c.id,'">',c.fullname,'</a>') AS Course
SELECT count( cm.id ) AS counter, m.name
,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = c.id) Modules
FROM `prefix_course_modules` AS cm
,(SELECT count(*) FROM prefix_groups g WHERE g.courseid = c.id) Groups
JOIN prefix_modules AS m ON cm.module = m.id
FROM `prefix_course` AS c
GROUP BY cm.module
WHERE groupmode > 0
ORDER BY counter DESC
</syntaxhighlight>
</syntaxhighlight>


===Courses with Groups===
====System Wide usage count of various course Activities====
(Tested and works fine in Moodle 2.x)
Like: Forum, Wiki, Blog, Assignment, Database,
#Within specific category
#Teacher name in course


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
<syntaxhighlight lang="sql">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course


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 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


<syntaxhighlight lang="sql">
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
SELECT c.shortname, g.name, c.groupmode
JOIN prefix_modules AS m ON cm.module = m.id
FROM prefix_course AS c
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
JOIN prefix_groups AS g ON c.id = g.courseid
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
WHERE c.groupmode > 0
JOIN prefix_modules AS m ON cm.module = m.id
</syntaxhighlight>
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs


===Users enrolled in a course with groups but not assigned a group ===
,(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


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 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


<syntaxhighlight lang="sql">
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
SELECT DISTINCT
JOIN prefix_modules AS m ON cm.module = m.id
user2.firstname AS Firstname,
WHERE cm.course = c.id AND m.name LIKE '%assignment%') AS Assignments
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
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_enrol AS en ON en.courseid = course.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
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)
FROM prefix_course AS c
WHERE c.category IN ( 18)
ORDER BY Wikis DESC,Blogs DESC, Forums DESC
</syntaxhighlight>


ORDER BY Course, Lastname
===Assignment Activity===
</syntaxhighlight>


===Groups in course with member list===
Note: The current Assignment module uses the tables with names starting with prefix_assign_. This is the module [https://docs.moodle.org/dev/Moodle_2.3_release_notes#Assignment_module introduced in Moodle 2.3] and has been in use ever since then (2012).


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
The old, previous Assignment module used tables beginning with prefix_assignment_. This old module was [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment removed and has not been supported since Moodle 2.7]. If you have any modern version of Moodle, only use the queries below that are for the new module. If you are the author of one of the older assignment modules, please remove it to prevent confusion. Thanks.


List the groups in a course (replace the # by the course id number) with the members of each group.


<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>


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:
==== Assignment type usage in courses ====
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
WHERE c.id = %%COURSEID%%
SELECT
</syntaxhighlight>


===Group Export===
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/assign/index.php?id=',c.id,'">',c.fullname,'</a>') AS "List assignments"


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
,(SELECT COUNT(*) FROM prefix_assign WHERE c.id = course) AS Assignments


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.
,(SELECT COUNT(*)
 
FROM prefix_assign_plugin_config AS apc
<syntaxhighlight lang="sql">
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
SELECT g.name AS groupname, g.description, g.enrolmentkey
WHERE iassign.course = c.id AND apc.plugin = 'file' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
FROM prefix_groups AS g
#GROUP BY apc.plugin
JOIN prefix_course as c ON g.courseid = c.id
) AS "File Assignments"
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>


==Course Design Reports==
,(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"


These are reports which summarize course design aspects, such as activity and resource modules per section, types of activities used, etc.
,(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"


===Course Content/Week===
,(SELECT COUNT(*)
Contributed by Elizabeth Dalton, Granite State College
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"


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:
,(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"


    Forums
FROM prefix_assign AS assign
    Graded Activities (may include Forums)
JOIN prefix_course AS c ON c.id = assign.course
    Resources (not including a Label)
GROUP BY c.id
</syntaxhighlight>


Totals of each of these types of content elements per section are provided.


'''Note''': Only visible resources and activities are counted.
====All Ungraded Assignments====
'''Note''': this is a "Global" report. Run it within a course to see a summary of the contents of that course.
 
'''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]


Returns all the submitted assignments that still need grading
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
select
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment"


cs.section AS 'Week'
from prefix_assignment_submissions as asb
, cs.name AS 'Section Name'
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


, COUNT(DISTINCT IF((gi.id IS NULL) AND (m.name NOT LIKE 'label'),cm.id,NULL)) AS 'Ungraded Resources'
where asb.grade < 0 and cm.instance = a.id
and cm.module = 1


, COUNT(DISTINCT IF(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'
order by c.fullname, a.name, u.lastname
</syntaxhighlight>


, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Graded Activities'
====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.


FROM prefix_course AS c
'''This query is updated for use with Moodle 2.2 or later. Contributed by Carly J. Born, Carleton College'''
JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section <= 14 AND cs.section > 0
<syntaxhighlight lang="sql">
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
SELECT
JOIN prefix_modules AS m ON m.id = cm.module
u.firstname AS "First",
LEFT JOIN prefix_grade_items AS gi ON gi.courseid = c.id AND gi.itemmodule = m.name AND gi.iteminstance = cm.instance
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment",


WHERE
concat('<a target="_new" href="%%WWWROOT%%/mod/assign/view.php?id=',
cs.visible = 1
cm.id,
AND cm.visible = 1
'&rownum=0&action=grader&userid=',
AND c.id = %%COURSEID%%
u.id,
 
'">Grade</a>')
GROUP BY cs.section
AS "Assignment link"
ORDER BY cs.section


</syntaxhighlight>
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


===Assignments and Weights===
WHERE cm.instance = a.id AND cm.module = 22 AND sub.status='submitted'
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.
ORDER BY c.fullname, a.name, u.lastname


Categories with weights of 0 are not included in this report.
NOTE: you will need to change the cm.module = 22 number to be the id number of the Assignment module in your site. By default, this is 1.  


Only visible activities are included in this report.
</syntaxhighlight>


'''Note''': This is designed to be a "Global" report in Configurable Reports.
====Assignments (and Quizzes) waiting to be graded====
<syntaxhighlight lang="sql">
SELECT


IF(gc.parent IS NOT NULL, gc.fullname, 'None') AS 'Grade Book Category'
'''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.
, 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'
''' See: [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment]


, 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
This report requires a YEAR filter to be added (Available when using the latest block/configurable_reports)


#get grade categories
Which you can always remove, to make this query work on earlier versions.
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
The report includes:
JOIN prefix_course_modules AS cm ON cm.course = c.id
*number of quizzes
# attach grade items to activities
*unFinished Quiz attempts
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
*Finished Quiz attempts
 
*number of students
# attach manual grade items to course-- they don't have modules
*number of Assignments
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual' AND mgi.categoryid = gc.id
*number of submitted answers by students
 
*number of unchecked assignments (waiting for the Teacher) in a Course.
WHERE
cm.visible = 1
AND c.id = %%COURSEID%%
 
GROUP BY gc.id
ORDER BY gc.id
 
</syntaxhighlight>
 
===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:
 
#  "Required blocks" include Instructor Block (mooprofile), Activities, and the Research block.
#    "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.
#    All courses should be in the "Collapsed Topics" format with the "Weeks" structure.
#    "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.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT 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


#,RIGHT(c.idnumber,2) AS Type # Specific to GSC "Instructional Method" storage
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
 
#, 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
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
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Instructor'
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


,(SELECT IF((u2.description IS NULL) OR (u2.description LIKE ''),'NO', 'YES')
,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">בחנים</a>') AS 'Quizzes'
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')
,(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
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 u3 ON u3.id = ra.userid
WHERE ra.roleid = 5
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Profile Has Picture'
AND ctx.instanceid = c.id
) AS nStudents


, 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
,(
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


#, IF(bi.configdata LIKE '%ZGl0IHRoaXMgYmxvY2s%','NO','') AS 'Instructor Details Block Updated' # HTML block has string 'dit this block'
,(
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'


#, 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
, CONCAT(ROUND( (100 / iAssignments ) * iOpenAssignments ) ,'%') 'unFinished <br/>Assignments <br/>(percent)'


, 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'
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'


, cfw.value AS 'weeks defined in course settings'
,(
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'


, 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)'
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


, COUNT(DISTINCT IF(m.name LIKE 'forum', cm.id, NULL)) AS 'Forums'
LEFT JOIN (
, COUNT(DISTINCT IF(m.name LIKE 'forum' ,cs.id , NULL)) AS 'Weeks with Forum'
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


, COUNT(DISTINCT IF(gi.id, cm.id, NULL)) AS 'Activities'
WHERE 1=1
, COUNT(DISTINCT IF(gi.id, cs.id, NULL)) AS 'Weeks with Activities'
#AND c.fullname LIKE '%תשעג%'
, COUNT(DISTINCT mgi.id) AS 'Manual Grade Items'
%%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>


, 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
====Users who have overdue assignments====


#,(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
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


#,(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
Shows a list of users who have not yet done an Assignment whose due date is past.


#,(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
<syntaxhighlight lang="sql">
SELECT DISTINCT
u.username AS "User",
c.shortname AS "Course",
a.name AS "Assignment",
DATE_FORMAT(FROM_UNIXTIME(a.gradingduedate),'%Y-%m-%d %H:%i') AS "Due_date_UTC"


,(SELECT FROM_UNIXTIME(MAX(prefix_resource.timemodified))
FROM prefix_user_enrolments ue
FROM prefix_resource
JOIN prefix_enrol AS e ON e.id = ue.enrolid
JOIN prefix_course ON prefix_course.id = prefix_resource.course WHERE c.id = prefix_resource.course AND prefix_resource.name LIKE '%syllabus%') AS SyllabusDate
JOIN prefix_course AS c ON c.id = e.courseid
JOIN prefix_user AS u ON u.id = ue.userid
JOIN prefix_assign a ON a.course = c.id
WHERE
# pick your course but make sure it agrees with the c.id in the subselect
c.id = 2
#skip future dates
AND DATEDIFF(NOW(),FROM_UNIXTIME(a.gradingduedate)) > 0
# only users who have not submitted
AND ue.userid NOT IN
(SELECT asub.userid
  FROM prefix_assign_submission AS asub
  JOIN prefix_assign AS a ON a.id = asub.assignment
  JOIN prefix_course c on a.course = c.id
  WHERE c.id = 2)


,(SELECT TO_DAYS(NOW())-TO_DAYS(FROM_UNIXTIME(MAX(prefix_resource.timemodified)))
ORDER BY u.username, c.shortname
FROM prefix_resource
</syntaxhighlight>
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'
====Rubrics without zero values in criteria====
Contributed by Eric Strom


FROM prefix_course AS c
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:
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
"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.
LEFT JOIN prefix_block_positions AS bpm ON bpm.contextid = ctxx.id AND bpm.blockinstanceid = '43962' # messages
TIP: To avoid confusion from this sort of thing, we recommend including a level with 0 points in every rubric criterion."
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
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.
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
Includes search filter of course idnumber.
LEFT JOIN prefix_forum_discussions AS fd ON fd.forum = f.id


# attach manual grade items to course-- they don't have modules
<syntaxhighlight lang="sql">
LEFT JOIN prefix_grade_items AS mgi ON mgi.courseid = c.id and mgi.itemtype = 'manual'
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,
LEFT JOIN prefix_course_format_options AS cfo ON cfo.courseid = c.id AND cfo.name = 'layoutstructure'
c.fullname AS Course_Name,
LEFT JOIN prefix_course_format_options AS cfw ON cfw.courseid = c.id AND cfw.name = 'numsections'
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'))


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%')
GROUP BY Rubric
LEFT JOIN prefix_block_positions AS bip ON bip.blockinstanceid = bi.id
ORDER BY Course_ID, Rubric


WHERE RIGHT(c.idnumber,2) IN ('OL', 'BL', 'HY')
%%FILTER_SEARCHTEXT:c.idnumber:~%%
# 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
</syntaxhighlight>
</syntaxhighlight>


===Module instances + Module HITs by role teacher and student in course===
====Who is using "Single File Upload" assignment====
 
NOTE: This module uses the old log format pre-Moodle 2.7. It will not work with Moodle logs since 2.7. If you are the author, please update this query for current Moodle.
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
m.name AS "Module name"
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
, COUNT(*) AS "Module count"


,(SELECT COUNT(*)
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_log AS l
FROM prefix_role_assignments AS ra
WHERE l.course = cm.course AND l.module = m.name ) AS "Hits"
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(*)
,ass.name as "Assignment Name"
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
FROM prefix_log AS l
prefix_assignment as ass
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
JOIN
WHERE l.course = cm.course AND l.module = m.name) AS "Teachers HITs"
prefix_course as c ON c.id = ass.course


FROM mdl_course_modules AS cm
WHERE `assignmenttype` LIKE 'uploadsingle'
JOIN mdl_modules AS m on m.id = cm.module
WHERE cm.course = '%%COURSEID%%'
GROUP BY cm.module
</syntaxhighlight>
</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.
====Assignment Dates with their Calendar events====
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
This query can help you diagnose issues related to setting dues dates and other dates in the Assignment along with their corresponding dates that are put into the Calendar. Assignment puts only the Due date and the Grade by reminder date into the calendar.  


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
a.id AS "A_id",
a.name AS "Assignment_name",
IF(a.duedate = 0, 'None',DATE_FORMAT(FROM_UNIXTIME(a.duedate),'%Y-%m-%d %H:%i')) AS "Assign Due",
IF(a.gradingduedate = 0, 'None',DATE_FORMAT(FROM_UNIXTIME(a.gradingduedate),'%Y-%m-%d %H:%i')) AS "Assign Grade_by",
IF(a.cutoffdate = 0, 'None',DATE_FORMAT(FROM_UNIXTIME(a.cutoffdate),'%Y-%m-%d %H:%i')) AS "Assign Cutoff",
IF(a.allowsubmissionsfromdate = 0, 'None',DATE_FORMAT(FROM_UNIXTIME(a.allowsubmissionsfromdate),'%Y-%m-%d %H:%i')) AS "Assign Open",
e.modulename AS "Module_type",
CASE
WHEN e.eventtype = 'due' THEN CONCAT('Due: ',DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%Y-%m-%d %H:%i'))
WHEN e.eventtype = 'gradingdue' THEN CONCAT('GradingDue: ',DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%Y-%m-%d %H:%i'))
WHEN e.eventtype IS NULL THEN '-'
ELSE 'None'
END AS "Event Timestart"


c.fullname AS 'fullname'
FROM prefix_assign a
, ec.idnumber AS 'elis-id'
LEFT JOIN prefix_event e ON a.id = e.instance
, DATE_FORMAT(FROM_UNIXTIME(ec.startdate), '%b %e, %Y') AS 'start'
WHERE e.modulename IS NULL OR e.modulename = 'assign'
, 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
ORDER BY a.id
FROM prefix_local_eliscore_fld_data_text AS eft
</syntaxhighlight>
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)
===Chat Activity===
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
====List the chats====
FROM prefix_local_eliscore_fld_data_char AS efc
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
JOIN prefix_local_eliscore_field AS ef ON ef.id = efc.fieldid AND ef.shortname = 'term-code'
This report gives the list of all chats with the name of the course and various ids needed for further queries.
WHERE ctxci.id = efc.contextid) AS 'termcode'


, (SELECT  eft.data
The column "participants" is intended to work with an (optional) secondary report. If you don't need it, you can erase it.
FROM prefix_local_eliscore_fld_data_text AS eft
It produces a direct link to another (optional) report which will give you the current participants list to this chat.
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
<syntaxhighlight lang="sql">
FROM prefix_local_eliscore_fld_data_text AS eft
select
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'textbooks'
c.shortname,
WHERE ctxci.id = eft.contextid) AS 'textbooks'
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


, (SELECT  eft.data
FROM
FROM prefix_local_eliscore_fld_data_text AS eft
prefix_chat ch
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'other-class-materials'
INNER JOIN prefix_course c ON c.id = ch.course
WHERE ctxci.id = eft.contextid) AS 'other-class-materials'


, (SELECT  eft.data
ORDER BY ch.chattime, c.fullname
FROM prefix_local_eliscore_fld_data_text AS eft
</syntaxhighlight>
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
====Participants to a chat (optional secondary report)====
FROM prefix_role_assignments AS ra
This version of the participant list is intended to work with a link given in the previous report.
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
* User opens the report listing all the chats on the platform
JOIN prefix_user AS u2 ON u2.id = ra.userid
* user clicks on the link from the column "chat participant"
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS 'Bio'
* 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
<syntaxhighlight lang="sql">


GROUP_CONCAT(DISTINCT CONCAT(
SELECT
 
c.id AS courseid,
'<tr><td style="border: solid #000 .5px">',IF(gc.parent IS NOT NULL, gc.fullname, 'None')
chu.chatid,
, ' </td><td style="border: solid #000 .5px"> '
chu.userid AS 'chat user userid',
,IF(gc.parent IS NOT NULL, ROUND(gic.aggregationcoef, 2), ROUND( gi.aggregationcoef, 2)+ROUND(mgi.aggregationcoef, 2))
c.fullname,
u.username,
u.firstname,
u.lastname,
u.email


) SEPARATOR '</td></tr>')
FROM
#get grade categories
prefix_user u
FROM prefix_grade_categories AS gc
LEFT JOIN prefix_chat_users chu ON chu.userid = u.id
# back from categories to grade items to get aggregations and weights
INNER JOIN prefix_course c ON c.id = chu.course
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'
WHERE 1=1
, '<table width = "100%" >' AS 'table start 2'
%%FILTER_COURSES:chu.chatid%%
, '</table>' AS 'table end'
# you can also filter by course
# but don't put comment line between where and filter
# %%FILTER_COURSES:chu.course%%


, (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'


ORDER BY c.fullname


, (SELECT  eft.data
</syntaxhighlight>
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
====List current participants to chat====
FROM prefix_local_eliscore_fld_data_text AS eft
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
JOIN prefix_local_eliscore_field AS ef ON ef.id = eft.fieldid AND ef.shortname = 'grading-scale'
<syntaxhighlight lang="sql">
WHERE ctxepm.id = eft.contextid) AS 'gradescale'
SELECT
c.id AS courseid,
chu.chatid,
chu.userid AS 'chat user userid',
c.fullname,
u.username,
u.firstname,
u.lastname,
u.email


FROM
FROM
prefix_course AS c
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%%


# connect moodle course to ELIS class instance
ORDER BY c.fullname
LEFT JOIN prefix_local_elisprogram_cls_mdl AS ecm ON ecm.moodlecourseid = c.id
</syntaxhighlight>
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
=== Choice Activity===
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
==== Choice Results====
LEFT JOIN prefix_local_elisprogram_pgm_crs AS epc ON epc.courseid = ecd.id
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
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
Results of the Choice activity. For all courses, shows course shortname, username, the Choice text, and the answer chosen by the user.


c.id = %%COURSEID%%
<syntaxhighlight lang="sql">
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>
</syntaxhighlight>


===Course Activities Helper===
===Database Activity===
Contributed by Elizabeth Dalton, Granite State College


This report provides a list of the graded activities in a course.
There are no reports yet for the Database activity.
* '''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.
===Face to Face Activity===
* '''Note''': This report assumes that course sections each last one week.
 
Get Face to Face sessions info, course info, user info. Note the xpath function is specific to Postgresql.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
# 303 Course Activities Helper
SELECT
SELECT
    /* Session info */
    ftf_sd.timestart session_start_date,
    ftf_sd.timefinish session_end_date,
    ftf_s.id session_id,
    /* Course info */
    c.id course_id,
    c.shortname course_shortname,
    c.visible course_visible,
    (
        SELECT count(*)
        FROM prefix_facetoface ftf2
        WHERE ftf2.course = c.id
    ) facetoface_activities_in_course_count,
    /* FaceToFace activity-level info */
    ftf_s.facetoface facetoface_activity_id,
    ftf.name activity_name,
    CASE
        WHEN ftf_s.details LIKE '<%' THEN xpath('//text()', cast(ftf_s.details AS xml))::text
        ELSE ftf_s.details
    END session_description,
    /* User info */
    ftf_su.userid user_id,
    ftf_ss.signupid signup_id,
    ftf_ss.timecreated signup_date,
    u.username user_username,
    u.suspended user_suspended,
    u.username user_firstname,
    u.username user_lastname,
    u.email user_email,
    u.city
FROM prefix_facetoface_sessions ftf_s
    LEFT JOIN prefix_facetoface_sessions_dates ftf_sd ON ftf_sd.sessionid = ftf_s.id
    JOIN prefix_facetoface ftf ON ftf.id = ftf_s.facetoface
    JOIN prefix_course c ON c.id = ftf.course
    JOIN prefix_facetoface_signups ftf_su ON ftf_su.sessionid = ftf_s.id
    JOIN prefix_facetoface_signups_status ftf_ss ON (
        ftf_su.id = ftf_ss.signupid
        AND ftf_ss.superceded = 0
    )
    JOIN prefix_user u ON (
        u.id = ftf_su.userid
        AND u.deleted = 0
    )
</syntaxhighlight>


gi.itemmodule AS 'activity type'
===Feedback Activity===
# cs.section AS 'section number'
====List the answers to all the Feedback activities within the current course, submitted by the current user====
<syntaxhighlight lang="sql">
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"


# Calculation assumes each section lasts one week
FROM prefix_feedback AS f
, 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'
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


, gi.itemname AS 'activity name'
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 */


#, (SELECT asg.intro FROM prefix_assign AS asg WHERE asg.id = cm.instance) AS 'intro'
ORDER BY f.id, c.timemodified, i.id
</syntaxhighlight>


#, (SELECT f.intro FROM prefix_forum AS f WHERE f.id = cm.instance) AS 'f intro'


, CASE gi.itemmodule
====Show all Feedbacks from all courses for all users including showing names of anonymous users====
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'
Contributed by: [https://moodle.org/user/profile.php?id=88992 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.


FROM
<syntaxhighlight lang="sql">
prefix_course AS c
SELECT
 
c.shortname AS Course,
#get grade sections
f.name AS Feedback,
LEFT JOIN prefix_course_sections AS cs ON cs.course = c.id  AND cs.section > 0 AND cs.section <=14
# i.id AS Itemid,
LEFT JOIN prefix_course_modules AS cm ON cm.course = c.id AND cm.section = cs.id
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


#LEFT JOIN prefix_assign AS asg ON asg.id = cm.instance
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>


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
====Show all Feedbacks from all courses for all users with their answers====
c.id = %%COURSEID%%
AND cs.visible = 1


ORDER BY gi.itemmodule, cs.section
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
</syntaxhighlight>


==Course Completion and Grade Reports==
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.
===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
<syntaxhighlight lang="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
Known to work in Moodle 3.5 to 3.10.
  WHEN gi.itemtype = 'course'
  THEN c.fullname + ' Course Total'
  ELSE gi.itemname
END AS 'Item Name',


ROUND(gg.finalgrade,2) AS Grade,
<syntaxhighlight lang="sql">
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
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


FROM prefix_course AS c
WHERE i.typ IN ('label', 'multichoice')
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
</syntaxhighlight>
</syntaxhighlight>
For MySQL users, you'll need to use the MySQL DATE_ADD function instead of DATEADD. Replace the line:
 
===Forum Activity===
 
 
====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">
<syntaxhighlight lang="sql">
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
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>
</syntaxhighlight>
with:
 
 
====Forum use Count per Course -- not including News Forum!====
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
FROM_UNIXTIME(gg.timemodified) AS Time
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>
</syntaxhighlight>
And:
 
====Forum use Count per course by type -- not including News Forum!====
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
u.firstname + ' ' + u.lastname AS 'Display Name',
SELECT prefix_course.fullname, prefix_forum.course, prefix_forum.type, count(*) as total FROM prefix_forum
</syntaxhighlight>
INNER JOIN prefix_course
with:
ON prefix_course.id = prefix_forum.course
<syntaxhighlight lang="sql">
WHERE NOT(prefix_forum.type = 'news')
CONCAT(u.firstname,' ',u.lastname) AS 'Display Name',
GROUP BY prefix_forum.course,prefix_forum.type
</syntaxhighlight>
ORDER BY total desc
And:
<syntaxhighlight lang="sql">
THEN c.fullname + ' Course Total'
</syntaxhighlight>
with:
<syntaxhighlight lang="sql">
THEN CONCAT(c.fullname,' Course Total')
</syntaxhighlight>
</syntaxhighlight>


Note by Randy Thornton: or in full the MySQL version is:
====Forum activity - system wide====
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT u.firstname AS 'First' ,  
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS CourseID
u.lastname AS 'Last',
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
CONCAT(u.firstname, ' ', u.lastname) AS 'Display Name',
  FROM prefix_role_assignments AS ra
c.fullname AS 'Course',
  JOIN prefix_user AS u ON ra.userid = u.id
cc.name AS 'Category',
  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%%


CASE
GROUP BY fd.forum
  WHEN gi.itemtype = 'course'
ORDER BY count( * ) DESC
  THEN CONCAT(c.fullname, ' Course Total')
</syntaxhighlight>
  ELSE gi.itemname
END AS 'Item Name',


ROUND(gg.finalgrade,2) AS Grade,
DATE_FORMAT(FROM_UNIXTIME(gg.timemodified),'%Y-%m-%d') AS Time


FROM prefix_course AS c
====Activity In Forums====
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
Trying to figure out how much real activity we have in Forums by aggregating:
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
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...
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 u.lastname
</syntaxhighlight>
 
===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
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name',
SELECT c.fullname,f.name,f.type
cc.name AS 'Category',
,(SELECT count(id) FROM prefix_forum_discussions as fd WHERE f.id = fd.forum) as Discussions
CASE
,(SELECT count(distinct fd.userid) FROM prefix_forum_discussions as fd WHERE fd.forum = f.id) as UniqueUsersDiscussions
  WHEN gi.itemtype = 'course'
,(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
  THEN c.fullname + ' Course Total'
,(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
  ELSE gi.itemname
,(SELECT Count( ra.userid ) AS Students
END AS 'Item Name',
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>


ROUND(gg.finalgrade,2) AS Grade,
====All Forum type:NEWS====
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
<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>


FROM prefix_course AS c
====All new forum NEWS items (discussions) from all my Courses====
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
change "userid = 26" and "id = 26" to a new user id
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
<syntaxhighlight lang="sql">
JOIN prefix_user AS u ON u.id = ra.userid
SELECT c.shortname,f.name,fd.name,FROM_UNIXTIME(fd.timemodified ,"%d %M %Y ") as Date
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
FROM prefix_forum_discussions as fd
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_forum as f ON f.id = fd.forum
JOIN prefix_course_categories as cc ON cc.id = c.category
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>


WHERE  gi.courseid = c.id AND gi.itemtype = 'course'


ORDER BY lastname
====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>
</syntaxhighlight>


For MySQL users:
====Number of Forum Posts by a Teacher====
<syntaxhighlight lang="sql">
 
SELECT u.firstname AS 'First' , u.lastname AS 'Last', CONCAT(u.firstname , ' ' , u.lastname) AS 'Display Name',
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.
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,
Number of forums that have been posted to by a teacher. We wanted to know what the teacher's actions are in the forums of each course, so this report was made.
FROM_UNIXTIME(gg.timemodified) AS TIME


FROM prefix_course AS c
<syntaxhighlight lang="sql">
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
SELECT
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS curso,
JOIN prefix_user AS u ON u.id = ra.userid
CONCAT(u.firstname ,' ',u.lastname) AS Facilitador,
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'
(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
WHERE cm.course = c.id AND m.name LIKE '%forum%') AS foros,


===Learner report by Learner with grades===
COUNT(*) AS Posts
Which Learners in which course and what are the grades
<syntaxhighlight lang="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
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


FROM prefix_course AS c
WHERE fp.userid =
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
(
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
select distinct prefix_user.id
JOIN prefix_user AS u ON u.id = ra.userid
from prefix_user
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
join prefix_role_assignments as ra on ra.userid = prefix_user.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
where ra.roleid = 3
JOIN prefix_course_categories AS cc ON cc.id = c.category
and userid = fp.userid
WHERE  gi.courseid = c.id and gi.itemname != 'Attendance'
limit 1
ORDER BY `Name` ASC
)
 
and c.shortname like '%2014-2-1%'
GROUP BY c.id, u.id
</syntaxhighlight>
</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 beginning 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>


=== Grades for all students in all courses ===
====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


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
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>


A basic report showing grades for Students in all courses. It has only four columns: username, course shortname, grade, and date, restricted to the standard role of Student. You can use this as the basis for more complex reports.
===Glossary Activity===
 
====All glossary entries====
 
Shows the entries from all glossaries in the site with student and times.
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT  
 
u.username,
SELECT
c.shortname AS "Course",
c.shortname AS "Course",
ROUND(gg.finalgrade,2) AS "Grade",
g.name AS "Glossary",
DATE_FORMAT(FROM_UNIXTIME(gg.timemodified), '%Y-%m-%d') AS "Date"
# g.intro AS "Introduction",
u.username,
ge.concept AS "Concept",
ge.definition AS "Definition",
IF(ge.approved=1,'Yes','No') AS "Approved",
DATE_FORMAT(FROM_UNIXTIME(ge.timecreated), '%Y-%m-%d %H:%i' ) AS "Created",
DATE_FORMAT(FROM_UNIXTIME(ge.timemodified), '%Y-%m-%d %H:%i' ) AS "Modified"
FROM prefix_glossary_entries ge
JOIN prefix_glossary g ON g.id = ge.glossaryid
JOIN prefix_user u ON u.id = ge.userid
JOIN prefix_course c ON c.id = g.course
</syntaxhighlight>
 
===H5P Activities===
 
There are no reports yet for the H5P activities (core and non-core).
 
===Lesson Activity===
 
 


FROM prefix_course AS c
====Lesson Questions====
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
WHERE gi.courseid = c.id
AND gi.itemtype = 'course'
# students only role id is 5
AND ra.roleid = 5
ORDER BY u.username, c.shortname
</syntaxhighlight>


===Course Completion sitewide for all Users===
Show all the Questions with their Answers for all the Lessons in a site. This shows the questions as set up, not student responses. This is known to work in 3.11 but note that this may change in Moodle 4.0 or 4.1 due to plans to have the Lesson module use the standard question bank questions.


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
A very simple report with a list of course completion status by username. Completions are noted by date, blank otherwise.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
  u.username,
c.shortname AS "Course",
  c.shortname,
l.name AS "Lesson_Name",
DATE_FORMAT(FROM_UNIXTIME(cp.timecompleted),'%Y-%m-%d') AS completed
# NOTE: the line below is formatted for the Ad-hoc database queries plugin
FROM prefix_course_completions AS cp
# if using Config Reports you can edit this for the proper HTML format or remove it
JOIN prefix_course AS c ON cp.course = c.id
CONCAT("%%WWWROOT%%/mod/lesson/view.php%%Q%%id=",cm.id) AS "Lesson_Name_link_url",
JOIN prefix_user AS u ON cp.userid = u.id
p.title AS "Page_Title",
WHERE c.enablecompletion = 1
p.contents AS "Question",
ORDER BY u.username
a.grade,
a.score,
a.answer,
a.response
FROM prefix_lesson_answers a
JOIN prefix_lesson l ON l.id = a.lessonid
JOIN prefix_lesson_pages p ON p.id = a.pageid AND p.lessonid = l.id
JOIN prefix_course c ON c.id = l.course
JOIN prefix_course_modules cm ON cm.instance = l.id
JOIN prefix_modules m ON m.id = cm.module
WHERE m.name = 'lesson'
# to limit this to a single question type add this eg true-false is 2
# AND p.qtype = 2
# for just one lesson then put its course module id from the url here
# AND cm.id = #
</syntaxhighlight>
</syntaxhighlight>


Another version which includes the start and completed times.
 
If you want to have a column for the Question type, you can add this to the SELECT statement:


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
CASE p.qtype
u.firstname,
WHEN 1 THEN 'Short answer'
u.lastname,
WHEN 2 THEN 'True/False'
c.shortname AS 'Course',
WHEN 3 THEN 'Multi-choice'
CASE
WHEN 5 THEN 'Matching'
  WHEN cp.timestarted = 0 THEN DATE_FORMAT(FROM_UNIXTIME(cp.timeenrolled),'%Y-%m-%d')
WHEN 8 THEN 'Numerical'
  ELSE DATE_FORMAT(FROM_UNIXTIME(cp.timestarted),'%Y-%m-%d')
WHEN 10 THEN 'Essay'
END AS 'Started',
ELSE p.qtype
FROM_UNIXTIME(cp.timecompleted) AS 'Complete'
END AS "Question type",
</syntaxhighlight>
FROM prefix_user AS u
 
JOIN prefix_course_completions AS cp ON cp.userid = u.id
===LTI External Tool Activity===
JOIN prefix_course c ON c.id = cp.course
==== 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.
 
<syntaxhighlight lang="sql">
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'
 


</syntaxhighlight>
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id AND m.name LIKE 'lti'


===User Course Completion with Criteria===
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


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
%%FILTER_STARTTIME:c.startdate:>%%
%%FILTER_ENDTIME:c.startdate:<%%


A report with course completions by username, with Aggregation method, Criteria types, and Criteria detail where available.
GROUP BY c.shortname, m.name
ORDER BY c.startdate, c.shortname
</syntaxhighlight>


===Quiz Activity===
====Generate a list of instructors and their email addresses for those courses that has "essay questions" in their quizzes====
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT u.username AS user,
SELECT qu.id AS quiz_id, qu.course AS course_id, qu.questions,
c.shortname AS course,
                co.fullname AS course_fullname, co.shortname AS course_shortname,
DATE_FORMAT(FROM_UNIXTIME(t.timecompleted),'%Y-%m-%d') AS completed,
                qu.name AS quiz_name, FROM_UNIXTIME(qu.timeopen) AS quiz_timeopen, FROM_UNIXTIME(qu.timeclose) AS quiz_timeclose,
CASE
                u.firstname, u.lastname, u.email,
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"
FROM prefix_quiz qu, prefix_course co, prefix_role re, prefix_context ct, prefix_role_assignments ra, prefix_user u
ELSE "All"
WHERE FROM_UNIXTIME(timeopen) > '2008-05-14' AND
END AS aggregation,
                qu.course = co.id AND
CASE
                co.id = ct.instanceid AND
WHEN p.criteriatype = 1 THEN "Self"
                ra.roleid = re.id AND
WHEN p.criteriatype = 2 THEN "By Date"
                re.name = 'Teacher' AND
WHEN p.criteriatype = 3 THEN "Unenrol Status"
                ra.contextid = ct.id AND
WHEN p.criteriatype = 4 THEN "Activity"
                ra.userid = u.id
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


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>
</syntaxhighlight>


===Courses with Completion Enabled and their settings===
====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


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
FROM prefix_course_modules cm
 
JOIN prefix_course c ON c.id = cm.course
List of all courses with completion enabled and their Aggregation setting, Criteria types, and Criteria details.
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">
<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>


SELECT c.shortname AS Course,
====Parse MultiAnswer (Cloze) Question Responses and Display in Columns====
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
</syntaxhighlight>


===Course Completion Report with custom dates===
(Contributed by Laura DiFiore, July 2021, Moodle 3.97+) In this example, I am using a 4-part Cloze question for stenography students to keep track of their writing practice sessions. In mdl_question_attempts, their answers are stored like this:


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
<pre>part 1: 84; part 2: 92; part 3: 2; part 4: 98
part 1: 85; part 2: 107; part 3: 0; part 4: 100</pre>


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
 
SELECT 
SELECT u.username AS 'User Name',
    SUBSTRING_INDEX(SUBSTRING_INDEX(responsesummary, ';', 1), ' ', -1) as Drill,
CONCAT(u.firstname , ' ' , u.lastname) AS 'Name',
    SUBSTRING_INDEX(SUBSTRING_INDEX(responsesummary, ';', 2), ' ', -1) as WPM,
c.shortname AS 'Course Name',
    SUBSTRING_INDEX(SUBSTRING_INDEX(responsesummary, ';', 3), ' ', -1) as Mistakes,
DATE_FORMAT(FROM_UNIXTIME(p.timecompleted),'%W %e %M, %Y') AS 'Completed Date',
    SUBSTRING_INDEX(SUBSTRING_INDEX(responsesummary, ';', 4), ' ', -1) as Accuracy
ROUND(c4.gradefinal,2) AS 'Score'
FROM `mdl_question_attempts` WHERE questionid=21
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
 
</syntaxhighlight>
</syntaxhighlight>
<pre>
Drill WPM mistakes accuracy
84 92 2 98
85 107 0 100</pre>


===Scales used in activities===
====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">
<syntaxhighlight lang="sql">
SELECT scale.name
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%%/grade/edit/tree/index.php?showadvanced=1&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"
FROM prefix_grade_items AS gi
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/modedit.php?up','date=',cm.id,'">',gi.itemname,'</a>') AS "Module Settings"
JOIN prefix_course as c ON c.id = gi.courseid
 
WHERE  `itemtype` = 'manual'
FROM prefix_grade_items AS gi
GROUP BY courseid
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>
</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


===Extra Credit Items by Name Only===
,(SELECT DATE_FORMAT(FROM_UNIXTIME(timeaccess),'%Y-%m-%d') FROM prefix_user_lastaccess WHERE userid=user2.id AND courseid=c.id) AS CourseLastAccess
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 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


<syntaxhighlight lang="sql">
FROM prefix_user_enrolments AS ue
SELECT DATE(FROM_UNIXTIME(c.startdate)) AS StartDate,
JOIN prefix_enrol AS e ON e.id = ue.enrolid
concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php',CHAR(63),'id=',
JOIN prefix_course AS c ON c.id = e.courseid
c.id,'">',c.idnumber,'</a>') AS Course_ID, gi.itemname AS Item_Name
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>


,(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
===Users who have not yet taken a quiz===
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>')
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
  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
This is a stripped-down version of the query above, showing users in a course and the quizzes they have not yet taken.


FROM prefix_grade_items AS gi
<syntaxhighlight lang="sql">
JOIN prefix_course AS c ON gi.courseid = c.id
SELECT DISTINCT
u.username AS "User",
c.shortname AS "Course",
q.name AS "Quiz"


WHERE gi.itemname LIKE '%extra credit%'
FROM
AND gi.gradetype = '1'
prefix_user_enrolments ue
AND gi.hidden = '0'
JOIN prefix_enrol AS e ON e.id = ue.enrolid
AND gi.aggregationcoef = '0'
JOIN prefix_course AS c ON c.id = e.courseid
AND c.visible = 1
JOIN prefix_user AS u ON u.id = ue.userid
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
JOIN prefix_quiz q ON q.course = c.id
WHERE
# specify course but be sure it matches the c.id in the subselect
c.id = #
# exclude users who have an attempt
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 c on q.course = c.id
  WHERE c.id = #
)
 
ORDER BY u.username, c.shortname, q.name
</syntaxhighlight>


GROUP BY Course_ID, gi.id
====List Questions in each Quiz====
ORDER BY StartDate, Course_ID


%%FILTER_SEARCHTEXT:Course_ID:~%%
<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>
</syntaxhighlight>


===Site Wide Number of Courses Completed by User===
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.
Contributed by Ken St. John


Simple report that shows the number of completed courses for all users site wide
Here is a version for Moodle 3.x


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT u.lastname, u.firstname,
SELECT cm.id 'cmid', quiz.id 'quiz id'
COUNT(p.timecompleted) AS TotalCompletions
,CONCAT('<a target="_new" href="%%WWWROOT%%/mod/quiz/edit.php?cmid=',
FROM prefix_course_completions AS p
  cm.id, '">', quiz.name, '</a>') AS 'edit quiz'
JOIN prefix_user AS u ON p.userid = u.id
,q.id 'qid', q.name 'question name'
GROUP BY p.userid
FROM mdl_quiz AS quiz
ORDER BY u.lastname
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>
</syntaxhighlight>


==Course Activity Module Reports==
====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)


Note that specific activity modules each have their own section below, with the Resource modules - book, file, folder, page and url all in one section together. At the end is a section for all third party additional activity modules.
<syntaxhighlight lang="sql">
SELECT
cm.course "course_id", cm.id "moduel_id", q.id "quiz_id", q.name "quiz_name",


===General or Multiple Activities===
CASE q.grademethod
 
      WHEN 1 THEN "GRADEHIGHEST"
Reports covering multiple or all course modules.
      WHEN 2 THEN "GRADEAVERAGE"
      WHEN 3 THEN "ATTEMPTFIRST"
      WHEN 4 THEN "ATTEMPTLAST"
END "grade method"


==== User activity completions with dates====
, q.attempts "quiz_attempts_allowed", cm.groupmode "group_mode"
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
, 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.


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.
"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">
<syntaxhighlight lang="sql">
SELECT
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
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'


</syntaxhighlight>
, 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'


====Detailed ACTIONs for each MODULE====
, (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'
<syntaxhighlight lang="sql">
SELECT module,action,count(id) as counter
FROM prefix_log
GROUP BY module,action
ORDER BY module,counter desc
</syntaxhighlight>


====Most popular ACTIVITY====
#, SUM(IF (qu.qtype = 'numerical', 1, 0 )) AS 'numerical'
<syntaxhighlight lang="sql">
#, SUM(IF (qu.qtype LIKE 'calc%', 1, 0 )) AS 'calculated'
SELECT COUNT(l.id) hits, module
#, SUM(IF (qu.qtype = 'random', 1, 0 )) AS 'random'
FROM prefix_log l
#, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'
WHERE module != 'login' AND module != 'course' AND module != 'role'
#, SUM(IF (qu.qtype = 'essay', 1, 0 )) AS 'essay'
GROUP BY module
ORDER BY hits DESC
</syntaxhighlight>


====System wide use of activities and resources====
<syntaxhighlight lang="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
</syntaxhighlight>


====Log file actions per module per course (ids)====
, IF(q.shufflequestions > 0,'Yes','No') AS 'Randomized Questions'
, IF(q.shuffleanswers > 0,'Yes','No') AS 'Randomized Answers'


''Editor note: This query is for old style logs before Moodle 2.7. Do not use it on later versions of Moodle. If you are the author, please update this query for Moodle 2.7 and later log system or remove it.''
#, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
#, FROM_UNIXTIME(MIN(q.timemodified)) AS 'Last Modified'


<syntaxhighlight lang="sql">
#, DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(MIN(q.timemodified))) AS 'Quiz age'
select course,module,action,count(action) as summa from prefix_log
where action <> 'new'
group by course,action,module
order by course,module,action
</syntaxhighlight>


====System Wide usage count of various course Activities====
, MIN(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Min Quiz Age'
(Tested and works fine in Moodle 2.x)
, MAX(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Max Quiz Age'
Like: Forum, Wiki, Blog, Assignment, Database,
#Within specific category
#Teacher name in course


<syntaxhighlight lang="sql">
#, SUM(IF (DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified)) < 90, 1,0)) AS 'new quizzes'
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_quiz AS q
FROM prefix_role_assignments AS ra
JOIN prefix_course AS c on c.id = q.course
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_quiz_question_instances AS qqi ON qqi.quiz = q.id
JOIN prefix_user AS u ON u.id = ra.userid
LEFT JOIN prefix_question AS qu ON qu.id = qqi.question
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
WHERE
JOIN prefix_modules AS m ON cm.module = m.id
1
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.startdate:<%%
,(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
GROUP BY c.id
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
ORDER BY c.shortname
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
</syntaxhighlight>
</syntaxhighlight>


====Aggregated Teacher activity by "WEB2" Modules====
====Student responses (answers) to quiz questions====
(Tested and works fine in Moodle 2.x)
(Contributed by Juan F with help from Tim hunt and fellow Moodlers on the forums)
The NV column shows activity without VIEW log activity
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">
<syntaxhighlight lang="sql">
SELECT ra.userid, u.firstname,u.lastname
SELECT
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%') AS Wiki
    concat( u.firstname, " ", u.lastname ) AS "Student Name",
,(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
    u.id,
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%') AS Forum
    quiza.userid,
,(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
    q.course,
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%') AS Blog
    q.name,
,(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
    quiza.attempt,
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%') AS Assignment
    qa.slot,
,(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
    que.questiontext AS 'Question',
FROM prefix_role_assignments AS ra
    qa.rightanswer AS 'Correct Answer',
JOIN prefix_user AS u ON u.id = ra.userid
    qa.responsesummary AS 'Student Answer'
WHERE ra.roleid = 3
GROUP BY ra.userid
</syntaxhighlight>


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


====Counter Blog usage in Courses,system wide====
WHERE q.name = "BIO 208 Post Test Assessment"
What teachers in what courses, uses blogs and how many + student count in that course.
AND q.course = "17926"
<syntaxhighlight lang="sql">


SELECT ( @counter := @counter+1) as counter,
ORDER BY quiza.userid, quiza.attempt, qa.slot
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
</syntaxhighlight>
</syntaxhighlight>


===Assignment Activity ==
====Questions which are tagged within a course/quiz====
 
Calculates subgrades for tags in the each of the quizzes in a course.
Note: The current Assignment module uses the tables with names starting with prefix_assign_. This is the module [https://docs.moodle.org/dev/Moodle_2.3_release_notes#Assignment_module introduced in Moodle 2.3] and has been in use ever since then (2012).
Contributed by Daniel Thies in https://moodle.org/mod/forum/discuss.php?d=324314#p1346542
 
The old, previous Assignment module used tables beginning with prefix_assignment_. This old module was [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment removed and has not been supported since Moodle 2.7]. If you have any modern version of Moodle, only use the queries below that are for the new module. If you are the author of one of the older assignment modules, please remove it to prevent confusion. Thanks.
 
 


==== Assignment type usage in courses ====
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
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===


CONCAT('<a target="_new" href="%%WWWROOT%%/mod/assign/index.php?id=',c.id,'">',c.fullname,'</a>') AS "List assignments"
====SCORM Usage by Course Start Date====
 
Contributed by Elizabeth Dalton, Granite State College
,(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(*)
Report of number of inclusions of SCORM activities in courses, filtered by course start date.
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(*)
<syntaxhighlight lang="sql">
FROM prefix_assign_plugin_config AS apc
SELECT
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(*)
CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'course'
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(*)
, cc.name AS 'Category'
FROM prefix_assign_plugin_config AS apc
, scm.name AS 'Sample Activity Name'
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
WHERE iassign.course = c.id AND apc.plugin = 'comments' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
, COUNT(DISTINCT cm.id) AS 'Resources Used'
) AS "Assignments Comments"
#, FROM_UNIXTIME(cm.added) AS 'resource added'


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


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


====All Ungraded Assignments====
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


'''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.
WHERE
''' See: [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment]
1


Returns all the submitted assignments that still need grading
%%FILTER_STARTTIME:c.startdate:>%%
<syntaxhighlight lang="sql">
%%FILTER_ENDTIME:c.startdate:<%%
select
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment"


from prefix_assignment_submissions as asb
GROUP BY c.shortname, m.name
join prefix_assignment as a ON a.id = asb.assignment
ORDER BY c.startdate, c.shortname
join prefix_user as u ON u.id = asb.userid
</syntaxhighlight>
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
====How many SCORM activities are used in each Course====
<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>
</syntaxhighlight>


===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'''
====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">
<syntaxhighlight lang="sql">
SELECT
SELECT
u.firstname AS "First",
u.firstname AS First,
u.lastname AS "Last",
u.lastname AS Last,
c.fullname AS "Course",
u.idnumber AS Employee_ID,
a.name AS "Assignment",
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


concat('<a target="_new" href="%%WWWROOT%%/mod/assign/view.php?id=',
FROM prefix_scorm_scoes_track AS st
cm.id,
JOIN prefix_user AS u ON st.userid=u.id
'&rownum=0&action=grader&userid=',
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
u.id,
JOIN prefix_scorm AS sc ON sc.id=st.scormid
'">Grade</a>')
JOIN prefix_course AS c ON c.id=sc.course
AS "Assignment link"
JOIN prefix_groups AS g ON g.courseid = c.id
 
JOIN prefix_groups_members AS m ON g.id = m.groupid
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'
WHERE st.element='cmi.core.lesson_status' AND m.userid=u.id


ORDER BY c.fullname, a.name, u.lastname
UNION


</syntaxhighlight>
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


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.
WHERE  st.timemodified IS NULL AND m.userid=user2.id
See: [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment]


ORDER BY  Course, Last, First, Attempt


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.
</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">
<syntaxhighlight lang="sql">
select
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
u.firstname AS "First",
FROM prefix_scorm_scoes_track AS st
u.lastname AS "Last",
JOIN prefix_user AS u ON st.userid=u.id
c.fullname AS "Course",
JOIN prefix_scorm AS sc ON sc.id=st.scormid
a.name AS "Assignment",
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>


'<a href="http://education.varonis.com/mod/assignment/submissions.php' + char(63) +
===Survey Activity===
+ 'id=' + cast(cm.id as varchar) + '&userid=' + cast(u.id as varchar)
Show all data for all surveys
+ '&mode=single&filter=0&offset=2">' + a.name + '</a>'
<syntaxhighlight lang="sql">
AS "Assignmentlink"
SELECT * FROM prefix_survey_answers
</syntaxhighlight>


Show all data for all surveys but with more info


from prefix_assignment_submissions as asb
<syntaxhighlight lang="sql">
join prefix_assignment as a ON a.id = asb.assignment
SELECT
join prefix_user as u ON u.id = asb.userid
  cm.id courseid, cm.instance surveyid, cm.visible,
join prefix_course as c ON c.id = a.course
  sa.id surveyid, sa.userid, sa.question questionid, sa.time time_date, sa.answer1, sa.answer2
join prefix_course_modules as cm ON c.id = cm.course
FROM prefix_course_modules cm
 
JOIN prefix_survey_answers sa ON cm.instance = sa.survey
where asb.grade < 0 and cm.instance = a.id and cm.module = 1
JOIN prefix_course c ON cm.course = c.id
 
JOIN prefix_modules m ON cm.module = m.id  
order by c.fullname, a.name, u.lastname
WHERE cm.course = c.id AND m.name LIKE '%survey%'
/*
ORDER BY c.id,sa.userid, sa.time DESC, sa.questionid
*/
</syntaxhighlight>
</syntaxhighlight>


====Assignments (and Quizzes) waiting to be graded====
=== Wiki Activity ===


'''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.
====Course wiki usage/activity over the last 6 semesters====
''' See: [https://docs.moodle.org/dev/Moodle_2.7_release_notes#Assignment]
<syntaxhighlight lang="sql">
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'


This report requires a YEAR filter to be added (Available when using the latest block/configurable_reports)
,(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'


Which you can always remove, to make this query work on earlier versions.
,(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/> סמסטר א'


The report includes:
,(SELECT count( m.name ) AS count FROM
*number of quizzes
prefix_course_modules AS cm
*unFinished Quiz attempts
JOIN prefix_modules AS m ON cm.module = m.id
*Finished Quiz attempts
JOIN prefix_course AS c ON c.id = cm.course
*number of students
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
*number of Assignments
and c.fullname LIKE CONCAT('%','תשעא','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעא <br/> סמסטר ב'
*number of submitted answers by students
 
*number of unchecked assignments (waiting for the Teacher) in a Course.
,(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/> סמסטר א'


<syntaxhighlight lang="sql">
,(SELECT count( m.name ) AS count FROM
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS 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 CONCAT(u.firstname,' ', u.lastname) AS Teacher
,(SELECT count( m.name ) AS count FROM
FROM prefix_role_assignments AS ra
prefix_course_modules AS cm
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_course AS c ON c.id = cm.course
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
and c.fullname LIKE CONCAT('%','תשעג','%') and c.fullname LIKE '%סמסטר א%') AS 'תשעג <br/> סמסטר א'


,concat('<a target="_new" href="%%WWWROOT%%/mod/assignment/index.php?id=',c.id,'">מטלות</a>') AS Assignments
,(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/> סמסטר ב'
</syntaxhighlight>


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


,(SELECT COUNT(*)
There are currently no reports for the Workshop activity.
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(*)
==COURSE RESOURCES REPORTS (Book, File, Folder, Label, Page, URL) ==
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(*)
===All resources that link to some specific external website===
FROM prefix_quiz_attempts AS qa
+ link to course
JOIN prefix_quiz AS q ON q.id = qa.quiz
+ who's the teacher
WHERE q.course = c.id
+ link to external resource
AND qa.timefinish > 0
<syntaxhighlight lang="sql">
GROUP BY q.course) AS 'finished quiz attempts'
SELECT
 
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,(SELECT Count( ra.userid ) AS Users
,c.shortname,r.name
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
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
WHERE ra.roleid = 5
JOIN prefix_user AS u ON u.id = ra.userid
AND ctx.instanceid = c.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
) AS nStudents
,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===
SELECT count(a.id)
+ (First)Teacher name
FROM prefix_assignment AS a
+ Where course is inside some specific Categories
JOIN prefix_course_modules AS cm ON a.course = cm.course
<syntaxhighlight lang="sql">
WHERE cm.instance = a.id AND cm.module = 1 AND a.course = c.id
SELECT
) nAssignments
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>
 
==NON-CORE MODULES==


,(
This is the section for non-core, contributed third party activity and resource plugin modules.
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)'
=== Elluminate (Blackboard Collaborate) - system wide usage===


,(
''Editor's note: This is for the [https://moodle.org/plugins/mod_collaborate Blackboard Collaborate plugin].''
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
<syntaxhighlight lang="sql">
LEFT JOIN (
SELECT e.name As Session ,er.recordingsize
SELECT course, count(*) AS iAssignments
,c.fullname As Course
FROM prefix_assignment AS a
,u.firstname,u.lastname
GROUP BY a.course
,DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%d-%m-%Y') AS dTimeStart
) AS tblAssignmentsCount ON tblAssignmentsCount.course = c.id
,concat('<a target="_new" href="%%WWWROOT%%/moodle/mod/elluminate/loadrecording.php?id=',er.id,'">Show</a>') AS RecordedSession


LEFT JOIN (
FROM prefix_elluminate_recordings AS er
SELECT course, count(*) AS iOpenAssignments
JOIN prefix_elluminate AS e ON e.meetingid = er.meetingid
FROM prefix_assignment AS a
JOIN prefix_course as c ON c.id = e.course
WHERE FROM_UNIXTIME(a.timedue) > NOW()
JOIN prefix_user AS u ON u.id = e.creator
GROUP BY a.course
ORDER BY er.recordingsize DESC
) 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
</syntaxhighlight>
</syntaxhighlight>


====Rubrics without zero values in criteria====
===List all the certificates issued, sort by variables in the custom profile fields===
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:
''Editor note: This is for the [https://moodle.org/plugins/mod_certificate classic Certificate module], which is no longer maintained since Moodle 3.3''


"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.
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.
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.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT cat.name AS Department, concat('<a target="_new" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',
SELECT
c.id,'">',c.idnumber,'</a>') AS Course_ID,
DATE_FORMAT( FROM_UNIXTIME(prefix_certificate_issues.timecreated), '%Y-%m-%d' ) AS Date,
c.fullname AS Course_Name,
prefix_certificate_issues.classname AS Topic,
concat('<a target="_new" href="%%WWWROOT%%/grade/grading/form/rubric/edit.php',CHAR(63),'areaid=',gd.areaid,'">',gd.areaid,'</a>') AS Rubric
prefix_certificate.name AS Certificate,
FROM prefix_course AS c
prefix_certificate_issues.studentname as Name,
JOIN prefix_course_categories AS cat
prefix_user_info_data.data AS Units
ON cat.id = c.category
 
JOIN prefix_course_modules AS cm
FROM
ON c.id=cm.course
prefix_certificate_issues
JOIN prefix_context AS ctx
 
ON cm.id = ctx.instanceid
INNER JOIN prefix_user_info_data
JOIN prefix_grading_areas AS garea
on prefix_certificate_issues.userid = prefix_user_info_data.userid
ON ctx.id = garea.contextid
 
JOIN prefix_grading_definitions AS gd
INNER JOIN prefix_certificate
ON garea.id = gd.areaid
on prefix_certificate_issues.certificateid = prefix_certificate.id
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
WHERE prefix_user_info_data.data='Unit 1'
ORDER BY Course_ID, Rubric
OR prefix_user_info_data.data='Unit 2'
OR prefix_user_info_data.data='Unit 3'


%%FILTER_SEARCHTEXT:c.idnumber:~%%
ORDER BY Units, Name, Topic ASC
</syntaxhighlight>
</syntaxhighlight>


====Who is using "Single File Upload" assignment====
=== All Simple Certificates Earned in the Site===
 
''Editor's note: This query is specific to the [https://moodle.org/plugins/mod_simplecertificate the Simple Certificate plugin]''.
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
Basic report of all certificates earned with [https://moodle.org/plugins/mod_simplecertificate the Simple Certificate plugin module] in the whole site, sorted by most recent first.
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
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
</syntaxhighlight>
 
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:
<syntaxhighlight lang="sql">
WHERE DATEDIFF(NOW(),FROM_UNIXTIME(sci.timecreated) ) < 30
</syntaxhighlight>


,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
===Student's posts content in all course blogs (oublog)===
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"
''Editor's Note: This query is specific to the [https://moodle.org/plugins/mod_oublog plugin OU Blog], not the standard Moodle blog tool.''


FROM
<syntaxhighlight lang="sql">
prefix_assignment as ass
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"


JOIN
FROM prefix_oublog_posts AS op
prefix_course as c ON c.id = ass.course
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 `assignmenttype` LIKE 'uploadsingle'
WHERE c.id = %%COURSEID%%
</syntaxhighlight>
</syntaxhighlight>


==Chat Activity==
==SITE WIDE USER TOOLS==
 
=== Badges===
 
==== All badges issued, by User ====


===List the chats===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
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.
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.
It produces a direct link to another (optional) report which will give you the current participants list to this chat.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
select
SELECT u.username, b.name AS badgename,
c.shortname,
CASE
c.fullname,
WHEN b.courseid IS NOT NULL THEN
ch.course,
(SELECT c.shortname
ch.id,
    FROM prefix_course AS c
# if you intend to use a secondary report to see the participants of a specific chat
    WHERE c.id = b.courseid)
# 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
WHEN b.courseid IS NULL THEN "*"
CONCAT('<a href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?id=21&filter_courses=', ch.id,'">Chat participants</a>') AS 'Course link',
END AS Context,
ch.chattime
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,
IF(d.dateexpire IS NULL, 'Never', 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>
 
==== All badges available in the system, with Earned count ====


FROM
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
prefix_chat ch
INNER JOIN prefix_course c ON c.id = ch.course


ORDER BY ch.chattime, c.fullname
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>
===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">
<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


SELECT
</syntaxhighlight>
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
==== Badges Leaderboard ====
%%FILTER_COURSES:chu.chatid%%
# you can also filter by course
# but don't put comment line between where and filter
# %%FILTER_COURSES:chu.course%%


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


ORDER BY c.fullname
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>
</syntaxhighlight>


===List current participants to chat===
==== Manage badges (System & Course) ====
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
List system wide badges, course and system level badges + a link to relevant "manage badges" page.
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
<syntaxhighlight lang="sql">
%%FILTER_COURSES:chu.course%%
SELECT b.id, b.name, b.description
 
,CASE
ORDER BY c.fullname
  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>
</syntaxhighlight>


===Blogs===


== Choice Activity==
=== Choice Results===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
Results of the Choice activity. For all courses, shows course shortname, username, the Choice text, and the answer chosen by the user.


====Counter Blog usage in Courses,system wide====
What teachers in what courses, uses blogs and how many + student count in that course.
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
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>


SELECT ( @counter := @counter+1) as counter,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course


==Database Activity==
,( 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
</syntaxhighlight>
 
 
====All site blogs posts by users====
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


There are no reports yet for the Database activity.
Shows all blog posts at site level by all users with dates, published status (draft, published to the site, or published publicly) along with links to the User blog profile and posts, and a link to delete any particular post. Known to work in 3.11.


==Feedback Activity==
===List the answers to all the Feedback activities within the current course, submitted by the current user===
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
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
SELECT
INNER JOIN prefix_course as crs on crs.id=f.course %%FILTER_COURSES:f.course%%
CONCAT('<a target="_new" href="%%WWWROOT%%/blog/index.php?id=',u.id,'">',CONCAT(u.firstname,' ',u.lastname),'</a>') AS "User (posts)",
INNER JOIN prefix_feedback_item AS i ON f.id=i.feedback
b.subject,
INNER JOIN prefix_feedback_completed AS c on f.id=c.feedback %%FILTER_COURSEUSER:c.userid%%
b.summary,
LEFT JOIN prefix_feedback_value AS v on v.completed=c.id AND v.item=i.id
# possible publish states are draft, site, public
INNER JOIN prefix_user AS u on c.userid=u.id
b.publishstate,
DATE_FORMAT(FROM_UNIXTIME(b.created),'%Y-%m-%d %H:%i') AS "Created",
DATE_FORMAT(FROM_UNIXTIME(b.lastmodified),'%Y-%m-%d %H:%i') AS "Last_modified",
CONCAT('<a target="_new" href="%%WWWROOT%%/blog/edit.php?action=',CHAR(ASCII('d')),'elete&entryid=',b.id,'">Remove this post</a>') AS "Remove_it"
 
FROM prefix_post b
JOIN prefix_user u ON u.id = b.userid
WHERE b.module = 'blog'
 
ORDER BY 1,2


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
</syntaxhighlight>
</syntaxhighlight>


===Show all Feedbacks from all courses for all users including showing names of anonymous users===
===Cohorts===
 
====Cohorts by user====


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
Contributed by: [https://moodle.org/user/profile.php?id=88992 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.
How to get a list of all users and which cohorts they belong to.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT u.firstname, u.lastname, h.idnumber, h.name
c.shortname AS Course,
FROM prefix_cohort AS h
f.name AS Feedback,
JOIN prefix_cohort_members AS hm ON h.id = hm.cohortid
# i.id AS Itemid,
JOIN prefix_user AS u ON hm.userid = u.id
i.name AS Itemname,
ORDER BY u.firstname
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'
</syntaxhighlight>
</syntaxhighlight>


 
====Cohorts with Courses====
===Show all Feedbacks from all courses for all users with their answers===


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
Contributed by: [https://moodle.org/user/profile.php?id=88992 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.
List of all cohorts with name, id, visibility, and which courses they are enrolled in.
 
Known to work in Moodle 3.5 to 3.10.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
c.fullname as "Course",
# h.id,
f.name AS "Feedback",
# e.customint1,
CONCAT(u.firstname,'  ',u.lastname) as "User",
h.name AS Cohort,
DATE_FORMAT(FROM_UNIXTIME(fc.timemodified), '%Y-%m-%d %H:%i') AS "When",
h.idnumber AS Cohortid,
IF(i.typ = 'label', i.presentation, i.name) AS "Question",
CASE
# answers presentation string starts with these 6 characters:  r>>>>>
WHEN h.visible = 1 THEN 'Yes'
CASE WHEN i.typ = 'multichoice' THEN SUBSTRING(i.presentation,7) END AS "Possible Answers",
  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
WHERE e.enrol = 'cohort' AND e.roleid = 5
</syntaxhighlight>
 
===Competencies===


CASE i.typ WHEN 'multichoice' THEN v.value ELSE '-' END AS "Chosen Answer Num",
====List of competencies from a framework and the courses including them====
CASE v.value
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
  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
<syntaxhighlight lang="sql">
JOIN prefix_course AS c ON c.id=f.course
SELECT
JOIN prefix_feedback_item AS i ON f.id=i.feedback
f.shortname AS 'Framework',
JOIN prefix_feedback_completed AS fc ON f.id=fc.feedback
comp.shortname AS 'Competency',
LEFT JOIN prefix_feedback_value AS v ON v.completed=fc.id AND v.item=i.id
cccomp.courseid AS 'Course id',
JOIN prefix_user AS u ON fc.userid=u.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>


WHERE i.typ IN ('label', 'multichoice')
====Count the courses using each competency from frameworks====
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]


</syntaxhighlight>
Unfortunately, there is not a filter by competency framework.


==Forum Activity==
===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">
<syntaxhighlight lang="sql">
SELECT
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
f.shortname AS framework,
,concat('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',fd.forum,'">',f.name,'</a>') AS Forum
comp.shortname AS 'Competency',
,count(*) as Posts
COUNT(cccomp.competencyid) AS 'nb course'
,(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_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>
 


FROM prefix_forum_posts AS fp
====Scale details with ids====
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!===
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
<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!===
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 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">
<syntaxhighlight lang="sql">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS CourseID
SELECT
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
s.id AS Scaleid,
  FROM prefix_role_assignments AS ra
s.name AS Scale_Name,
   JOIN prefix_user AS u ON ra.userid = u.id
s.scale AS Scale,
   JOIN prefix_context AS ctx ON ctx.id = ra.contextid
CASE
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
  WHEN s.courseid = 0 THEN 'System'
,c.fullname as Course
  ELSE (SELECT shortname FROM prefix_course WHERE id = s.courseid)
,f.type
END AS Context,
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
CASE
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
   WHEN s.userid = 0 THEN 'System'
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
   ELSE (SELECT username FROM prefix_user WHERE id = s.userid)
, fd.forum, f.name,count(*) AS cPostAndDisc
END AS User,
,(SELECT count(*) FROM prefix_forum_discussions AS ifd WHERE ifd.forum = f.id) AS cDiscussion
s.description,
FROM prefix_forum_posts AS fp
DATE_FORMAT( FROM_UNIXTIME(s.timemodified), '%Y-%m-%d %H:%i' ) AS 'Modified'
JOIN prefix_forum_discussions AS fd ON fd.id = fp.discussion
FROM prefix_scale s
JOIN prefix_forum AS f ON f.id = fd.forum
 
JOIN prefix_course AS c ON c.id = f.course
</syntaxhighlight>
WHERE f.type != 'news' AND c.fullname LIKE '%2013%'
 
## WHERE 1=1
====Site and Course level Competency Drill Down Reporting====
## %%FILTER_YEARS:c.fullname%%
Contributed by [https://moodle.org/user/profile.php?id=2682159 Ben Haensel]
## You can enable the SEMESTER filter as well,
 
## by uncommenting the following line:
=====Competencies: Department Selection=====
## %%FILTER_SEMESTERS:c.fullname%%
This reporting drill down logic assumes there is a correlation between the Course Category (Department) name and the Competency name.


GROUP BY fd.forum
<syntaxhighlight lang="sql">
ORDER BY count( * ) DESC
select concat('<a target="_blank" href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?id=117&filter_var=',cc.id,'">',cc.name,'</a>') Department
#Change the CR Report ID to go to your "Standards: All Site Standards with Course/Mod Counts" report (see below)
from prefix_course_categories cc
order by cc.name;
</syntaxhighlight>
</syntaxhighlight>


===Activity In Forums===
=====Competencies: All Site Standards with Course/Mod Counts=====
Trying to figure out how much real activity we have in Forums by aggregating:
Parent Report: Department Selection
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...
This report provides a list of all competencies within a Framework with links to a report of which activities (mods) use the specific competency within a course.
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT c.fullname,f.name,f.type
select cmp.id CompID,
,(SELECT count(id) FROM prefix_forum_discussions as fd WHERE f.id = fd.forum) as Discussions
cmp.shortname Competency,
,(SELECT count(distinct fd.userid) FROM prefix_forum_discussions as fd WHERE fd.forum = f.id) as UniqueUsersDiscussions
cmp.description Comp_Desc,
,(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
concat('<a target="_blank" href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?id=119&filter_var=',cmp.id,'">',
,(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
#Change the CR Report ID to go to your "Course Level Report" report (see below)
,(SELECT Count( ra.userid ) AS Students
(select count(distinct c.id)  
FROM prefix_role_assignments AS ra
from prefix_course c
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
join prefix_powerschool_course_fields pcf ON pcf.courseid = c.id
WHERE ra.roleid =5
join prefix_course_modules cm on c.id = cm.course
AND ctx.instanceid = c.id
join prefix_competency_modulecomp cmc on cm.id = cmc.cmid
) AS StudentsCount
where cmc.competencyid = cmp.id
,(SELECT Count( ra.userid ) AS Teachers
group by cmp.id) ,'</a>') CrsCnt,
FROM prefix_role_assignments AS ra
(select count(cmc.cmid)  
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
from prefix_course c
WHERE ra.roleid =3
join prefix_powerschool_course_fields pcf ON pcf.courseid = c.id
AND ctx.instanceid = c.id
join prefix_course_modules cm on c.id = cm.course
) AS 'Teacher<br/>Count'
join prefix_competency_modulecomp cmc on cm.id = cmc.cmid
,(SELECT Count( ra.userid ) AS Users
where cmc.competencyid = cmp.id
FROM prefix_role_assignments AS ra
group by cmp.id) ActCnt,
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
#Modify this case statement for your departments based on compency shortname or remove
WHERE ra.roleid IN (3,5)
case when cmp.shortname like 'ART%' then 'Art'
AND ctx.instanceid = c.id
when cmp.shortname like 'SOC%' then 'Social_Studies'
) AS UserCount
when cmp.shortname like 'MTH%' then 'Math'
, (SELECT (UniqueUsersDiscussions / StudentsCount )) as StudentDissUsage
when cmp.shortname like 'SCI%' then 'Science'
, (SELECT (UniqueUsersPosts /StudentsCount)) as StudentPostUsage
when cmp.shortname like 'WL%' then 'World_Language'
FROM prefix_forum as f
when cmp.shortname like 'ELA%' then 'English'
JOIN prefix_course as c ON f.course = c.id
else cmp.shortname
WHERE `type` != 'news'
end as Dept
ORDER BY StudentPostUsage DESC
from prefix_competency cmp
where cmp.competencyframeworkid = '%%FILTER_VAR%%';
</syntaxhighlight>
 
=====Competencies: Course Level Report=====
Parent Report: All Site Standards with Course/Mod Counts
This report provides a course level view of a specific competency and what activities it is connected to.
Multiple courses may show activities (mods) that are connected to the selected competency.
The link under the activity column goes to edit that selected activity.
 
<syntaxhighlight lang="sql">
select c.id courseid,
c.fullname course,
cmp.shortname competency,
concat('<a target="_blank" href="%%WWWROOT%%/course/modedit.php?update=',cm.id,'">',gi.itemname,'</a>') activity
from prefix_course c
join prefix_course_modules cm on c.id = cm.course
join prefix_modules m on cm.module = m.id
join prefix_grade_items gi on cm.instance = gi.iteminstance and gi.itemmodule = m.name
join prefix_competency_modulecomp cmc on cm.id = cmc.cmid
join prefix_competency cmp on cmc.competencyid = cmp.id
join prefix_powerschool_course_fields pcf on c.id = pcf.courseid
where '%%FILTER_VAR%%' = cmp.id
order by c.id, gi.itemname;
</syntaxhighlight>
</syntaxhighlight>


===All Forum type:NEWS===
===Messaging===
<syntaxhighlight lang="sql">
 
SELECT f.id, f.name
The Messaging system received an overhaul in Moodle 3.5 (database changes) and in [https://docs.moodle.org/dev/Moodle_3.6_release_notes#Messaging 3.6 (new interface)].
FROM prefix_course_modules AS cm
 
JOIN prefix_modules AS m ON cm.module = m.id
==== Messages of All Users ====
JOIN prefix_forum AS f ON cm.instance = f.id
 
WHERE m.name = 'forum'
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton].  
AND f.type = 'news'
 
</syntaxhighlight>
This version of the query has been updated for Moodle 3.6 and above, when the Messaging database structures were revamped and substantially changed. This is a version of this query that has been tested with Moodle 3.10 back to Moodle 3.6. Huge thank you to [https://moodle.org/user/view.php?id=2247767&course=11 Sandy Noe] for testing!


===All new forum NEWS items (discussions) from all my Courses===
change "userid = 26" and "id = 26" to a new user id
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT c.shortname,f.name,fd.name,FROM_UNIXTIME(fd.timemodified ,"%d %M %Y ") as Date
SELECT
FROM prefix_forum_discussions as fd
cv.id AS "Conversation_id",
JOIN prefix_forum as f ON f.id = fd.forum
DATE_FORMAT(FROM_UNIXTIME(me.timecreated), '%Y-%m-%d %H:%i') AS "At",
JOIN prefix_course as c ON c.id = f.course
(SELECT CONCAT(firstname,' ',lastname,' (',username,')') FROM prefix_user WHERE id = me.useridfrom) AS 'From',
JOIN prefix_user_lastaccess as ul ON (c.id = ul.courseid AND ul.userid = 26)
(SELECT
WHERE fd.timemodified > ul.timeaccess
  GROUP_CONCAT(DISTINCT CONCAT(u.firstname ,' ',lastname,' (',username,')'))
  AND fd.forum IN (SELECT f.id
  FROM prefix_user u
  FROM prefix_course_modules AS cm
  JOIN prefix_message_conversation_members cvm ON cvm.userid = u.id
  JOIN prefix_modules AS m ON cm.module = m.id
  WHERE cvm.conversationid = cv.id
  JOIN prefix_forum AS f ON cm.instance = f.id
  AND u.id != me.useridfrom
  WHERE m.name = 'forum'
  GROUP BY cvm.conversationid
  AND f.type = 'news')
) AS "To",
  AND c.id IN (SELECT c.id
IF(me.subject IS NULL, "(reply)", me.subject) AS "Subject",
  FROM prefix_course AS c
me.fullmessage AS "Message"
  JOIN prefix_context AS ctx ON c.id = ctx.instanceid
FROM prefix_messages me
  JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_message_conversations cv ON cv.id = me.conversationid
  JOIN prefix_user AS u ON u.id = ra.userid
ORDER BY cv.id, me.timecreated
  WHERE u.id = 26) ORDER BY `fd`.`timemodified` DESC
 
</syntaxhighlight>
</syntaxhighlight>


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].


===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>
===Number of Forum Posts by a Teacher===


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.


We wanted to know what the teacher's actions are in the forums of each course, so this report was made.
===Private Files===


====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">
<syntaxhighlight lang="sql">
SELECT
Select u.firstname, u.lastname, u.username,
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS curso,
concat('<a target="_new" href="%%WWWROOT%%/user/view.php?id=',u.id,'">',u.id,'</a>') as 'ID and Link to User Profilel',
CONCAT(u.firstname ,' ',u.lastname) AS Facilitador,
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>


(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
====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


FROM prefix_forum_posts AS fp
<syntaxhighlight lang="sql">
JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id
select f.contextid, f.component, f.filearea, f.filename,
JOIN prefix_forum AS f ON f.id = fd.forum
concat('<a target="_new" href="%%WWWROOT%%/user/view.php?id=',f.userid,'">',f.userid,'</a>') as 'ID and Link to Userprofile',
JOIN prefix_course AS c ON c.id = fd.course
u.firstname, u.lastname,
JOIN prefix_user AS u ON u.id = fp.userid
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>


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===
==== All Private Files by User ====
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"
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
<syntaxhighlight lang="sql">
 
SELECT
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.
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">
<syntaxhighlight lang="sql">
SELECT
SELECT
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=', f.id, '">', f.name, '</a>') AS 'Forum name',
u.username,
fd.name AS 'Discussion',
f.filename,
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/forum/discuss.php?d=', fd.id, '#p', fp.id, '">', fp.subject, '</a>') AS 'Post (link)',
CONCAT('/', LEFT(f.contenthash,2), '/', MID(f.contenthash,3,2), '/', f.contenthash) AS "Filedir_Location",
fp.message
DATE_FORMAT(FROM_UNIXTIME(f.timecreated),'%Y-%m-%d %H:%i') AS "Created"
 
FROM prefix_files f
FROM mdl_forum_posts AS fp
JOIN prefix_user u ON u.id = f.userid
  JOIN mdl_forum_discussions AS fd ON fd.id = fp.discussion
WHERE f.component = 'user'
  JOIN mdl_forum AS f ON f.id = fd.forum
AND f.filearea = 'private'
  JOIN mdl_course_modules AS cm ON cm.module = 9 AND cm.instance = f.id
AND f.filesize > 0
WHERE cm.id = %%FILTER_VAR%%
ORDER BY u.username, f.filename
ORDER BY f.id, fd.id
</syntaxhighlight>
</syntaxhighlight>


==Glossary Activity==


There are no reports yet for the Glossary activity.
===Tags===


==Lesson Activity==
==== All Tags in use in Courses and Activities ====


There are no reports yet for the Lesson activity.
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


==LTI (External Tool) Activity==
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.
=== 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.
Note: this version includes the new H5P core activity in its list of modules.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
t.name AS "Tag",
CASE ti.itemtype
  WHEN 'course' THEN 'Course'
  ELSE "Activity"
END AS "Tag_Type",


CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',c.id,'">',c.shortname,'</a>') AS 'course'
# 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",


, cc.name AS 'Category'
# get the activity type
, lti.name AS 'Sample Activity Name'
CASE ti.itemtype
, FROM_UNIXTIME(c.startdate) AS 'Course Start Date'
  WHEN 'course' THEN '-'
, COUNT(DISTINCT cm.id) AS 'Resources Used'
  ELSE
#, FROM_UNIXTIME(cm.added) AS 'resource added'
    # (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')


FROM prefix_course_modules AS cm
ORDER BY 1,2,3,4,5
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
</syntaxhighlight>
</syntaxhighlight>


==Quiz Activity==
==ADMINISTRATOR REPORTS==
===Generate a list of instructors and their email addresses for those courses that has "essay questions" in their quizzes===
 
 
===Privacy Policy Details===
 
Known to work in 3.11. May work in earlier versions of the Privacy policy system.
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
In the privacy policies management tools, you can see some but not all of the information about the various policies you have. Some key data is missing, including when and by whom policies were last changed. This report provides such information. It outputs the policy id, name, whether it is active or not, whether is archived or draft, what type it is, the audience, whether optional or required, dates, and who edited it last.
 
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT qu.id AS quiz_id, qu.course AS course_id, qu.questions,
SELECT  
                co.fullname AS course_fullname, co.shortname AS course_shortname,
p.id AS "Policy id",
                qu.name AS quiz_name, FROM_UNIXTIME(qu.timeopen) AS quiz_timeopen, FROM_UNIXTIME(qu.timeclose) AS quiz_timeclose,
# v.id AS "Version id",
                u.firstname, u.lastname, u.email,
v.name AS "Name",  
FROM prefix_quiz qu, prefix_course co, prefix_role re, prefix_context ct, prefix_role_assignments ra, prefix_user u
IF(v.archived = 0,"Active", "Not active") AS "Activity status",
WHERE FROM_UNIXTIME(timeopen) > '2008-05-14' AND
CASE
                qu.course = co.id AND
WHEN p.currentversionid IS NULL THEN 'Draft'
                co.id = ct.instanceid AND
WHEN p.currentversionid = v.id THEN 'Active'
                ra.roleid = re.id AND
ELSE 'Archived'
                re.name = 'Teacher' AND
END AS "Policy status",
                ra.contextid = ct.id AND
# per /admin/tool/policy/classes/policy_version.php
                ra.userid = u.id
CASE v.type
WHEN 0 THEN 'Site'
WHEN 1 THEN 'Privacy'
WHEN 2 THEN 'Third party'
WHEN 99 THEN 'Other'
ELSE 'Unknown policy type'
END AS "Type",
CASE v.audience
WHEN 0 THEN 'All'
WHEN 1 THEN 'Logged_in'
WHEN 3 THEN 'Guest'
ELSE 'Unknown audience type'
END AS "Audience",
IF(v.optional = 0,"Required","Optional") AS "Required",
DATE_FORMAT(FROM_UNIXTIME(v.timecreated),'%Y-%m-%d %H:%i') AS "Created",
DATE_FORMAT(FROM_UNIXTIME(v.timemodified),'%Y-%m-%d %H:%i') AS "Last_modified",
u.username AS "Modified_by"
FROM prefix_tool_policy_versions v
JOIN prefix_user u ON u.id = v.usermodified
JOIN prefix_tool_policy p ON p.id = v.policyid
ORDER BY p.id, v.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>
</syntaxhighlight>


===Number of Quizes per Course===
===Config changes in Export friendly form===
<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
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
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===
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 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">
<syntaxhighlight lang="sql">
SELECT COUNT( * )
SELECT
,concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php?showadvanced=1&id=',c.id,'">',c.fullname,'</a>') AS Course
DATE_FORMAT( FROM_UNIXTIME( g.timemodified ) , '%Y-%m-%d' ) AS date,
FROM  prefix_grade_items AS gi
u.username AS user,
JOIN prefix_course as c ON c.id = gi.courseid
g.name AS setting,
WHERE  `itemtype` =  'manual'
CASE
GROUP BY courseid
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>
</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',
=== List of users with language===
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
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


,(SELECT r.name
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.
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
This will show you the language setting for all users:
JOIN prefix_enrol AS e ON e.id = ue.enrolid
<syntaxhighlight lang="sql">
JOIN prefix_course AS c ON c.id = e.courseid
SELECT username, lang from prefix_user
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>
</syntaxhighlight>


===List Questions in each Quiz===
 
This code will change the setting from 'en' to 'en_us' for all users:
NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools. You will not be able to do this with the two Moodle report plugins.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT quiz.id,quiz.name, q.id, q.name
UPDATE prefix_user SET lang = 'en_us' WHERE lang = 'en'
FROM mdl_quiz AS quiz
</syntaxhighlight>
JOIN mdl_question AS q ON FIND_IN_SET(q.id, quiz.questions)
 
WHERE quiz.course = %%COURSEID%%
To do this for only users who have a particular country set, use this as an example:
ORDER BY quiz.id ASC
<syntaxhighlight lang="sql">
UPDATE prefix_user SET lang = 'en_us' WHERE country = 'US' AND lang = 'en'
</syntaxhighlight>
</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.
=== List of users with Authentication ===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]


Here is a version for Moodle 3.x
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:
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT cm.id 'cmid', quiz.id 'quiz id'
SELECT username, auth from prefix_user
,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>
</syntaxhighlight>


===Quiz activity research===
NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools.
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)
 
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.)


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
UPDATE prefix_user SET auth = 'ldap' WHERE auth = 'manual' AND id > 2
cm.course "course_id", cm.id "moduel_id", q.id "quiz_id", q.name "quiz_name",
</syntaxhighlight>
 
===Course Aggregation Report===
Contributed by Elizabeth Dalton, Granite State College


CASE q.grademethod
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.
      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"
In particular, be on the lookout for any courses with the following combinations of parameters, which are known to cause changes in calculations:
, 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
# mean of grades set with aggregate with subcategory.
JOIN mdl_course_modules as cm ON cm.instance = q.id and cm.module = 14
# Simple weighted mean of grades with aggregate with sub category and drop the lowest
JOIN mdl_quiz_attempts qa ON q.id = qa.quiz
# Sum of grades drop the lowest
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===
Also review:
Contributed by Elizabeth Dalton, Granite State College
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


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.
<syntaxhighlight lang="sql">
SELECT


"Multiple Choice" questions include true/false and matching question types.
COUNT(c.shortname) AS 'Count of Courses'


"Short Answer" are questions that accept a single phrase.
# 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'


"Other" questions include fixed numerical, calculated, essay, and various drag and drop types.
# 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'


"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.
, gc.aggregation AS 'aggregation method'


'''Note''': In Configurable Reports, the Date Filter is not applied until the "Apply" button is clicked.
#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
<syntaxhighlight lang="sql">
  WHEN 0 THEN 'Mean of Grades'
SELECT
  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'


c.shortname AS 'Course'
# 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
#, u.lastname AS 'Instructor'
, gc.keephigh AS 'keep high'
, COUNT(DISTINCT q.id) AS 'Quizzes'
, gc.droplow AS 'dr0p low'
, COUNT(DISTINCT qu.id) AS 'Questions'
, gc.aggregateonlygraded AS 'Aggregate only graded'
, SUM(IF (qu.qtype = 'multichoice', 1, 0 )) + SUM(IF (qu.qtype = 'truefalse', 1, 0 )) + SUM(IF (qu.qtype = 'match', 1, 0 ))  AS 'multichoice'
, gc.aggregateoutcomes AS 'aggregate outcomes'
, gc.aggregatesubcats AS 'aggregate subcategories'


, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'
# 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'


, 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'
# 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'


, (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'
FROM


#, SUM(IF (qu.qtype = 'numerical', 1, 0 )) AS 'numerical'
prefix_course AS c
#, SUM(IF (qu.qtype LIKE 'calc%', 1, 0 )) AS 'calculated'
JOIN prefix_grade_categories AS gc ON gc.courseid = c.id
#, SUM(IF (qu.qtype = 'random', 1, 0 )) AS 'random'
JOIN prefix_course_categories AS cc ON cc.id = c.category
#, SUM(IF (qu.qtype = 'shortanswer', 1, 0 )) AS 'shortanswer'
#, SUM(IF (qu.qtype = 'essay', 1, 0 )) AS 'essay'


#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


, IF(q.shufflequestions > 0,'Yes','No') AS 'Randomized Questions'
WHERE
, IF(q.shuffleanswers > 0,'Yes','No') AS 'Randomized Answers'
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


#, 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'
GROUP BY gc.aggregation, gc.keephigh, gc.droplow, gc.aggregateonlygraded, gc.aggregateoutcomes, gc.aggregatesubcats


, MIN(DATEDIFF(FROM_UNIXTIME(c.startdate),FROM_UNIXTIME(q.timemodified))) AS 'Min Quiz Age'
</syntaxhighlight>
, 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'
=== Running Cron jobs (task_scheduled) ===
<syntaxhighlight lang="sql">
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)
</syntaxhighlight>


FROM prefix_quiz AS q
=== Categories with id and name ===
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
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
1
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.startdate:<%%


GROUP BY c.id
This is intended to help with building the csv upload file for the Course upload process, where the category id number is required to identify the course category. It is a simple report with id and name of the category, and the id of its direct parent category. Known to work with 3.11.


ORDER BY c.shortname
<syntaxhighlight lang="sql">
SELECT
cat.id AS "Id",
cat.name AS "Category",
IF(cat.parent = 0,"0 (Top)",cat.parent) AS "Parent_id",
cat.path AS "Path_ids"
FROM prefix_course_categories cat
ORDER BY cat.id
</syntaxhighlight>
</syntaxhighlight>


===Student responses (answers) to quiz questions===
=== Flat file enrollments waiting for processing ===
(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.
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">
<syntaxhighlight lang="sql">
SELECT
SELECT
    concat( u.firstname, " ", u.lastname ) AS "Student Name",
u.username,
    u.id,
c.fullname AS "Course",
    quiza.userid,
ef.action,
    q.course,
r.shortname AS "Role",
    q.name,
DATE_FORMAT(FROM_UNIXTIME(ef.timestart),'%Y-%m-%d %H:%i')  AS "Enrolment Start",
    quiza.attempt,
DATE_FORMAT(FROM_UNIXTIME(ef.timeend),'%Y-%m-%d %H:%i')  AS "Enrolment End",
    qa.slot,
DATE_FORMAT(FROM_UNIXTIME(ef.timemodified),'%Y-%m-%d %H:%i') AS "Uploaded Date"
    que.questiontext AS 'Question',
 
    qa.rightanswer AS 'Correct Answer',
FROM prefix_enrol_flatfile ef
    qa.responsesummary AS 'Student Answer'
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


FROM mdl_quiz_attempts quiza
ORDER BY u.username
JOIN mdl_quiz q ON q.id=quiza.quiz
</syntaxhighlight>
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"
=== All Meta courses with Parent and Child course relationships ===
AND q.course = "17926"


ORDER BY quiza.userid, quiza.attempt, qa.slot
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
</syntaxhighlight>


===Questions which are tagged within a course/quiz===
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').
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">
<syntaxhighlight lang="sql">
SELECT
SELECT
    quiz.name AS quiz,
c.fullname AS 'Parent course name',
    t.rawname AS tag,
c.shortname AS 'Parent course shortname',
    CONCAT('<a target="_new" href="%%WWWROOT%%/mod/quiz/review.php?attempt=',
en.courseid AS 'Parent course id',
            MAX(quiza.id),'">',u.firstname,' ',u.lastname,'</a>') AS student,
(SELECT fullname FROM prefix_course WHERE prefix_course.id = en.customint1) As 'Child course name',
    CAST(SUM(qas.fraction) as decimal(12,1)) AS correct,
(SELECT shortname FROM prefix_course WHERE prefix_course.id = en.customint1) As 'Child course shortname',
    CAST(SUM(qa.maxmark) as decimal(12,1)) AS maximum,
en.customint1 AS 'Child course id'
    CAST(SUM(qas.fraction)/SUM(qa.maxmark)*100 as decimal(4,2)) AS score
FROM prefix_enrol en
FROM prefix_quiz_attempts quiza
JOIN prefix_course c ON c.id = en.courseid
JOIN prefix_user u ON quiza.userid = u.id
WHERE en.enrol = 'meta'
JOIN prefix_question_usages qu ON qu.id = quiza.uniqueid
ORDER BY c.fullname
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>
</syntaxhighlight>


==Resource Modules (Book, File, Folder, Label, Page, URL) ==
===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)
===List "Recently uploaded files"===
see what users are uploading
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT FROM_UNIXTIME(time,'%Y %M %D %h:%i:%s') as time ,ip,userid,url,info
SELECT CONCAT( 'rm -f /var/moodledatanew/filedir/', SUBSTRING( contenthash, 1, 2 ) , '/', SUBSTRING( contenthash, 3, 2 ) , '/', contenthash )
FROM `prefix_log`
FROM `mdl_files`
WHERE `action` LIKE 'upload'
WHERE `filename` LIKE '%mbz%'
ORDER BY `prefix_log`.`time`  DESC
AND filearea = 'automated'
</syntaxhighlight>
</syntaxhighlight>


===List Courses that loaded a specific file: "X"===
Find out how much disk space is used by all automated backup files:
Did the Teacher (probably) uploaded course's Syllabus ?
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT c.id, c.fullname  FROM `prefix_log` as l
SELECT SUM(filesize)/(1024*1024*1024) FROM `mdl_files` WHERE `filename` LIKE '%mbz%' AND filearea =  'automated'
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>
</syntaxhighlight>


===All resources that link to some specific external website===
==LOG REPORTS==
+ link to course
 
+ who's the teacher
=== Logs Skeleton Report Containing All Log Columns ===
+ link to external resource
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton].
 
This query contains all the columns in the standard log table (as of Moodle 3.11 anyway). You can use this to uncomment the various fields that you want to have in a report. I have uncommented a few common columns (id, action, target, userid, courseid, etc.) so you can see how it works as well as adding some useful things such as grabbing user and course names, formatting times, etc. Note also: when commenting and uncomment near the end, be sure to take care with your final commas :)
 
'''WARNING:''' Do NOT use this query as is on the live site unless you are sure you know what you are doing! Logs can get really big and a log query could take a long time to run. Always add something to the WHERE clause or use other means to limit the results to what you really need.
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
l.id,
,c.shortname,r.name
# l.eventname,
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
# l.component,
FROM prefix_role_assignments AS ra
l.action,
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
l.target,
JOIN prefix_user AS u ON u.id = ra.userid
# l.objecttable,
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
# l.objectid,
,concat('<a target="_new" href="%%WWWROOT%%/mod/resource/view.php?id=',r.id,'">',r.name,'</a>') AS Resource
# l.crud,
FROM prefix_resource AS r
# l.edulevel,
JOIN prefix_course AS c ON r.course = c.id
# l.contextid,
WHERE r.reference LIKE 'http://info.oranim.ac.il/home%'
# l.contextlevel,
# l.contextinstanceid,
l.userid,
# (SELECT username FROM prefix_user WHERE id = l.userid) As "User" ,
l.courseid,
# CASE l.courseid
#  WHEN 0 THEN 'Not logged in'
#  WHEN 1 THEN 'Front page'
#  ELSE (SELECT shortname FROM prefix_course WHERE id = l.courseid)
# END AS "Course_Name" ,
# l.relateduserid,
# (SELECT username FROM prefix_user WHERE id = l.relateduserid) As "Related_User" ,
# l.anonymous,
# l.other,
# l.timecreated,
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%Y-%m-%d %H:%i') AS "Time_UTC"
# l.origin,
# l.ip,
# l.realuserid
 
FROM prefix_logstore_standard_log l
# you really want to add a WHERE clause to limit your results to your specific object to look for eg course, user, time frame etc
# WHERE something = something
 
# Sorting: TIP - time created seems more accurate than id oddly for the actual sequencing due to the way the events are logged
ORDER BY l.timecreated
</syntaxhighlight>
</syntaxhighlight>


==="Compose Web Page" RESOURCE count===
===Course Creation and Restore Times===
 
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
Versions: known to work in Moodle 3.8 to 3.11
 
When a course is created, the time and the person creating the course are logged by the event system, and the course itself also contains this time. However, when a course is restored, unfortunately, the course creation time is not updated to the time of the restore, but retains the time created for the original course you are restoring from. This can create lots of false data for course creation times ([https://moodle.org/mod/forum/discuss.php?d=415162 as discussed in this forum conversation] and [https://tracker.moodle.org/browse/MDL-70467 Tracker 70467].)
 
This report shows the actual creation time of all courses in your logs, whether created anew or restored, with the time and the user creating/restoring them. It also handles the cases where courses have been deleted or the user who created/restored them has been deleted as well.
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT course,prefix_course.fullname, COUNT(*) AS Total
SELECT
FROM `prefix_resource`
l.id AS "Log_id",
JOIN `prefix_course` ON prefix_course.id = prefix_resource.course
IF(c.id IS NULL,CONCAT("(deleted id: ",l.courseid, ")"),c.shortname) AS "Course",
WHERE type='html'
IF(l.action='restored',"Restored","Created") AS "Action",
GROUP BY course
IF(u.id IS NULL,CONCAT("deleted id: ",l.userid, ")"),u.username) As "By",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%Y-%m-%d %H:%i') AS "At_UTC"
FROM prefix_logstore_standard_log l
LEFT JOIN prefix_course c ON c.id = l.courseid
LEFT JOIN prefix_user u ON u.id = l.userid
WHERE l.eventname = '\\core\\event\\course_created'  
OR l.eventname = '\\core\\event\\course_restored'
</syntaxhighlight>
</syntaxhighlight>


===Resource count in courses===
===Distinct user logins per month===
+ (First)Teacher name
 
+ Where course is inside some specific Categories
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.
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
COUNT(*) AS count
COUNT(DISTINCT l.userid) AS 'DistinctUserLogins',
,r.course
DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%M') AS 'Month'
,c.shortname shortname
FROM prefix_logstore_standard_log l
,c.fullname coursename
WHERE l.action = 'loggedin' AND YEAR(FROM_UNIXTIME(l.timecreated)) = '2017'
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
GROUP BY MONTH(FROM_UNIXTIME(l.timecreated))
  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>
</syntaxhighlight>


===Delete all the automated backup files===
===Total activity per course, per unique user on the last 24h===
Prepare bash cli script to delete all the automated backup files on the file system. (clean up some disk space)
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT CONCAT( 'rm -f /var/moodledatanew/filedir/', SUBSTRING( contenthash, 1, 2 ) , '/', SUBSTRING( contenthash, 3, 2 ) , '/', contenthash )
SELECT
FROM `mdl_files`
    COUNT(DISTINCT userid) AS countUsers
WHERE `filename` LIKE '%mbz%'
  , COUNT(l.courseid) AS countVisits
AND filearea = 'automated'
  , CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">', c.fullname, '</a>') AS Course
</syntaxhighlight>


Find out how much disk space is used by all automated backup files:
FROM mdl_logstore_standard_log AS l
<syntaxhighlight lang="sql">
  JOIN mdl_course AS c ON c.id = l.courseid
SELECT SUM(filesize)/(1024*1024*1024) FROM `mdl_files` WHERE  `filename` LIKE '%mbz%' AND filearea =  'automated'
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
</syntaxhighlight>
</syntaxhighlight>


===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.


==SCORM Activity==
'''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.


===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.
'''Note''': Post-2.7 log version:


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


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


, cc.name AS 'Category'
, FROM_UNIXTIME(c.startdate) AS Course_Start_Date
, 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'


, c.visible AS Visible


FROM prefix_course_modules AS cm
,  COUNT(DISTINCT l.id) AS Edits
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
, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
JOIN prefix_course_categories AS cc ON cc.id = c.category
JOIN prefix_scorm AS scm ON scm.id = cm.instance


WHERE
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
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'
%%FILTER_STARTTIME:c.startdate:>%%
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=3,l.id,NULL)) AS 'Week 4'
%%FILTER_ENDTIME:c.startdate:<%%
, 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'


GROUP BY c.shortname, m.name
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'
ORDER BY c.startdate, c.shortname
</syntaxhighlight>


, 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


===How many SCORM activities are used in each Course===
FROM prefix_user AS u
<syntaxhighlight lang="sql">
LEFT JOIN prefix_role_assignments AS ra ON u.id = ra.userid
SELECT cm.course,c.fullname ,m.name
LEFT JOIN prefix_context AS ctx ON ra.contextid = ctx.id
,concat('<a target="_new" href="%%WWWROOT%%/mod/scorm/index.php?id=',c.id,'">',count(cm.id),'</a>') AS Counter
LEFT JOIN prefix_course AS c ON c.id = ctx.instanceid
LEFT JOIN prefix_course_categories as cc ON c.category = cc.id


FROM `prefix_course_modules` as cm
LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id AND l.crud IN ('c','u')
  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>


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


===Lists All completed SCORM activites by Course name===
GROUP BY u.idnumber, c.id
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.
#HAVING students > 0
<syntaxhighlight lang="sql">
ORDER BY RIGHT(c.shortname,2), c.shortname
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>
</syntaxhighlight>


===Lists SCORM status for all enrolled users by Course name===
===Weekly Student Online Participation===
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.
Contributed by Elizabeth Dalton, Granite State College
<syntaxhighlight lang="sql">
 
SELECT
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).
u.firstname AS First,
 
u.lastname AS Last,
Links to three other reports are also provided:
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
* Logs: complete log entries for the student in the course, organized by date
JOIN prefix_user AS u ON st.userid=u.id
* Activity Outline: the "Outline Report" from the User Activity Reports, summarizing the student's activity in the course, organized by course content
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
* 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)
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
'''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.


UNION
'''Note''': Post-2.7 (Standard Logs) version


<syntaxhighlight lang="sql">
SELECT
SELECT
user2.firstname AS First,
u.lastname AS 'Last Name'
user2.lastname AS Last,
, u.firstname AS 'First Name'
user2. idnumber AS Employee_ID,
, COUNT(l.id) AS 'Edits'
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
, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
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
, 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'


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


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


===Site-wide completed SCORM activities by Course name===
, 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'
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>


==Survey Activity==
, 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'


There are no reports yet for the Survey activity.
, 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'


== Wiki 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


===Course wiki usage/activity over the last 6 semesters===
# student academic coach - you can include custom profile field data with these methods
<syntaxhighlight lang="sql">
# LEFT JOIN prefix_user_info_data as uid ON u.id = uid.userid AND uid.fieldid = '2'
SELECT "Courses with Wikis"
# student academic coach email
# LEFT JOIN prefix_user_info_data as uce on u.id = uce.userid AND uce.fieldid = '6'


,(SELECT count( m.name ) AS count FROM
LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id AND l.crud IN ('c','u')
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
WHERE ra.roleid =5
prefix_course_modules AS cm
AND ctx.instanceid = c.id
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
AND c.id = %%COURSEID%%
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
GROUP BY u.idnumber
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 u.lastname, u.firstname
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
===My Weekly Online Participation===
prefix_course_modules AS cm
Contributed by Elizabeth Dalton, Granite State College
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
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).
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
This report uses Standard Logs (post 2.7).
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/> סמסטר ב'
</syntaxhighlight>


===Detailed WIKI activity (per wiki per course)===
Including Number of Students in course (for reference)
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID
SELECT
,(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
</syntaxhighlight>


===Wiki usage, system wide===
l.component AS 'activity'
(you can filter the output by selecting some specific course categories : "WHERE c.category IN ( 8,13,15)")


<syntaxhighlight lang="sql">
, COUNT(DISTINCT IF((l.timecreated-c.startdate)<0,l.id,NULL)) AS 'Before Term'
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
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=0,l.id,NULL)) AS 'Week 1'
JOIN prefix_modules AS m ON cm.module = m.id
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))=1,l.id,NULL)) AS 'Week 2'
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
, 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'


,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%') AS 'WikiActivity<br/>ALL'
, COUNT(DISTINCT IF(FLOOR((l.timecreated - c.startdate)/(60*60*24*7))>=12,l.id,NULL)) AS 'After Term'


,(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'
, COUNT(l.id) AS 'Total'


,(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'
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


,(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'
LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id AND l.crud IN ('c','u')


,(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'
WHERE 1
AND ctx.instanceid = c.id


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


,(SELECT count(*) FROM prefix_ouwiki_pages as ouwp
GROUP BY l.component
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
ORDER BY l.component
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>
</syntaxhighlight>


==Workshop Activity==
===Faculty/Student Interactions===
Contributed by Elizabeth Dalton, Granite State College


There are currently no reports for the Workshop activity.
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.


==Other Third Party Activities==
'''Note''': This should be defined as a "Global" report (visible from within all courses).


This is the section for non-core, contributed third party activity and resource plugin modules.
'''Note''': This report can take a long time to run.


=== Elluminate (Blackboard Collaborate) - system wide usage===


Editor's note: This is for the [https://moodle.org/plugins/mod_collaborate Blackboard Collaborate plugin].
<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'


<syntaxhighlight lang="sql">
, 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'
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
, 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'
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
</syntaxhighlight>


===List all the certificates issued, sort by variables in the custom profile fields===
## Only posts within last 7 days


Editor note: This is for the [https://moodle.org/plugins/mod_certificate classic Certificate module], no longer maintained since Moodle 3.3
# Count posts by student
, COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL)) AS 'Forum Stu Posts - 7 days'


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.
# 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'


<syntaxhighlight lang="sql">
# using link back to student posts on replies, get unique student IDs responded
SELECT
, 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'
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
# all replies
prefix_certificate_issues
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpsr.id,NULL)) AS 'Forum All Replies - 7 days'


INNER JOIN prefix_user_info_data
# add in count of graded assignments - 7 days
on prefix_certificate_issues.userid = prefix_user_info_data.userid
, 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'


INNER JOIN prefix_certificate
# Messages between students and instructors - 7 days
on prefix_certificate_issues.certificateid = prefix_certificate.id
,  (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'


WHERE prefix_user_info_data.data='Unit 1'
## All posts in course so far
OR prefix_user_info_data.data='Unit 2'
# Count posts by student
OR prefix_user_info_data.data='Unit 3'
, COUNT(DISTINCT fps.id) AS 'Forum Stu Posts - to date'


ORDER BY Units, Name, Topic ASC
# Count replies to student posts by instructors
</syntaxhighlight>
, COUNT(DISTINCT fpi.id) AS 'Forum Instr Replies - to date'


=== All Simple Certificates Earned in the Site===
# 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'


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
# all replies
, COUNT(DISTINCT fpsr.id) AS 'Forum All Replies - to date'


Basic report of all certificates earned with [https://moodle.org/plugins/mod_simplecertificate the Simple Certificate plugin module] in the whole site, sorted by most recent first.
# 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'


<syntaxhighlight lang="sql">
# Messages between students and instructors - to date
SELECT
,  (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'
CONCAT (u.firstname, ' ',u.lastname) As 'User',
, (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'
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
</syntaxhighlight>


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:
## JOINS
<syntaxhighlight lang="sql">
WHERE DATEDIFF(NOW(),FROM_UNIXTIME(sci.timecreated) ) < 30
</syntaxhighlight>


# 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


===Student's posts content in all course blogs (oublog)===
# 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


Editor's Note: This query is specific to the [https://moodle.org/plugins/mod_oublog plugin OU Blog] not the standard Moodle blog tool.
# 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


<syntaxhighlight lang="sql">
# Separately, we connect the instructors of the courses
SELECT
# We can use the context we have already gotten for the students
b.name
LEFT JOIN prefix_role_assignments AS rai ON rai.contextid = ctx.id
,op.title
LEFT JOIN prefix_user AS instr ON instr.id = rai.userid AND rai.roleid =3
,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
# Now we will connect to posts by instructors that are replies to student posts
JOIN prefix_oublog_instances AS oi ON oi.id = op.oubloginstancesid
# This is a left join, because we don't want to eliminate any students from the list
JOIN prefix_oublog as b ON b.id = oi.oublogid
LEFT JOIN prefix_forum_posts AS fpi ON fpi.discussion = fd.id AND fpi.userid = instr.id AND fpi.parent = fps.id
JOIN prefix_course AS c ON b.course = c.id


WHERE c.id = %%COURSEID%%
# To get identities of only those students who were replied to:
</syntaxhighlight>
# 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


== Badges==
# 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


=== All badges issued, by User ===
# get the activity modules
LEFT JOIN prefix_course_modules AS cm ON c.id = cm.course


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
# 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


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.
# 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


<syntaxhighlight lang="sql">
WHERE
SELECT u.username, b.name AS badgename,
c.id = %%COURSEID%%
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>


=== All badges available in the system, with Earned count ===
# GROUP BY c.shortname , allstu.id
GROUP BY allstu.id


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
ORDER BY allstu.lastname
</syntaxhighlight>


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.
'''Note''': Post-2.7 Standard Logs version


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT b.id, b.name, b.description,
SELECT
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>
# 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'


=== Badges Leaderboard ===
, 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: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
, 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'


A simple list of usernames and how many badges they have earned overall.
## Only posts within last 7 days


<syntaxhighlight lang="sql">
# Count posts by student
SELECT u.username, (SELECT COUNT(*) FROM prefix_badge_issued AS d WHERE d.userid = u.id) AS earned
, COUNT(DISTINCT IF(fps.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fps.id,NULL)) AS 'Forum Stu Posts - 7 days'
FROM prefix_user AS u
ORDER BY earned DESC, u.username ASC
</syntaxhighlight>


=== Manage badges (System & Course) ===
# 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'


List system wide badges, course and system level badges + a link to relevant "manage badges" page.
# 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'


<syntaxhighlight lang="sql">
# all replies
SELECT b.id, b.name, b.description
, COUNT(DISTINCT IF(fpsr.created > (UNIX_TIMESTAMP()  - (7*24*60*60)),fpsr.id,NULL)) AS 'Forum All Replies - 7 days'
,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==
# 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'


===Config changes in Export friendly form===
# 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'


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
## All posts in course so far
# Count posts by student
, COUNT(DISTINCT fps.id) AS 'Forum Stu Posts - to date'


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.
# Count replies to student posts by instructors
, COUNT(DISTINCT fpi.id) AS 'Forum Instr Replies - to date'


<syntaxhighlight lang="sql">
# using link back to student posts on replies, get unique student IDs responded
SELECT
, COUNT(DISTINCT fpsr.id) - COUNT(DISTINCT fpi.id) AS 'Forum Stu Replies - to date'
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===
# 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'


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
## JOINS


How to get a list of all users and which cohorts they belong to.
# 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


<syntaxhighlight lang="sql">
# Now we get the forums and forum discussions from this course only
SELECT u.firstname, u.lastname, h.idnumber, h.name
JOIN prefix_forum AS frm ON frm.course = c.id AND c.id = %%COURSEID%%
FROM prefix_cohort AS h
JOIN prefix_forum_discussions AS fd ON fd.course = %%COURSEID%% AND fd.forum = frm.id
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===
# 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


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
# 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


List of all cohorts with name, id, visibility, and which courses they are enrolled in.
# 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


<syntaxhighlight lang="sql">
# To get identities of only those students who were replied to:
SELECT
# Connect from instr replies back up to parent posts by students again
# h.id,
# This has to be a LEFT JOIN, we know these posts exist but don't eliminate non-responded students
# e.customint1,
LEFT JOIN prefix_forum_posts AS fpir ON fpir.id = fpi.parent
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===
# We also want to know if students are replying to one another
Active courses is counting course that have at least one Hit, And "Active_MoreThan100Hits" counts courses that have at least 100 Hits
# These are posts that are replies to student posts
<syntaxhighlight lang="sql">
# Again, a left join
SELECT
LEFT JOIN prefix_forum_posts AS fpsr ON fpsr.discussion = fd.id AND fpsr.parent = fps.id


YEAR( FROM_UNIXTIME( `timecreated` ) ) AS YEAR, COUNT( * ) AS Counter
# get the activity modules
JOIN prefix_course_modules AS cm ON c.id = cm.course


, (SELECT COUNT( DISTINCT course )
# get the assignments
FROM prefix_log AS l
JOIN prefix_assign AS a ON  cm.instance = a.id
WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
LEFT JOIN prefix_assign_submission AS asb ON a.id = asb.assignment AND asb.userid=allstu.id
) AS "Active"
LEFT JOIN prefix_assign_grades AS asg ON asg.assignment = a.id AND asg.userid = allstu.id AND asg.assignment = asb.assignment


,(SELECT COUNT(*) FROM (
WHERE
SELECT COUNT( * ),time
c.id = %%COURSEID%%
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 c.shortname , allstu.id
GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )
GROUP BY allstu.id
</syntaxhighlight>


===Users created And Active users by Year===
ORDER BY allstu.lastname
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>
</syntaxhighlight>


===Course Aggregation Report===
===Student Resource Usage===
Contributed by Elizabeth Dalton, Granite State College
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.
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+.


In particular, be on the lookout for any courses with the following combinations of parameters, which are known to cause changes in calculations:
'''Note''': This should be defined as a "Global" report (visible from within all courses).


# mean of grades set with aggregate with subcategory.
<syntaxhighlight lang="sql">
# Simple weighted mean of grades with aggregate with sub category and drop the lowest
SELECT
# Sum of grades drop the lowest
cs.section AS 'Week'
, cs.name AS 'Section Name'
, m.name AS 'item type'


Also review:
, CONCAT(
https://tracker.moodle.org/browse/MDL-48618
COALESCE(a.name, ''),
https://tracker.moodle.org/browse/MDL-48634
COALESCE(b.name,''),
https://tracker.moodle.org/browse/MDL-49257
COALESCE(cert.name,''),
https://tracker.moodle.org/browse/MDL-50089
COALESCE(chat.name,''),
https://tracker.moodle.org/browse/MDL-50062
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'


<syntaxhighlight lang="sql">
SELECT


COUNT(c.shortname) AS 'Count of Courses'
, 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'


# If you want to display all the courses for each aggregation type, uncomment the next line and change GROUP BY settings
FROM prefix_user AS u
#, c.shortname AS 'course name'
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


# If you need to display grade categories for each aggregation type, uncomment the next line and change GROUP BY settings
JOIN prefix_course_sections AS cs ON cs.course = c.id AND cs.section <= 14 #AND cs.section > 0
#, gc.fullname AS 'grade category name'
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'


, gc.aggregation AS 'aggregation method'
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'
#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.
LEFT JOIN prefix_certificate AS cert ON cert.id = cm.instance AND m.name = 'certificate'
, CASE gc.aggregation
LEFT JOIN prefix_chat AS chat ON chat.id = cm.instance AND m.name = 'chat'
  WHEN 0 THEN 'Mean of Grades'
LEFT JOIN prefix_choice AS choice ON choice.id = cm.instance AND m.name = 'choice'
  WHEN 2 THEN 'Median of Grades'
LEFT JOIN prefix_data AS data ON data.id = cm.instance AND m.name = 'data'
  WHEN 6 THEN 'Highest Grade'
LEFT JOIN prefix_feedback AS feedback ON feedback.id = cm.instance AND m.name = 'feedback'
  WHEN 8 THEN 'Mode of Grades'
LEFT JOIN prefix_folder AS folder ON folder.id = cm.instance AND m.name = 'folder'
  WHEN 10 THEN 'Weighted Mean of Grades'
LEFT JOIN prefix_forum AS forum ON forum.id = cm.instance AND m.name = 'forum'
  WHEN 11 THEN 'Simple Weighted Mean of Grades'
LEFT JOIN prefix_glossary AS glossary ON glossary.id = cm.instance AND m.name = 'glossary'
  WHEN 12 THEN 'Mean of Grades (with extra credits)'
LEFT JOIN prefix_imscp AS imscp ON imscp.id = cm.instance AND m.name = 'imscp'
  WHEN 13 THEN 'Sum of Grades'
LEFT JOIN prefix_lesson AS lesson ON lesson.id = cm.instance AND m.name = 'lesson'
END AS 'aggregation name'
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'
# 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
LEFT JOIN prefix_quiz AS quiz ON quiz.id = cm.instance AND m.name = 'quiz'
, gc.keephigh AS 'keep high'
LEFT JOIN prefix_resource AS cr ON cr.id = cm.instance AND m.name = 'resource'
, gc.droplow AS 'dr0p low'
LEFT JOIN prefix_scorm AS scorm ON scorm.id = cm.instance AND m.name = 'scorm'
, gc.aggregateonlygraded AS 'Aggregate only graded'
LEFT JOIN prefix_survey AS survey ON survey.id = cm.instance AND m.name = 'survey'
, gc.aggregateoutcomes AS 'aggregate outcomes'
LEFT JOIN prefix_url AS url ON url.id = cm.instance AND m.name = 'url'
, gc.aggregatesubcats AS 'aggregate subcategories'
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'


# If you are displaying data about individual courses, you may want to know how old they are
LEFT JOIN prefix_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id
#, 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
WHERE ra.roleid =5
AND ctx.instanceid = c.id
AND cs.visible = 1
AND cm.visible = 1


prefix_course AS c
AND c.id = %%COURSEID%%
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
GROUP BY cm.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


ORDER BY cs.section
</syntaxhighlight>
</syntaxhighlight>


=== Running Cron jobs (task_scheduled) ===
<syntaxhighlight lang="sql">
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)
</syntaxhighlight>


=== Categories with id and name ===


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


This is intended to help with building the csv upload file for the Course upload process, where the category id number is required to identify the course category. It is a simple report with id and name of the category, and the id of its direct parent category. Known to work with 3.11.
===Student Resource Usage for Standard Core Modules only===


<syntaxhighlight lang="sql">
Updated version contributed by [https://moodle.org/user/profile.php?id=88992 Randy Thornton], based on report above contributed by Elizabeth Dalton, Granite State College.
SELECT
cat.id AS "Id",
cat.name AS "Category",
IF(cat.parent = 0,"0 (Top)",cat.parent) AS "Parent_id",
cat.path AS "Path_ids"
FROM prefix_course_categories cat
ORDER BY cat.id
</syntaxhighlight>


=== Flat file enrollments waiting for processing ===
This is the same report as the above, but with thee changes so that it will work in any standard Moodle installation:


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
* all the non-core, third party activity module references have been removed
* the new core H5P Activity has been added
* shows all the data in all courses with the course shortname (however if you want to limit it to the current course, then uncomment the "# AND c.id = %%COURSEID%%" statement in the WHERE clause)


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.
Known to work in Moodle 3.11.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
u.username,
c.shortname AS "Course",
c.fullname AS "Course",
cs.section AS "Section",
ef.action,
cs.name AS "Section_Name",
r.shortname AS "Role",
m.name AS "Activity_Type",
DATE_FORMAT(FROM_UNIXTIME(ef.timestart),'%Y-%m-%d %H:%i') AS "Enrolment Start",
CONCAT(
DATE_FORMAT(FROM_UNIXTIME(ef.timeend),'%Y-%m-%d %H:%i') AS "Enrolment End",
COALESCE(a.name, ''),
DATE_FORMAT(FROM_UNIXTIME(ef.timemodified),'%Y-%m-%d %H:%i') AS "Uploaded Date"
COALESCE(b.name,''),
 
COALESCE(chat.name,''),
FROM prefix_enrol_flatfile ef
COALESCE(choice.name,''),
JOIN prefix_user u ON u.id = ef.userid
COALESCE(data.name,''),
JOIN prefix_course c ON c.id = ef.courseid
COALESCE(feedback.name,''),
JOIN prefix_role r ON r.id = ef.roleid
COALESCE(folder.name,''),
COALESCE(forum.name,''),
COALESCE(glossary.name,''),
COALESCE(h5pactivity.name,''),
COALESCE(imscp.name,''),
COALESCE(lesson.name,''),
COALESCE(p.name,''),
COALESCE(quiz.name,''),
COALESCE(cr.name,''),
COALESCE(scorm.name,''),
COALESCE(survey.name,''),
COALESCE(url.name,''),
COALESCE(wiki.name,''),
COALESCE(workshop.name,'')
) AS "Activity_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
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_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_h5pactivity AS h5pactivity ON h5pactivity.id = cm.instance AND m.name = 'h5pactivity'
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_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_logstore_standard_log AS l ON l.userid = u.id AND l.courseid = c.id


ORDER BY u.username
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 c.shortname, cs.section
</syntaxhighlight>
</syntaxhighlight>


=== All Meta courses with Parent and Child course relationships ===
===Module activity (Hits) between dates===
 
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">
<syntaxhighlight lang="sql">
SELECT
SELECT module, COUNT( * )
c.fullname AS 'Parent course name',
FROM prefix_logstore_standard_log AS l
c.shortname AS 'Parent course shortname',
WHERE (FROM_UNIXTIME( l.`timecreated` ) BETWEEN  '2018-10-01 00:00:00' AND  '2019-09-31 00:00:00')
en.courseid AS 'Parent course id',
GROUP BY module
(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>
</syntaxhighlight>


=== All Private Files by User ===
===Module activity (Instances and Hits) for each academic year===
<syntaxhighlight lang="sql">
SELECT name


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
,(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"


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 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"


<syntaxhighlight lang="sql">
,(SELECT COUNT(*)
SELECT
FROM prefix_logstore_standard_log AS l
u.username,
WHERE (FROM_UNIXTIME(l.`timecreated`) BETWEEN '2018-10-01 00:00:00' AND '2019-09-31 00:00:00')
f.filename,
AND l.module = m.name AND l.action = 'add'
CONCAT('/', LEFT(f.contenthash,2), '/', MID(f.contenthash,3,2), '/', f.contenthash) AS "Filedir_Location",
) AS "Added 2018"
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 ===
,(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"


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
,(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"


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.
,(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"


Note: this version includes the new H5P core activity in its list of modules.
FROM mdl_modules AS m
</syntaxhighlight>


===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)
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT COUNT(DISTINCT userid) AS "Unique User Logins"
t.name AS "Tag",
,DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y /%m / %d") AS "Year / Month / Day", "Graph"
CASE ti.itemtype
FROM `mdl_logstore_standard_log`
  WHEN 'course' THEN 'Course'
WHERE action LIKE 'loggedin'
  ELSE "Activity"
#AND timecreated >  UNIX_TIMESTAMP('2015-01-01 00:00:00') # optional start date
END AS "Tag_Type",
#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>
 
And...


# get the course name
Counting user's global and unique hits per day + counting individual usage of specific activities and resources (on that day),
CASE ti.itemtype
 
  WHEN 'course' THEN
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 CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',id,'">',shortname,'</a>') FROM prefix_course WHERE id = ti.itemid)
<syntaxhighlight lang="sql">
  ELSE
SELECT DATE_FORMAT(FROM_UNIXTIME(timecreated), "%y-%m-%d") AS "Datez"
  (SELECT CONCAT('<a target="_blank" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',id,'">',shortname,'</a>') FROM prefix_course WHERE id = cm.course)
,COUNT(DISTINCT userid) AS "Unique Users"
END AS "Course",
,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)"


# get the activity type
FROM `mdl_logstore_standard_log`
CASE ti.itemtype
WHERE 1=1
  WHEN 'course' THEN '-'
AND timecreated >  UNIX_TIMESTAMP('2015-03-01 00:00:00') # optional START DATE
  ELSE
AND timecreated <= UNIX_TIMESTAMP('2015-05-31 23:59:00') # optional END DATE
    # (SELECT CONCAT(name, ' (',cm.module,')') FROM prefix_modules WHERE id = cm.module)
GROUP BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
m.name
ORDER BY MONTH(FROM_UNIXTIME(timecreated)), DAY(FROM_UNIXTIME(timecreated))
END AS "Activity_Type",
</syntaxhighlight>


# get the activity name
===System wide, daily unique user hits for the last 7 days===
CASE ti.itemtype
<syntaxhighlight lang="sql">
  WHEN 'course' THEN '-'
SELECT
  ELSE
  DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%m%d') 'Day'
    CASE
  ,COUNT(DISTINCT l.userid) AS 'Distinct Users Hits'
    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)
  ,COUNT( l.userid) AS 'Users Hits'
    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
FROM prefix_logstore_standard_log AS l
CASE t.isstandard
WHERE l.courseid > 1
  WHEN 1 THEN 'Yes'
      AND FROM_UNIXTIME(l.timecreated) >= DATE_SUB(NOW(), INTERVAL 7 DAY)
  ELSE CONCAT('No (', (SELECT username FROM prefix_user WHERE id = t.userid),')')
GROUP BY DAY(FROM_UNIXTIME(timecreated))
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>
</syntaxhighlight>


== Learning Analytics Reports ==
===User detailed activity in course modules===
(Moodle v. 3.4 and later)
Considering only several modules: url, resource, forum, quiz, questionnaire.


=== Learning Analytics Model Summary ===
<syntaxhighlight lang="sql">
This report provides a list of the learning analytics models on your site, whether enabled or not, and several details about them.
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:<%%


(Note: this report was created on a system using PostgreSQL. Some changes may be needed for other forms of SQL.)
GROUP BY u.id, l.component
Contributed by Elizabeth Dalton, Moodle HQ
ORDER BY u.lastname, u.firstname
</syntaxhighlight>


===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.
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',
am.id AS "model id",
  course.id,'">',course.fullname,'</a>') AS Course
split_part(am.target,'\',5) AS "target",
 
CASE WHEN am.enabled=1 THEN 'YES' ELSE 'NO' END AS "enabled",
#,course.shortname
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
,CASE
JOIN prefix_analytics_predictions AS ap ON am.id = ap.modelid
  WHEN course.fullname LIKE '%2012%' THEN '2012'
LEFT JOIN prefix_analytics_models_log AS aml ON aml.modelid = am.id
  WHEN course.fullname LIKE '%2013%' THEN '2013'
LEFT JOIN prefix_analytics_prediction_actions AS apa ON apa.predictionid = ap.id
  WHEN course.fullname LIKE '%2014%' THEN '2014'
GROUP BY am.id, ap.prediction, apa.actionname
  WHEN course.fullname LIKE '%2015%' THEN '2015'
</syntaxhighlight>
END AS Year


=== Analytics Indicator Calculations ===
,CASE
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.
  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


<syntaxhighlight lang="sql">
,IF(course.startdate>0, DATE_FORMAT(FROM_UNIXTIME(startdate), '%d-%m-%Y'), 'no date') AS "Course Start Date"
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
,(SELECT COUNT( ra.userid ) AS Users
WHERE id = 1
FROM prefix_role_assignments AS ra
</syntaxhighlight>
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = course.id
) AS Students


===Analytics Models ===
,(SELECT COUNT( ra.userid ) AS Users
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.
FROM prefix_role_assignments AS ra
Contributed by Elizabeth Dalton, Moodle HQ
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 4 AND ctx.instanceid = course.id
) AS "Assistant teacher"


<syntaxhighlight lang="sql">
,(SELECT COUNT( ra.userid ) AS Users
SELECT
FROM prefix_role_assignments AS ra
id,
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
enabled,
WHERE ra.roleid = 3 AND ctx.instanceid = course.id
trained,
) AS Teachers
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
# Uncomment to use the new Moodle 2.8+ logstore
</syntaxhighlight>
#,(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"


=== Analytics Models Log ===
#,(SELECT COUNT(*)
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.
#FROM mdl_logstore_standard_log AS l
Contributed by Elizabeth Dalton, Moodle HQ
#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"


<syntaxhighlight lang="sql">
,(SELECT COUNT(*)
SELECT
FROM mdl_log AS l
id,
JOIN mdl_context AS con ON con.instanceid= l.course AND con.contextlevel=50
modelid,
JOIN mdl_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3
to_timestamp(version) AS "version",
WHERE l.course = course.id) AS "Teachers HITs"
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
,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) )
</syntaxhighlight>
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


=== Analytics Predictions ===
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = course.id) Modules
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 COUNT(DISTINCT cm.module) FROM prefix_course_modules cm
SELECT
  WHERE cm.course = course.id) UniqueModules
id,
 
modelid,
,(SELECT GROUP_CONCAT(DISTINCT m.name)
contextid,
  FROM prefix_course_modules cm
sampleid,
  JOIN mdl_modules as m ON m.id = cm.module
rangeindex,
  WHERE cm.course = course.id) UniqueModuleNames
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
,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
</syntaxhighlight>
  WHERE cm.course = course.id AND m.name IN ( 'ouwiki', 'wiki') ) "Num Wikis"


=== Analytics Prediction Actions ===
,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
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.
  WHERE cm.course = course.id AND m.name IN ( 'oublog') ) "Num Blogs"
Contributed by Elizabeth Dalton, Moodle HQ


<syntaxhighlight lang="sql">
,(SELECT COUNT(*) FROM mdl_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
SELECT
  WHERE cm.course = course.id AND m.name IN ( 'forum', 'forumng') ) "Num Forums"
id,
predictionid,
userid,
actionname,
to_timestamp(timecreated) AS "time created"


FROM prefix_analytics_prediction_actions
,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
</syntaxhighlight>
  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"


=== Analytics Predictions with All Indicators ===
,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
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.
  WHERE cm.course = course.id AND m.name IN ('advmindmap', 'assign', 'attendance', 'book', 'choice', 'folder', 'tab', 'glossary', 'questionnaire', 'quiz', 'label' ) ) "Avarage Activities"
Contributed by Elizabeth Dalton, Moodle HQ


<syntaxhighlight lang="sql">
,(SELECT COUNT(*) FROM prefix_course_modules cm JOIN mdl_modules as m ON m.id = cm.module
SELECT
  WHERE cm.course = course.id AND m.name IN ('elluminate', 'game', 'workshop') ) "Advanced Activities"
id AS "Prediction ID",
 
modelid AS "Model ID",
FROM prefix_course AS course
contextid AS "Context ID",
 
sampleid AS "Sample ID",
#WHERE course.shortname LIKE '%2015%'
rangeindex AS "Analysis Interval",
#WHERE 1=1
prediction AS "Prediction value",
#%%FILTER_SEARCHTEXT:course.shortname:~%%
predictionscore,
 
calculations,
WHERE course.fullname LIKE '%2015%'
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
HAVING Modules > 2
ORDER BY UniqueModules DESC
</syntaxhighlight>
</syntaxhighlight>


=== Analytics Predict Samples ===
===Weekly attendance report===
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.
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.
Contributed by Elizabeth Dalton, Moodle HQ
<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
 
WHERE (((arsess.logout) BETWEEN UNIX_TIMESTAMP(DATE_SUB(CURDATE(), INTERVAL 7 DAY)) AND UNIX_TIMESTAMP(CURDATE())))
 
GROUP BY arsess.userid
</syntaxhighlight>


===Annual course/attendance report===
This report is designed for a site where all students are always subscribed in every course divided in fix groups and where the lessons are organised by the teacher using the groups . The real participation is confirmed by the teacher. As also teachers are assigne to all courses, the teacher of a specific lesson is considered to be the user who created the lesson. An annual limitation parameter csnnot be added in this module, so I added a limitation to the current calendar year. Eventually a copy of the report is needed for the past year in order to be able to launch it in January, too.
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT CASE WHEN @date <> SESSION.sessdate OR NOT  @description = SESSION.description THEN @row := @row +1 ELSE @row END AS NR_CORSO,
id,
FROM_UNIXTIME(SESSION.sessdate, '%d/%m/%Y') as DATA, CODAGE.data as COD_AGENZIA, AGENZIA.data as AGENZIA,  
modelid,
CONCAT({user}.lastname, ' ', {user}.firstname) as NOMINATIVO, RUI.data as RUI, RUOLO.data as FUNZIONE,
analysableid,
REPLACE (
split_part(timesplitting,'\',5) AS "interval",
REPLACE (
rangeindex,
REPLACE (
/* sampleids, */
UNHEX( REPLACE( HEX( SESSION.description ), '3B', '' ) )
char_length(sampleids) - char_length(REPLACE(sampleids,',',''))+1 AS "samples used",
, '<p dir="ltr" style="text-align: left">', ''
to_timestamp(timecreated) AS "time created",
)
to_timestamp(timemodified) AS "time modified"
  ,  '</p>', '' )
  , '<br>', '' ) as INFO,
{course}.fullname as CORSO,
CASE WHEN upper({attendance}.name) like '%AULA%' THEN 'IN AULA' WHEN upper({attendance}.name) like '%LINE%' THEN 'WEBINAR' ELSE {attendance}.name END AS MODALITÀ_CORSO,
CONCAT(DOCENTE.lastname, ' ', DOCENTE.firstname) as DOCENTE, # ROUND(SESSION.duration/3600, 0) as ORE #, {groups}.name as Gruppo,
DURATA.charvalue as ORE, {groups}.name as Gruppo, UPPER(LEFT(RUI.data, 1)) as Categoria, STATUS.acronym as Partecipazione, # STATUS.grade ,  {user}.ID, {user}.username,
CASE WHEN {course_completions}.timecompleted is not null THEN 'SI' ELSE 'NO' END as COMPLETATO
,  @date := SESSION.sessdate AS DATUM, @description := SESSION.description AS INFO_LEZIONE, SESSION.id


FROM prefix_analytics_predict_samples
FROM {attendance_sessions}  SESSION JOIN (SELECT @row := 0, @date := 0, @description := null) TEMP
LEFT JOIN {attendance} ON {attendance}.id = SESSION.attendanceid
LEFT JOIN {attendance_log} LOG ON LOG.sessionid = SESSION.id # AND LOG.studentid = {user}.id
LEFT JOIN {attendance_statuses} STATUS ON STATUS.id = LOG.statusid
LEFT JOIN {course_completions} ON {course_completions}.userid = LOG.studentid AND {course_completions}.course = {attendance}.course
LEFT JOIN {groups} ON {groups}.id = SESSION.groupid
LEFT JOIN {user} ON {user}.id = LOG.studentid
LEFT JOIN {user_info_data} AGENZIA ON AGENZIA.userid = {user}.id AND AGENZIA.fieldid = 3  # AGENZIA
LEFT JOIN {user_info_data} RUI ON RUI.userid = {user}.id AND RUI.fieldid = 2    #  RUI
LEFT JOIN {user_info_data} RUOLO ON RUOLO.userid = {user}.id AND RUOLO.fieldid = 5    #  FUNZIONE
LEFT JOIN {user_info_data} CODAGE ON CODAGE.userid = {user}.id AND CODAGE.fieldid = 6    #  COD_AGE
LEFT JOIN {course}  ON {course}.id = {attendance}.course
LEFT JOIN {event} ON {event}.id = SESSION.caleventid
LEFT JOIN {user} DOCENTE ON DOCENTE.id = {event}.userid
LEFT JOIN {customfield_data} DURATA ON  INSTANCEID = {course}.id AND DURATA.FIELDID = 3 # DURATA
WHERE NVL(STATUS.grade, 0) > 1  #  per filtrare i soli presenti
  AND FROM_UNIXTIME(SESSION.sessdate, '%d/%m/%Y') > CONCAT('01/01/', YEAR(CURDATE()))
</syntaxhighlight>
</syntaxhighlight>


=== Analytics Train Samples ===
===How many distinct users connected to Moodle using the app by month===
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.
https://moodle.org/mod/forum/discuss.php?d=336086#p1354194 by
Contributed by Elizabeth Dalton, Moodle HQ
Iñigo Zendegi Urzelai
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
SELECT
id,
  to_char(to_timestamp("timecreated"),'YYYY') as year,
modelid,
  to_char(to_timestamp("timecreated"),'MM') as month,
analysableid,
  count(distinct userid) as distinct_users
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
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');
</syntaxhighlight>
</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">
==LEARNING ANALYTICS REPORTS==
SELECT
(Moodle v. 3.4 and later)
id,
modelid,
action,
analysableid,
to_timestamp(firstanalysis) AS "first analysis",
to_timestamp(timeanalysed) AS "time analysed"


FROM prefix_analytics_used_analysables
=== Learning Analytics Model Summary ===
</syntaxhighlight>
This report provides a list of the learning analytics models on your site, whether enabled or not, and several details about them.


=== Analytics Used Files ===
(Note: this report was created on a system using PostgreSQL. Some changes may be needed for other forms of SQL.)
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
Contributed by Elizabeth Dalton, Moodle HQ


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT
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"


id,
FROM prefix_analytics_models AS am
modelid,
JOIN prefix_analytics_predictions AS ap ON am.id = ap.modelid
fileid,
LEFT JOIN prefix_analytics_models_log AS aml ON aml.modelid = am.id
action,
LEFT JOIN prefix_analytics_prediction_actions AS apa ON apa.predictionid = ap.id
TO_TIMESTAMP(time) AS Time
GROUP BY am.id, ap.prediction, apa.actionname
 
FROM prefix_analytics_used_files
</syntaxhighlight>
</syntaxhighlight>


===Average Cognitive Depth and Social Breadth===
=== 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.
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">
<syntaxhighlight lang="sql">
SELECT
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"


i.contextid,
FROM prefix_analytics_indicator_calc
i.sampleid,
WHERE id = 1
</syntaxhighlight>


TRUNC(AVG(CASE
===Analytics Models ===
WHEN i.indicator LIKE '%cognitive%' THEN i.value
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.
ELSE '0'
Contributed by Elizabeth Dalton, Moodle HQ
END),2) AS "Average Cognitive Depth",


TRUNC(AVG(CASE
<syntaxhighlight lang="sql">
WHEN i.indicator LIKE '%social%' THEN i.value
SELECT
ELSE '0'
id,
END),2) AS "Average Social Breadth"
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_indicator_calc as i
FROM prefix_analytics_models
WHERE
i.value != 0
GROUP BY i.contextid, i.sampleid
</syntaxhighlight>
</syntaxhighlight>


==Competencies==


===List of competencies from a framework and the courses including them===
=== Analytics Models Log ===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
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">
<syntaxhighlight lang="sql">
SELECT
SELECT
f.shortname AS 'Framework',
id,
comp.shortname AS 'Competency',
modelid,
cccomp.courseid AS 'Course id',
to_timestamp(version) AS "version",
c.fullname AS 'Course name',
evaluationmode,
c.shortname AS 'Course code'
split_part(target,'\',5) AS "target",
FROM
/* indicators,*/
prefix_competency_coursecomp AS cccomp
char_length(indicators) - char_length(REPLACE(indicators,',',''))+1 AS "indicator count",
INNER JOIN prefix_competency AS comp ON cccomp.competencyid = comp.id
split_part(timesplitting,'\',5) AS "interval",
INNER JOIN prefix_course AS c ON cccomp.courseid = c.id
score,
INNER JOIN prefix_competency_framework AS f ON comp.competencyframeworkid = f.id
info,
dir,
to_timestamp(timecreated) AS "time created",
usermodified
 
FROM prefix_analytics_models_log
</syntaxhighlight>
</syntaxhighlight>


===Count the courses using each competency from frameworks===
=== Analytics Predictions ===
Contributed by [https://moodle.org/user/profile.php?id=2049965 François Parlant]
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


Unfortunately, there is not a filter by competency framework.
<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"


<syntaxhighlight lang="sql">
from prefix_analytics_predictions
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>
</syntaxhighlight>


 
=== Analytics Prediction Actions ===
=== Scale details with ids ===
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
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">
<syntaxhighlight lang="sql">
SELECT
SELECT
s.id AS Scaleid,
id,
s.name AS Scale_Name,
predictionid,
s.scale AS Scale,
userid,
CASE
actionname,
  WHEN s.courseid = 0 THEN 'System'
to_timestamp(timecreated) AS "time created"
  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


FROM prefix_analytics_prediction_actions
</syntaxhighlight>
</syntaxhighlight>


== Other Useful Things==


Below are some sections on other items useful for building and using the reports.
=== 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"


===Sub queries and code snippets===
from prefix_analytics_predictions
</syntaxhighlight>


In this section please put any short one purpose sub queries that show how common procedures often useful as part of larger queries.
=== 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.
==== All teachers or students in the course ====
Contributed by Elizabeth Dalton, Moodle HQ
 
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. If you change the number to 5, it will list Students instead.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
,(SELECT GROUP_CONCAT( CONCAT( u.firstname, " ", u.lastname ) )
SELECT
FROM prefix_course ic
id,
JOIN prefix_context con ON con.instanceid = ic.id
modelid,
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
analysableid,
JOIN prefix_role r ON ra.roleid = r.id
split_part(timesplitting,'\',5) AS "interval",
JOIN prefix_user u ON u.id = ra.userid
rangeindex,
WHERE r.id = 3 AND ic.id = c.id
/* sampleids, */
GROUP BY ic.id
char_length(sampleids) - char_length(REPLACE(sampleids,',',''))+1 AS "samples used",
) AS TeacherNames
to_timestamp(timecreated) AS "time created",
to_timestamp(timemodified) AS "time modified"
 
FROM prefix_analytics_predict_samples
</syntaxhighlight>
</syntaxhighlight>


To get all Students instead, use the role id number of 5 instead of 3.
=== 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


==== Get custom User profile fields for a user ====
<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"


Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
FROM prefix_analytics_train_samples
 
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>
</syntaxhighlight>


If you want to limit it to one of those fields, you can restrict it by shortname of the custom profile field, so:
=== 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">
<syntaxhighlight lang="sql">
SELECT u.username, uif.name, uid.data
SELECT
FROM prefix_user AS u
id,
JOIN prefix_user_info_data AS uid ON uid.userid = u.id
modelid,
JOIN prefix_user_info_field AS uif ON (uid.fieldid = uif.id AND uif.shortname = 'shortname1')
action,
analysableid,
to_timestamp(firstanalysis) AS "first analysis",
to_timestamp(timeanalysed) AS "time analysed"
 
FROM prefix_analytics_used_analysables
</syntaxhighlight>
</syntaxhighlight>


will show you only the data from the custom profile field with the shortname 'shortname1'.
=== 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


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:
id,
modelid,
fileid,
action,
TO_TIMESTAMP(time) AS Time


<syntaxhighlight lang="sql">
FROM prefix_analytics_used_files
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>
</syntaxhighlight>


==== Get custom User profile fields for a user Alternate (sub select) Method ====
===Average Cognitive Depth and Social Breadth===


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.
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
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">
<syntaxhighlight lang="sql">
SELECT u.username
SELECT


,(SELECT d1.data FROM prefix_user_info_data d1
i.contextid,
JOIN prefix_user_info_field f1 ON d1.fieldid = f1.id AND f1.shortname = 'shortname1'
i.sampleid,
WHERE d1.userid = u.id
) AS thefirstfield


,(SELECT d1.data FROM prefix_user_info_data d1
TRUNC(AVG(CASE
JOIN prefix_user_info_field f1 ON d1.fieldid = f1.id AND f1.shortname = 'shortname2'
WHEN i.indicator LIKE '%cognitive%' THEN i.value
WHERE d1.userid = u.id
ELSE '0'
) AS thesecondfield
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_user u
FROM prefix_analytics_indicator_calc as i
WHERE
i.value != 0
GROUP BY i.contextid, i.sampleid
</syntaxhighlight>
</syntaxhighlight>


===Configurable Reports Variable and Filters===
=APPENDIX: OTHER USEFUL THINGS=


====Variables====
Below are some sections on other items useful for building and using the reports. Feel free to share any useful items for building or using queries or the plugins here.


This is a list of the variables that you can use with the Configurable Reports plugin in your queries. Place the variable where you would the corresponding column. You will see numerous examples of these in the queries above.


* %%CATEGORYID%%
==How-tos, sub queries and code snippets==
* %%COURSEID%%
* %%CURRENTUSER%%
* %%DEBUG%%
* %%FILTER_VAR%%
* %%STARTTIME%%’,’%%ENDTIME%%
* %%USERID%%
* %%WWWROOT%%


In this section please put any short one purpose sub queries that show how common procedures often useful as part of larger queries.


For example, to run a report that shows the current user their own profile information, you can use the %%CURRENTUSERID%% variable in place of the user id:
=== All teachers or students in the course ===
<syntaxhighlight lang="sql">
SELECT username, firstname, lastname, email
FROM prefix_user
WHERE id = %%CURRENTUSERID%%
</syntaxhighlight>


To add logic to any query run inside a course to limit it to the data just for that course, use the %%COURSEID%% variable:
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. If you change the number to 5, it will list Students instead.


<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT shortname, fullname
,(SELECT GROUP_CONCAT( CONCAT( u.firstname, " ", u.lastname ) )
FROM prefix_course
FROM prefix_course ic
WHERE id = %%COURSEID%%
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>
</syntaxhighlight>


====Filters====
To get all Students instead, use the role id number of 5 instead of 3.
 
=== Forms of user names ===


(To be filled out one day)
There are a great variety of different ways to show the names of users in the reports above. Moodle, unlike some applications, does not have a single column for the users whole name, but has separate columns for first name and last name (or surname). If you just need to change the name formats, you can use any of these snippets:


* %%FILTER_CATEGORIES:
<syntaxhighlight lang="sql">
* %%FILTER_COURSEMODULEID:
SELECT
* %%FILTER_COURSEMODULEFIELDS:
u.id AS "Internal id",
* %%FILTER_COURSEMODULE:
u.username,
* %%FILTER_COURSES:
u.firstname,
* %%FILTER_COURSEENROLLEDSTUDENTS:
u.lastname,
* %%FILTER_USERS:
CONCAT(u.firstname, ' ', u.lastname) AS "First name - last name",
* %%FILTER_ROLE:
CONCAT(u.lastname, ' ', u.firstname) AS "Last name - first name",
* %%FILTER_SEARCHTEXT:
CONCAT(u.id, ' ', u.username, ' ',u.idnumber) AS "Id - username - idnumber",
* %%FILTER_SEMESTER:
u.email,
* %%FILTER_STARTTIME:
u.idnumber AS "User idnumber",
* %%FILTER_ENDTIME:
IF(u.deleted = 1, "Deleted","Not deleted") AS "Deletion status",
* %%FILTER_SUBCATEGORIES:
IF(u.suspended = 1, "Suspended","Active") AS "Suspension status"
* %%FILTER_COURSEUSER:
FROM prefix_user u
</syntaxhighlight>
 
=== Including and Excluding Deleted and Suspended Users ===
 
All users have two columns in their user entry in the prefix_user table: deleted and suspended. The value of 0 (false) means the user is not deleted or not suspended, respectively. A value of 1 (true) means the user is deleted or suspended, respectively. To exclude user accounts that have been deleted or suspended from any query, you can add a WHERE clause restriction (among other ways to do this).
 
To show only active users, use any of these equivalent forms:
 
<syntaxhighlight lang="sql">
WHERE u.deleted = 0 AND u.suspended = 0
WHERE u.deleted != 1 AND u.suspended != 1
WHERE u.deleted <> 1 AND u.suspended <> 1
</syntaxhighlight>
 
To show active and suspended users, you can use:
<syntaxhighlight lang="sql">
WHERE u.deleted != 1
</syntaxhighlight>
To show only suspended users, you can use:
<syntaxhighlight lang="sql">
WHERE u.suspended = 1
</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>
 
=== Get custom User profile fields for a user Alternate (sub select) Method ===
 
If you have more than a couple of fields you need to use, then the query above using JOINs for all the custom fields may time out or not return data due to too many joins. The practical 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>
 
==Moodle Report Plugins Variables, Filters and Other Idiosyncracies==
 
 
===Shared variables===
 
Both the plugins share this variable in common. Code that uses only these will run in both plugins without change:
 
* %%WWWROOT%% - this substitutes the base url for your Moodle site exactly as set in the config.php file
* %%USERID%% - this substitutes the user id (not idnumber!) of the current user running the report
 
===Ad-hoc database queries plugin===
 
==== AD variables ====
 
The following notes are taken directly from the documentation that shows up in each query right under the code edit box below the "Verify the SQL and update the form" button. Please carefully read the whole set of notes there if you think you are getting syntax or other error messages.
* The token %%WWWROOT%% in the results will be replaced with [the root of your site as set in config.php].
* The token %%USERID%% in the query will be replaced with the user id of the user viewing the report, before the report is executed.
* For scheduled reports, the tokens %%STARTTIME%% and %%ENDTIME%% are replaced by the Unix timestamp at the start and end of the reporting week/month in the query before it is executed.
 
==== Forbidden URL Parameters====
 
Pay particular attention to this section if you are constructing URLS in your code that may use parameters!
 
* You cannot use the characters :, ; or ? in strings in your query. If you need them in output data (such as when outputting URLs), you can use the tokens %%C%%, %%S%% and %%Q%% respectively. If you need them in input data (such as in a regular expression or when querying for the characters), you will need to use a database function to get the characters and concatenate them yourself. In Postgres, respectively these are CHR(58), CHR(59) and CHR(63); in MySQL CHAR(58), CHAR(59) and CHAR(63).
 
 
Note that the question mark ? is often used as a url parameter in Moodle urls. Watch out for those. Please see the following forum post for more details and discussion on this: https://moodle.org/mod/forum/discuss.php?d=407295#p1648774
 
==== How AD Auto URL Linking Works====
 
This plugin has its own method of creating links which avoids having to put any HTML in your SQL statement. Instead you designate two columns: one as the text and one as the link.
 
In the example below the column named "User" shows the username. The very next column is called "User_link_url" where this must be the same name as the column before but you add "_link_url" to the column name to tell the plugin this is how to build the url.
 
The user is the TEXT that you would normally build a link with: leave out all the HTML code, just put the link text. In the following example you will see it is a standard link to a user profile, where there are three variables: the root, a %%Q%% symbol that stands for ? and the user id. This will make a normal url of the form: https://example.com/user/profile.php?id=2 and so forth.
 
<syntaxhighlight lang="sql">
SELECT
u.username AS "User",
CONCAT("%%WWWROOT%%/user/profile.php%%Q%%id=", u.id) AS "User_link_url"
FROM prefix_user u
</syntaxhighlight>
 
Note that even though there are two columns defined in the SELECT statement, they are collapsed into one column by the plugin. The output of this sample will be a one column list of usernames, all linked to their  user profile pages.
 
If you only want the full url to show up linkable, then use just the one column without designating the name, e.g.
 
<syntaxhighlight lang="sql">
SELECT
CONCAT("%%WWWROOT%%/user/profile.php%%Q%%id=", u.id) AS "User"
FROM prefix_user u
</syntaxhighlight>
 
The output of this query will be single column of full urls to the users profiles that are already linked.
 
===Configurable Reports plugin===
====CR Variables====
 
For fuller documentation and examples, please see the official [[Configurable reports|Configurable Reports documentation page]].
 
This is a list of the variables that you can use with the Configurable Reports plugin in your queries. Place the variable where you would the corresponding column. You will see numerous examples of these in the queries above.
 
* %%CATEGORYID%%
* %%COURSEID%%
* %%CURRENTUSER%%
* %%DEBUG%%
* %%FILTER_VAR%%
* %%STARTTIME%%
* %%ENDTIME%%
* %%USERID%%
* %%WWWROOT%%
 
 
For example, to run a report that shows the current user their own profile information, you can use the %%USERID%% variable in place of the user id:
<syntaxhighlight lang="sql">
SELECT username, firstname, lastname, email
FROM prefix_user
WHERE id = %%USERID%%
</syntaxhighlight>
 
To add logic to any query run inside a course to limit it to the data just for that course, use the %%COURSEID%% variable:
 
<syntaxhighlight lang="sql">
SELECT shortname, fullname
FROM prefix_course
WHERE id = %%COURSEID%%
</syntaxhighlight>
 
(Tip: if you run this outside of a course on the front page or dashboard, it will return the name of the site, which is technically course id = 1)
 
====CR Filters====
If you know how these work and have some code examples, feel free to share your knowledge here. Meanwhile, for fuller documentation and examples, please see the official [[Configurable reports|Configurable Reports documentation page]].
 
===== List of CR Filters=====
 
* %%FILTER_CATEGORIES:
* %%FILTER_COURSEMODULEID:
* %%FILTER_COURSEMODULEFIELDS:
* %%FILTER_COURSEMODULE:
* %%FILTER_COURSES:
* %%FILTER_COURSEENROLLEDSTUDENTS:
* %%FILTER_USERS:
* %%FILTER_ROLE:
* %%FILTER_SEARCHTEXT:
* %%FILTER_SEMESTER:
* %%FILTER_STARTTIME:
* %%FILTER_ENDTIME:
* %%FILTER_SUBCATEGORIES:
* %%FILTER_COURSEUSER:
* %%FILTER_SYSTEMUSER:
* %%FILTER_SYSTEMUSER:
* %%FILTER_YEARHEBREW:
* %%FILTER_YEARHEBREW:
* %%FILTER_YEARNUMERIC:
* %%FILTER_YEARNUMERIC:
 
 
====Using the Date Time Filters====
 
 
=====CR Filters Location=====
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
 
Configurable Reports filters are part of the WHERE clause of your query. The CR code will take the filters it finds and then put in the proper syntax for the filters as it builds the query. Therefore, your filters have to be in the proper location as part of the WHERE clause, and so they must come before any other clauses that may follow such as GROUP BY, HAVING BY,  or ORDER BY or others, in accordance with the SQL standards for syntax.
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.
 
 
For example, the following is correct where the filters are after the WHERE clause and before any other clauses, in this case ORDER BY:
Here is a simple example:
 
 
<syntaxhighlight lang="sql">
<syntaxhighlight lang="sql">
SELECT cat.name,
SELECT u.username,
c.shortname,
DATE_FORMAT(FROM_UNIXTIME(u.firstaccess),'%Y-%m-%d %H:%i') AS 'FirstAccess',
c.fullname,
DATE_FORMAT(FROM_UNIXTIME(u.lastaccess),'%Y-%m-%d %H:%i') AS 'LastAccess'
c.summary
FROM prefix_user u
FROM prefix_course c
 
JOIN prefix_course_categories cat
WHERE 1=1
WHERE cat.id = 1
%%FILTER_STARTTIME:u.firstaccess:>%%
%%FILTER_SEARCHTEXT_S:c.summary:~%%
%%FILTER_ENDTIME:u.lastaccess:<%%
%%FILTER_COURSES:c.shortname%%
</syntaxhighlight>
ORDER BY c.shortname
 
</syntaxhighlight>
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.
 
 
When this is run, it will be interpreted as:
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.
<syntaxhighlight lang="sql">
 
WHERE cat.id =1
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.)
AND {the text you have entered in the search box to find in the course summary}
 
AND {the course name you have chosen from the pull down menu}
===Useful Constants and other common items===
</syntaxhighlight>
 
 
==== Role id numbers ====
 
The standard default roles have the id numbers as follows:
======What if you have no WHERE clause?======
 
 
* 1 Manager
If your query doesn't have a WHERE clause, you MUST ADD a dummy WHERE clause in order to use the filters. A common form of which is just to use WHERE 1=1. For example, this is CORRECT:
* 2 Course creator
 
* 3 Editing Teacher
<syntaxhighlight lang="sql">
* 4 Non-editing Teacher
WHERE 1=1
* 5 Student
%%FILTER_SEARCHTEXT_S:c.summary:~%%
* 6 Guest
%%FILTER_COURSES:c.shortname%%
* 7 Authenticated user
ORDER BY c.shortname
</syntaxhighlight>
 
However, the following is INCORRECT and will not work: the query will appear to work but when you do anything with the filters, it will generate a SQL Error telling you there was a syntax error, because the "AND" comes immediately after the "JOIN" and that is a syntax error.
 
<syntaxhighlight lang="sql">
SELECT cat.name,
c.shortname,
c.fullname,
c.summary
FROM prefix_course c
JOIN prefix_course_categories cat
# ooops there's no WHERE statement here!
%%FILTER_SEARCHTEXT_S:c.summary:~%%
%%FILTER_COURSES:c.shortname%%
ORDER BY c.shortname
</syntaxhighlight>
 
Moral of the story? IF you are using FILTERS you must always have a WHERE clause.
 
====Using the Search Text filter====
Contributed by: [https://moodle.org/user/profile.php?id=88992 Randy Thornton]
 
In the Configurable reports block for Moodle 3.11, CR version 3.9.0 (2020110390), there is a [https://github.com/jleyva/moodle-block_configurablereports/pull/155/commits/94dcc5ba26b58685a843cc06df8287d6ccde3599 new way of naming the Search text filter]. The goal of this new method is to allow you to now have more than one Search text filter for the same query, so that you can search more than one column from your report. The following shows how to do this.
 
In your code, you must add an identifier to your filter like this FILTER_SEARCHTEXT_ID1 where ID1 is just any arbitrary identifier you want. I usually just use _1 or _2 but you could use _username or to make it clearer just _U for username as a reminder.
 
Step 1: Add an ID to the end of the filter name %%FILTER_SEARCHTEXT_ID. The ID can be any one letter, number or word that you wish. Note that there must be an underscore!!. Also, the ID is case sensitive. For example:
 
<syntaxhighlight lang="sql">
SELECT
u.username,
u.firstname,
u.lastname
FROM prefix_user u
WHERE 1=1
%%FILTER_SEARCHTEXT_U:u.username:~%%
</syntaxhighlight>
 
will let you search on the username field of your report. You could use _U or _u or _username or _1 or any indicator you want as long as it is not duplicated by any other SEARCHTEXT id you may add.
 
 
Step 2: In the filter tab for the ID, add ONLY the identifier part without the underscore line, so 1 or 2 or U or whatever you use. Do NOT use the whole filter starting with the %% or include the underscore, use only the ID itself. So, for this example, put the ID "U".
 
 
'''Adding Multiple Searches'''
 
This method allows you to have two filters to search with, so:
<syntaxhighlight lang="sql">
SELECT
u.username,
u.firstname,
u.lastname
FROM prefix_user u
WHERE 1=1
%%FILTER_SEARCHTEXT_U:u.username:~%%
%%FILTER_SEARCHTEXT_F:u.firstname:~%%
</syntaxhighlight>
 
then you would add two filters in the Filters tab, one with an ID of U and the Second with the ID of F - and put Labels of "Username" and "Firstname" so that the user knows which is which.
 
Example Output with two Search Text filters:
 
[[File:cr-searchtextoutput.jpg]]
 
 
 
'''Backwards compatibility'''
 
For backwards compatibility and filters without idnumber, this old method of matching without idnumber still works if you are only using a single searchtext filter in your query.
 
====Using the 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>
 
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.)
 
 
====CR Security setting and "Not Allowed Words" message====
 
The CR plugin has two security modes, high and low.
 
In plugin versions 3.8 and below, this is controlled by the setting in ''Site administration > Plugins > Blocks > Configurable Reports > SQL Security''. The default is On, which is the high security mode. Unchecking this will enable low security mode.
 
In plugin version 3.9 and above (released November 2020), you must also set a variable in your config.php file as follows for this feature to work, as per the [https://github.com/jleyva/moodle-block_configurablereports documentation]:
 
''Starting this version for allowing SQL queries performing data insertion/creation the following configuration variable set to 1 is required in your site root /config.php:
''
<syntaxhighlight lang="php">
$CFG->block_configurable_reports_enable_sql_execution = 1;
</syntaxhighlight>
 
''Otherwise, previous Custom SQL reports performing data insertion/creation will stop working.
''
 
 
In high security mode, the plugin blocks the following SQL keywords:
 
<blockquote>
ALTER | CREATE | DELETE | DROP | GRANT | INSERT | INTO | TRUNCATE | UPDATE | SET | VACUUM | REINDEX | DISCARD | LOCK
</blockquote>
If your code uses any of these keywords, you will receive a "Not allowed words" error message when trying to run the query.
 
In low security mode, the plugin will allow the keywords '''INSERT | INTO | CREATE''' but will continue to block those other keywords. This means that low security mode will allow you to CREATE new tables, including temporary ones, and insert data into them, but it will not allow you to use UPDATE to alter current table data.
 
For more, see the code in [https://github.com/jleyva/moodle-block_configurablereports/blob/MOODLE_36_STABLE/components/customsql/form.php#L82 /components/customsql/form.php around lines 80].
 
==Useful Constants==
 
=== Role id numbers ===
The standard default roles as installed have the id numbers as follows:
 
* 1 Manager
* 2 Course creator
* 3 Editing Teacher
* 4 Non-editing Teacher
* 5 Student
* 6 Guest
* 7 Authenticated user
* 8 Authenticated user on the frontpage
 
 
You can see all your roles with the simple query:
 
<syntaxhighlight lang="sql">SELECT * FROM prefix_role</syntaxhighlight>
 
=== Context level ids ===
 
These are the [https://github.com/moodle/moodle/blob/master/lib/accesslib.php#L121-L137 constants used in the context levels] in the context table and elsewhere.
 
* SYSTEM = 10
* PERSONAL = 20
* USER = 30
* COURSECAT = 40
* COURSE = 50
* GROUP = 60
* MODULE = 70
* BLOCK = 80
 
The following snippet can be helpful (assuming an alias of ctx for the context table):
 
<syntaxhighlight lang="sql">
 
CASE ctx.contextlevel
  WHEN 10 THEN 'System'
  WHEN 20 THEN 'Personal'
  WHEN 30 THEN 'User'
  WHEN 40 THEN 'Course_Category'
  WHEN 50 THEN 'Course'
  WHEN 60 THEN 'Group'
  WHEN 70 THEN 'Activity_Module'
  WHEN 80 THEN 'Block'
ELSE CONCAT('Unknown context: ',ctx.contextlevel)
END AS "Context_level"
 
</syntaxhighlight>
 
=== Constants for permission levels ===
 
[https://github.com/moodle/moodle/blob/master/lib/accesslib.php#L112-L120 Constants for permissions] are:
 
* 1 = Allow
* -1 = Prevent
* -1000 = Prohibit
 
 
"Not set" is NULL and will have no table entry in the role definition.


==== Context level ids ====
=== Constants for Course Restores ===


These are the constants used in the context levels in the context table and elsewhere.  
[https://github.com/moodle/moodle/blob/master/backup/backup.class.php#L97-L103 Constants that tell you what type of restore] was being done. These are used in the logs in the 'Other' field for the 'target' parameter.


* SYSTEM = 10
* TARGET_CURRENT_DELETING = 0
* PERSONAL = 20
* TARGET_CURRENT_ADDING = 1
* USER = 30
* TARGET_NEW_COURSE = 2
* COURSECAT = 40
* TARGET_EXISTING_DELETING = 3
* COURSE = 50
* TARGET_EXISTING_ADDING = 4
* GROUP = 60
* MODULE = 70
* BLOCK = 80


==== Constants for permission levels ====


Constants for permissions are:
So, a standard restore of a new course from backup is 2. ADDING is what is called in the Moodle interface as a "merge". DELETING is overwriting the current or another existing course with the backup.


* 1 = Allow
=== Logs origin ===
* -1 = Prevent
* -1000 = Prohibit


Meaning of the strings in the origin field in the standard logs:


"Not set" is NULL and will have no table entry in the role definition.
* cli - command line interface, including scheduled tasks and cron events
* restore - an event done during a course restore
* web - normal events by users in the web interface
* ws - web services calls, including those from the mobile app


==See also==
==See also==
Line 5,863: Line 6,555:
====Adminer plugin====
====Adminer plugin====


To help work with the database, you can use the [https://moodle.org/plugins/local_adminer Moodle Adminer plugin]. This is especially useful if you do not have access to the database on your server via some third party tool such as PhpMyAdmin.  
To help work with the database, you can use the [https://moodle.org/plugins/local_adminer Moodle Adminer plugin]. This is especially useful if you do not have access to the database on your server via some third-party tool such as PhpMyAdmin.  


====Github repository====
====Github repository====

Latest revision as of 17:22, 5 October 2022

Introduction

Note: The Moodle Docs wiki software was upgraded substantially in July 2021 and required all query code to be updated for language syntax presentation. I have done that and taken the opportunity to make some updates and cleaning up on this page. For more details, please see the discussion on Upgrade of Moodle docs and Ad-hoc reports page. Thanks, Randy.

Licensing and Disclaimer

Disclaimer:

All queries on this page are provided as is. You are completely responsible for using them and for any and all effects they may have on your site, including any data loss. In the standard wording of the GNU license that accompanies all Moodle code, all queries and content here are:

distributed in the hope that it will be useful, but WITHOUT ANY WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.

Precautions:

  • Backup your database before using queries
  • Never use a query on a production site, only on a test site
  • If you don't know what you are doing, then don't do it


Licensing:

All queries and content here are property of their original copyright holders and are licensed here under the GNU General Public License.

Moodle Report Plugins

There are two plugins commonly used in Moodle for making and viewing SQL reports:


The discussion forum dedicated to these plugins and how to make and use queries with them is located here: Configurable reports block (plugin). You will also find more information in the Analytics and reporting forum.

You can install and use either of these plugins into your Moodle site for reports. If you are more focused on emailing reports, first look at the Ad-hoc database queries. If you need to share reports with teachers and students in courses, then look at the Configurable Reports plugin.

Some Technical Notes for Report Users

Table Names and prefix_

You will see many of the queries below use "prefix_" to start table names, e.g. prefix_user. This prefix_ is used before table names when you are using either of the two plugins, Ad-hoc reports or Contributed reports. These two plugins replace prefix_ with the actual prefix set in your Moodle configuration config.php file. This is because while the default table prefix is mdl_, when you install Moodle you can designate any prefix you want, so it is customizable.

Queries written to be used with either of those two plugins should always have prefix_ to begin all table names instead of the actual prefix.

When you use tools outside those two Moodle plugins, such as PhpMyAdmin, Workbench, etc., you have to use the actual table names as they are in the database including the actual prefix set for your own site.

Therefore:

  • If a query below has "prefix_" in its table names and you want to use that query in a tool such as phpMyAdmin, you will need to replace those with the actual prefix of your site's tables.
  • If a query below has "mdl_" or some other prefix in its table names, and you are using that in either of the two Moodle plugins, you will need to replace those explicit prefixes with "prefix_".


You will receive a "No explicit prefix" error in either of those plugins if you use code with the actual table prefix in it.

About %%FILTER_ and similar Variables

You will see a number of queries with variables in them that start and end with two %% percentage signs, e.g. %%WWWROOT%% and several of them that start with %%FILTER_. Theses variables are specific to one or both of the two Moodle plugins. They are not standard SQL code and will not work in code done in other tools outside of those two plugins.

In addition, while these two plugins do share some of the variable, some only work in one plugin or the other. For example, %%WWWROOT%% works in both; the %%C%%, %%S%% and %%Q%% variables only work in the Ad-hoc database queries plugin; and those starting %%FILTER_ only work in the Configurable Reports plugin. You will receive a syntax error if you use a variable that the plugin does not support.

Find more details in the section on Variables below.

About Date and Time Formatting

Dates and times in Moodle are stored internally in the database as the Unix Epoch timestamp which is the number of seconds since January 1, 1970 at 00:00 UTC, which in the database will be represented as 0.

To convert them to "human readable" formats we use everyday, you will need to do that in your query with code. There are numerous examples in the reports on this page: a search of this page for "FROM_UNIXTIME" will show you how to use and convert the dates. Note that when times are converted into standard date and times from timestamps are in UTC format and you may want to convert those to a local time zone.

The functions FROM_UNIXTIME and DATE_FORMAT that are common in the reports below are MySQL specific functions, which you can use in MySQL and MariaDB sites.

For other version of SQL, you will need to edit such queries to get them to work properly. For Postgres, see the manual page on Data Type Formatting Functions. There are a number of examples specific to Postgres among the queries below. For MSSQL, see this documentation at How to Return the Unix Timestamp in SQL Server. For Oracle, call Larry Ellison on his yacht and ask why he doesn't have a rocket yet like all the other vainglorious billionaires.

There are many date and time formats used in various countries, but all can be formatted based on the original timestamp value. For a sample in MySQL, you can use the following query to show you the install date of your Moodle site in several formats:

SELECT
l.timecreated AS "Timestamp",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%d/%m/%Y') AS "Common world format",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%m/%d/%Y') AS "US format",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%Y-%m-%d') AS "ISO standard format",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated), '%Y-%m-%d %H:%i') AS "ISO standard format with 24 hour time"
FROM prefix_logstore_standard_log l
WHERE l.id =1

See the MySQL documentation for all the possible date formatting options.

Note: for timestamps that are 0, this sometimes represents "Never" or "No date" for some fields in Moodle. For example, if a user's first login is 0, that means they have never logged in at all, not that their first log in was January 1, 1970 (since Moodle did not exist yet). If you want to distinguish such dates in your output, you can use a conditional to test for the 0, for example:

IF(u.firstaccess = 0, "Never",DATE_FORMAT(FROM_UNIXTIME(u.firstaccess),'%Y-%m-%d %H:%i')) AS 'FirstAccess',

which will show "Never" when the timestamp is 0 and the properly formatted date otherwise, allowing you to sort the column easily.

Standard Logs and Legacy Logs

The log table is the where events in the system are stored. It is a key table for certain types of reports, especially anything related to system events like logins, accessing pages, creating and deleting objects, changing settings, etc.

Moodle made a major update to the log system in Moodle 2.7 in 2014. The older log format using the table prefix_log are called "Legacy logs" while the current logstore system are called "Standard" logs. Unless your Moodle site was running such logs in the 2.7 and before era, and you for some reason chose not to update to the new log format, then you will be using the new log system, with a log table prefix_logstore_standard_log.

Use Standard Log Reports

Use the reports in the Standard Log Reports section below for current versions of Moodle unless you are sure you have ancient log data from very old Moodles in your system for some reason.

Since the legacy log table still exists in newer versions of Moodle, these Legacy queries may actually run but will not return results in later versions of Moodle using the new logstore system. You can check this for yourself with the following query on your site, which will show you the 0 count for the empty Legacy log table compared with your active Standard log table:

SELECT 
(SELECT COUNT(*) FROM prefix_log) AS "Legacy_log",
COUNT(*) AS "Standard log"
FROM prefix_logstore_standard_log
Finding Old Legacy Log Reports

If you wish to find and use queries from this old system, you should search in the Ad-hoc pages for earlier versions of Moodle to find such reports, which will use the table prefix_log or mdl_log. Reports from Moodle 2.0 to 3.10 will contain such queries.

All these old queries have been removed from the pages for Moodle 3.11 and newer. If you are the author of one of these old queries, please consider updating your query for current Moodle logstore system and move it into the main Log Reports section of the current Moodle version. Thanks.

Suggestions for Contributors

Everyone is free to contribute to this page. If you have working queries that you think would be of use to community members, please share them here. The following suggestions would make your contributions more useful.

Versioning

  • Only post queries verified to work in the current version of this page for its Moodle version: all Moodle docs pages are specific to one version of Moodle and are rolled over twice yearly at new releases in May and November
  • Please do not post versions of queries for old, out-of-support versions (if you want to, use the version page specific to that version, not the current one)
  • Please remove any query you have written that no longer works in the current version of Moodle: especially in cases of structural changes to tables that render old queries broken (e.g. changes in the Logs in 2.7, Messaging in 3.6, etc.)

Adding annotations for others

  • If you are using a SQL dialect other than MySQL, please note which dialect it is and any specific functions or other quirks present
  • Please consider putting your name and/or a link as "Contributed by"
  • Please consider adding a short description of what your report does and its expected output
  • If the code includes any non-default, third party plugins, please specifically note that in your description
  • If your code includes any domain names, course or user names, or other references specific to your site, consider making those more generic
  • Please use English since this is the English version of the Moodle documentation
  • If there is a discussion or other information about the query from a forum discussion, feel free to link to that discussion

Commonly used table aliases

Over the years, some common conventions have arisen for table aliases. You will see these used often on these reports.

If you use these aliases, then your queries will be easier for others to read. But of course, any legal alias can be used.

  • c = prefix_course
  • cat or cc = prefix_course_categories
  • cm = prefix_course_modules
  • ctx or con = prefix_context
  • e = prefix_enrol
  • f = prefix_files
  • l or log = prefix_logstore_standard_log
  • m = prefix_module
  • r = prefix_role
  • ra = prefix_role_assignments
  • u = prefix_user
  • ue = prefix_user_enrolments

Other Useful Things

Please see the sections at the end of this page for other useful things including the database schema, commonly used snippets of code, the Config Reports variables and filters, and other nice things.



The REPORTS

USER and ENROLMENT Reports

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

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)

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

Log in and Log out history complete for a specific user

Contributed by: Randy Thornton

This query uses the logs to show the complete login and logout history for a particular user. You can use it as the basis for further refining the report. Replace the ## in the WHERE clause below with the id number of the user you wish to see. Warning: as always with queries from the logs, this can take a long time to run and may return more data that the maximum limit allowed.

SELECT
l.id AS "Log_event_id",
l.timecreated AS "Timestamp",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%Y-%m-%d %H:%i') AS "Time_UTC",
l.action,
u.username,
l.origin,
l.ip
FROM prefix_logstore_standard_log l
JOIN prefix_user u ON u.id = l.userid
WHERE l.action IN ('loggedin','loggedout')
AND l.userid = ##
ORDER BY l.timecreated

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

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

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:<%%

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

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 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


All users individual timezone settings

Contributed by: Randy Thornton

If you allow users to set their own time zones, this can sometimes lead to confusion about due dates and times for assignments. This shows all active users with their personal time zone settings if any.

SELECT 
u.username, 
IF(u.timezone=99,"-Site Default-",u.timezone) AS "User Timezone"
FROM prefix_user u
WHERE u.deleted = 0
ORDER BY u.timezone DESC

ROLES and PERMISSIONS 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


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

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

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

Note: for the meaning of the number 6 see the section on Role ids below.

Permissions Overrides 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

All Role Assignments with contexts

Contributed by: Randy Thornton

This lists all the roles that have been assigned in the site, along with the role shortname and the type of context where it is assigned, e.g. System, Course, User, etc. The last column, the context instance id, is the id number of the particular object where the assignment has been made. So, if the context is course, then the context instance id means the course id; if a category, then the category id, and so forth. So you can then use that number to locate the particular place where the role is assigned.

SELECT
u.username,
r.shortname AS "Role",
CASE ctx.contextlevel 
  WHEN 10 THEN 'System'
  WHEN 20 THEN 'Personal'
  WHEN 30 THEN 'User'
  WHEN 40 THEN 'Course_Category'
  WHEN 50 THEN 'Course'
  WHEN 60 THEN 'Group'
  WHEN 70 THEN 'Course_Module'
  WHEN 80 THEN 'Block'
 ELSE CONCAT('Unknown context: ',ctx.contextlevel)
END AS "Context_level",
ctx.instanceid AS "Context instance id"
FROM prefix_role_assignments ra
JOIN prefix_user u ON u.id = ra.userid
JOIN prefix_role r ON r.id = ra.roleid
JOIN prefix_context ctx ON ctx.id = ra.contextid
ORDER BY u.username

COURSE REPORTS

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


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

Last access time of users to a course

Contributed by: Randy Thornton

This shows all users and their last access time to courses.

SELECT 
u.username, 
c.shortname AS "Course",
DATE_FORMAT(FROM_UNIXTIME(la.timeaccess), '%Y-%m-%d %H:%i') AS "Last access time"
FROM prefix_user_lastaccess la
JOIN prefix_user u ON u.id = la.userid
JOIN prefix_course c ON c.id = la.courseid
ORDER BY u.username, c.shortname

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

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

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>';

?>

All teachers and courses

Contributed by François Parlant

  • not taking into account the END DATE
SELECT 
c.id, c.shortname,  
CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', c.id, '">',c.fullname,'</a>') AS 'Course link', 
u.id as 'prof id', 
u.username, u.firstname, u.lastname, r.shortname as 'role'
From prefix_user as u
join prefix_user_enrolments ue on ue.userid=u.id
join prefix_enrol en on ue.enrolid=en.id
join prefix_role_assignments ra on u.id=ra.userid
join prefix_role r on ra.roleid=r.id and (r.shortname ='editingteacher' or r.shortname ='teacher')
join prefix_context cx on cx.id = ra.contextid and cx.contextlevel = 50
JOIN prefix_course c ON c.id = cx.instanceid AND en.courseid = c.id
JOIN prefix_course_categories cc ON c.category = cc.id
WHERE 1=1
%%FILTER_SUBCATEGORIES:cc.path%%
%%FILTER_STARTTIME:c.startdate:>%%

All courses without an END DATE

Contributed by François Parlant

select c.id, c.fullname, c.shortname,
-- c.startdate, c.enddate,
FROM_UNIXTIME(c.startdate,'%d/%m/%Y') as "Date début",
FROM_UNIXTIME(c.enddate,'%d/%m/%Y') as "Date fin",
CONCAT('<a href="https://pedago-msc.campusonline.me/course/view.php?id=', c.id,'">voir cours</a>') AS 'lien cours',
CONCAT('<a href="https://pedago-msc.campusonline.me/user/index.php?id=', c.id,'">voir participants</a>') AS 'lien participants'
FROM prefix_course  AS c
INNER JOIN prefix_course_categories cc ON c.category = cc.id
WHERE c.enddate = 0
%%FILTER_CATEGORIES:c.path%%
%%FILTER_SUBCATEGORIES:cc.path%%
%%FILTER_STARTTIME:c.startdate:>%%

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)

List all courses WITHOUT Syllabus

Contributed by François Parlant

  • courses without ressource with name starting by "syllabus" (using upper case or lower case)
  • display the name as a direct link
  • shows the name of teacher
  • category with sub category filter
  • start date and end date filters
SELECT c.id as 'id cours',
c.shortname, CONCAT('<a href="%%WWWROOT%%/course/view.php?id=', c.id, '">',c.fullname,'</a>') AS 'Course link',
u.id, u.username, u.firstname, u.lastname, r.shortname as 'role'
FROM prefix_user as u
JOIN prefix_user_enrolments ue on ue.userid=u.id
JOIN prefix_enrol en on ue.enrolid=en.id
JOIN prefix_role_assignments ra on u.id=ra.userid
JOIN prefix_role r on ra.roleid=r.id and (r.shortname ='editingteacher' or r.shortname ='teacher')
JOIN prefix_context cx on cx.id = ra.contextid and cx.contextlevel = 50
JOIN prefix_course c ON c.id = cx.instanceid AND en.courseid = c.id
JOIN prefix_course_categories cc ON c.category = cc.id
WHERE c.id Not in (
  SELECT distinct(r.course)
  FROM prefix_resource AS r
  WHERE LOWER( r.name) LIKE 'syllabus%'
  GROUP BY r.course)
%%FILTER_SUBCATEGORIES:cc.path%%
%%FILTER_STARTTIME:c.startdate:>%% %%FILTER_ENDTIME:c.enddate:<%%

Count the number of resources whose name starts by "Syllabus"

Contributed by François Parlant

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)

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

  • without teachers
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
INNER JOIN prefix_course_categories cc ON c.category = cc.id
WHERE r.course NOT IN (
  Select r.course
  from prefix_resource AS r
  WHERE LOWER( r.name) LIKE 'syllabus%'
  GROUP BY r.course) 
%%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%%

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


Enrolment methods used in all courses

List of all the enrolment methods attached to all courses with their type, enabled status, sort order, and custom name if any. Includes a link directly the each course's enrolment methods settings page. Known to work in 3.11 (should work in most earlier version.) This report could serve as the basis and be easily expanded to show the various settings details for the methods if you want.

Contributed by: Randy Thornton

SELECT
CONCAT('<a target="_new" href="%%WWWROOT%%/enrol/instances.php?id=',c.id,'">',c.shortname,'</a>') AS "Course",
e.enrol AS "Method",
CASE e.status 
   WHEN 0 THEN 'Enabled' 
   WHEN 1 THEN '-' 
   ELSE e.status 
END AS "Status",
IF(e.name IS NOT NULL,e.name,'-') AS "Custom name"

FROM prefix_enrol e 
JOIN prefix_course c ON c.id = e.courseid
ORDER BY c.shortname,e.sortorder

GROUP REPORTS

List course group mode settings

Contributed by: Randy Thornton

Every course has a group mode set in the course settings. The options are stored in prefix_course.groupmode, where

  • 0 = No groups
  • 1 = Separate groups
  • 2 = Visible groups

The Group mode forced setting is in prefix_course.groupmodeforce and is 0 for off and 1 for on. The following query will show you these settings for all courses.

SELECT
c.shortname AS "Course",
CASE c.groupmode
WHEN 0 THEN "No groups"
WHEN 1 THEN "Separate groups"
WHEN 2 THEN "Visible groups" 
ELSE "This should not happen!"
END AS "Group mode",
IF(c.groupmodeforce=0, "Not forced","Forced") AS "Group mode forced"
FROM prefix_course c
ORDER BY c.shortname

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%%

All the Groups I am in in all courses

Contributed by: Randy Thornton

This will show all the groups in all courses that the user running the report is a member of. It uses the variable %%USERID%% used by the two Moodle plugins to do this.


SELECT
c.shortname AS Course,
g.name AS Groupname
FROM (SELECT userid, groupid FROM prefix_groups_members WHERE userid = %%USERID%%) AS GRU
JOIN prefix_user u ON u.id = GRU.userid
JOIN prefix_groups g ON g.id = GRU.groupid
JOIN prefix_course c ON c.id = g.courseid
# uncomment to limit it to only the current course 
WHERE g.courseid = %%COURSEID%%
ORDER BY c.shortname, g.name

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 = #

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

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

COURSE COMPLETION and GRADE 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.

Editor Note: This version is for MSSQL server. For MySQL, see below.

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',

And:

THEN c.fullname + ' Course Total'

with:

THEN CONCAT(c.fullname,' Course Total')

Editor Note by Randy Thornton: or in full the MySQL version is:

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, ' Course Total')
  ELSE gi.itemname
END AS 'Item Name',

ROUND(gg.finalgrade,2) AS Grade,
DATE_FORMAT(FROM_UNIXTIME(gg.timemodified),'%Y-%m-%d') 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 u.lastname

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


Grades for all students in all courses

Contributed by: Randy Thornton

A basic report showing grades for Students in all courses. It has only four columns: username, course shortname, grade, and date, restricted to the standard role of Student. You can use this as the basis for more complex reports.

SELECT 
u.username, 
c.shortname AS "Course",
ROUND(gg.finalgrade,2) AS "Grade",
DATE_FORMAT(FROM_UNIXTIME(gg.timemodified), '%Y-%m-%d') AS "Date"

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
WHERE gi.courseid = c.id 
AND gi.itemtype = 'course'
# students only role id is 5
AND ra.roleid = 5
ORDER BY u.username, c.shortname

Users who have not completed a course

By DKeeler

Reference: https://stackoverflow.com/questions/69544738/sql-ad-hoc-report-of-all-users-not-completed-a-course

SELECT
    u.id AS userid,
    u.firstname,
    u.lastname,
    u.idnumber,
    u.email
FROM mdl_user u
WHERE u.deleted = 0
AND u.suspended = 0
AND firstname NOT LIKE "Guest user"
AND NOT EXISTS (
    SELECT ue.userid
    FROM mdl_user_enrolments ue
    JOIN mdl_enrol e ON e.id = ue.enrolid AND e.courseid = 123
    WHERE ue.userid = u.id
)
ORDER BY
    lastname,
    firstname

Course Completion sitewide for all Users

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(cp.timecompleted),'%Y-%m-%d') AS completed
FROM prefix_course_completions AS cp
JOIN prefix_course AS c ON cp.course = c.id
JOIN prefix_user AS u ON cp.userid = u.id
WHERE c.enablecompletion = 1
ORDER BY u.username

Another version which includes the start and completed times.

SELECT 
u.firstname,
u.lastname,
c.shortname AS 'Course',
CASE 
  WHEN cp.timestarted = 0 THEN DATE_FORMAT(FROM_UNIXTIME(cp.timeenrolled),'%Y-%m-%d')
  ELSE DATE_FORMAT(FROM_UNIXTIME(cp.timestarted),'%Y-%m-%d')
END AS 'Started',
FROM_UNIXTIME(cp.timecompleted) AS 'Complete'
 
FROM prefix_user AS u
JOIN prefix_course_completions AS cp ON cp.userid = u.id
JOIN prefix_course c ON c.id = cp.course

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

Note that specific activity modules each have their own section below, with the Resource modules - book, file, folder, page and url all in one section together. At the end is a section for all third party additional activity modules.

General or Multiple Activities

Reports covering multiple or all course modules.

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 Activityname,
# 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

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

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

Assignment Activity

Note: The current Assignment module uses the tables with names starting with prefix_assign_. This is the module introduced in Moodle 2.3 and has been in use ever since then (2012).

The old, previous Assignment module used tables beginning with prefix_assignment_. This old module was removed and has not been supported since Moodle 2.7. If you have any modern version of Moodle, only use the queries below that are for the new module. If you are the author of one of the older assignment modules, please remove it to prevent confusion. Thanks.


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


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: you will need to change the cm.module = 22 number to be the id number of the Assignment module in your site. By default, this is 1.

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: [2]


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


Users who have overdue assignments

Contributed by: Randy Thornton

Shows a list of users who have not yet done an Assignment whose due date is past.

SELECT DISTINCT
u.username AS "User",
c.shortname AS "Course",
a.name AS "Assignment",
DATE_FORMAT(FROM_UNIXTIME(a.gradingduedate),'%Y-%m-%d %H:%i') AS "Due_date_UTC"

FROM prefix_user_enrolments 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 u ON u.id = ue.userid
JOIN prefix_assign a ON a.course = c.id
WHERE 
# pick your course but make sure it agrees with the c.id in the subselect
c.id = 2
#skip future dates
AND DATEDIFF(NOW(),FROM_UNIXTIME(a.gradingduedate)) > 0 
# only users who have not submitted 
AND ue.userid NOT IN 
 (SELECT asub.userid
  FROM prefix_assign_submission AS asub
  JOIN prefix_assign AS a ON a.id = asub.assignment 
  JOIN prefix_course c on a.course = c.id
  WHERE c.id = 2)

ORDER BY u.username, c.shortname


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'


Assignment Dates with their Calendar events

Contributed by: Randy Thornton

This query can help you diagnose issues related to setting dues dates and other dates in the Assignment along with their corresponding dates that are put into the Calendar. Assignment puts only the Due date and the Grade by reminder date into the calendar.

SELECT
a.id AS "A_id",
a.name AS "Assignment_name",
IF(a.duedate = 0, 'None',DATE_FORMAT(FROM_UNIXTIME(a.duedate),'%Y-%m-%d %H:%i')) AS "Assign Due",
IF(a.gradingduedate = 0, 'None',DATE_FORMAT(FROM_UNIXTIME(a.gradingduedate),'%Y-%m-%d %H:%i')) AS "Assign Grade_by",
IF(a.cutoffdate = 0, 'None',DATE_FORMAT(FROM_UNIXTIME(a.cutoffdate),'%Y-%m-%d %H:%i')) AS "Assign Cutoff",
IF(a.allowsubmissionsfromdate = 0, 'None',DATE_FORMAT(FROM_UNIXTIME(a.allowsubmissionsfromdate),'%Y-%m-%d %H:%i')) AS "Assign Open",
e.modulename AS "Module_type",
CASE 
 WHEN e.eventtype = 'due' THEN CONCAT('Due: ',DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%Y-%m-%d %H:%i')) 
 WHEN e.eventtype = 'gradingdue' THEN CONCAT('GradingDue: ',DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%Y-%m-%d %H:%i'))
 WHEN e.eventtype IS NULL THEN '-'
 ELSE 'None'
END AS "Event Timestart"

FROM prefix_assign a 
LEFT JOIN prefix_event e ON a.id = e.instance 
WHERE e.modulename IS NULL OR e.modulename = 'assign'

ORDER BY a.id

Chat Activity

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

Choice Activity

Choice Results

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

Database Activity

There are no reports yet for the Database activity.

Face to Face Activity

Get Face to Face sessions info, course info, user info. Note the xpath function is specific to Postgresql.

SELECT
    /* Session info */
    ftf_sd.timestart session_start_date,
    ftf_sd.timefinish session_end_date,
    ftf_s.id session_id,
    /* Course info */
    c.id course_id,
    c.shortname course_shortname,
    c.visible course_visible,
    (
        SELECT count(*)
        FROM prefix_facetoface ftf2
        WHERE ftf2.course = c.id
    ) facetoface_activities_in_course_count,
    /* FaceToFace activity-level info */
    ftf_s.facetoface facetoface_activity_id,
    ftf.name activity_name,
    CASE
        WHEN ftf_s.details LIKE '<%' THEN xpath('//text()', cast(ftf_s.details AS xml))::text
        ELSE ftf_s.details
    END session_description,
    /* User info */
    ftf_su.userid user_id,
    ftf_ss.signupid signup_id,
    ftf_ss.timecreated signup_date,
    u.username user_username,
    u.suspended user_suspended,
    u.username user_firstname,
    u.username user_lastname,
    u.email user_email,
    u.city
FROM prefix_facetoface_sessions ftf_s
    LEFT JOIN prefix_facetoface_sessions_dates ftf_sd ON ftf_sd.sessionid = ftf_s.id
    JOIN prefix_facetoface ftf ON ftf.id = ftf_s.facetoface
    JOIN prefix_course c ON c.id = ftf.course
    JOIN prefix_facetoface_signups ftf_su ON ftf_su.sessionid = ftf_s.id
    JOIN prefix_facetoface_signups_status ftf_ss ON (
        ftf_su.id = ftf_ss.signupid
        AND ftf_ss.superceded = 0
    )
    JOIN prefix_user u ON (
        u.id = ftf_su.userid
        AND u.deleted = 0
    )

Feedback Activity

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')

Forum Activity

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

Number of Forum Posts by a Teacher

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.

Number of forums that have been posted to by a teacher. We wanted to know what the teacher's actions are in the forums of each course, so this report was made.

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 beginning 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

Glossary Activity

All glossary entries

Shows the entries from all glossaries in the site with student and times.

Contributed by: Randy Thornton

SELECT
c.shortname AS "Course",
g.name AS "Glossary",
# g.intro AS "Introduction",
u.username,
ge.concept AS "Concept",
ge.definition AS "Definition",
IF(ge.approved=1,'Yes','No') AS "Approved",
DATE_FORMAT(FROM_UNIXTIME(ge.timecreated), '%Y-%m-%d %H:%i' ) AS "Created",
DATE_FORMAT(FROM_UNIXTIME(ge.timemodified), '%Y-%m-%d %H:%i' ) AS "Modified"
FROM prefix_glossary_entries ge
JOIN prefix_glossary g ON g.id = ge.glossaryid
JOIN prefix_user u ON u.id = ge.userid
JOIN prefix_course c ON c.id = g.course

H5P Activities

There are no reports yet for the H5P activities (core and non-core).

Lesson Activity

Lesson Questions

Show all the Questions with their Answers for all the Lessons in a site. This shows the questions as set up, not student responses. This is known to work in 3.11 but note that this may change in Moodle 4.0 or 4.1 due to plans to have the Lesson module use the standard question bank questions.

Contributed by: Randy Thornton

SELECT
c.shortname AS "Course",
l.name AS "Lesson_Name",
# NOTE: the line below is formatted for the Ad-hoc database queries plugin
# if using Config Reports you can edit this for the proper HTML format or remove it
CONCAT("%%WWWROOT%%/mod/lesson/view.php%%Q%%id=",cm.id) AS "Lesson_Name_link_url",
p.title AS "Page_Title",
p.contents AS "Question",
a.grade,
a.score,
a.answer,
a.response
FROM prefix_lesson_answers a
JOIN prefix_lesson l ON l.id = a.lessonid
JOIN prefix_lesson_pages p ON p.id = a.pageid AND p.lessonid = l.id
JOIN prefix_course c ON c.id = l.course
JOIN prefix_course_modules cm ON cm.instance = l.id
JOIN prefix_modules m ON m.id = cm.module
WHERE m.name = 'lesson'
# to limit this to a single question type add this eg true-false is 2
# AND p.qtype = 2 
# for just one lesson then put its course module id from the url here
# AND cm.id = #


If you want to have a column for the Question type, you can add this to the SELECT statement:

CASE p.qtype 
 WHEN 1 THEN 'Short answer'
 WHEN 2 THEN 'True/False'
 WHEN 3 THEN 'Multi-choice'
 WHEN 5 THEN 'Matching'
 WHEN 8 THEN 'Numerical'
 WHEN 10 THEN 'Essay'
 ELSE p.qtype
END AS "Question type",

LTI External Tool Activity

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

Quiz Activity

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'

Parse MultiAnswer (Cloze) Question Responses and Display in Columns

(Contributed by Laura DiFiore, July 2021, Moodle 3.97+) In this example, I am using a 4-part Cloze question for stenography students to keep track of their writing practice sessions. In mdl_question_attempts, their answers are stored like this:

part 1: 84; part 2: 92; part 3: 2; part 4: 98
part 1: 85; part 2: 107; part 3: 0; part 4: 100
SELECT  
    SUBSTRING_INDEX(SUBSTRING_INDEX(responsesummary, ';', 1), ' ', -1) as Drill,
    SUBSTRING_INDEX(SUBSTRING_INDEX(responsesummary, ';', 2), ' ', -1) as WPM,
    SUBSTRING_INDEX(SUBSTRING_INDEX(responsesummary, ';', 3), ' ', -1) as Mistakes,
    SUBSTRING_INDEX(SUBSTRING_INDEX(responsesummary, ';', 4), ' ', -1) as Accuracy
FROM `mdl_question_attempts` WHERE questionid=21
Drill	WPM	mistakes	accuracy
84	92	2	98
85	107	0	100

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%')


Users who have not yet taken a quiz

Contributed by: Randy Thornton

This is a stripped-down version of the query above, showing users in a course and the quizzes they have not yet taken.

SELECT DISTINCT
u.username AS "User",
c.shortname AS "Course",
q.name AS "Quiz"

FROM
prefix_user_enrolments 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 u ON u.id = ue.userid
JOIN prefix_quiz q ON q.course = c.id
WHERE 
# specify course but be sure it matches the c.id in the subselect
c.id = #
# exclude users who have an attempt
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 c on q.course = c.id
  WHERE c.id = #
 )
  
ORDER BY u.username, c.shortname, q.name

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

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


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


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

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

Survey Activity

Show all data for all surveys

SELECT * FROM prefix_survey_answers

Show all data for all surveys but with more info

SELECT 
  cm.id courseid, cm.instance surveyid, cm.visible, 
  sa.id surveyid, sa.userid, sa.question questionid, sa.time time_date, sa.answer1, sa.answer2
FROM prefix_course_modules cm
JOIN prefix_survey_answers sa ON cm.instance = sa.survey
JOIN prefix_course c ON cm.course = c.id
JOIN prefix_modules m ON cm.module = m.id 
WHERE cm.course = c.id AND m.name LIKE '%survey%'
/* 
ORDER BY c.id,sa.userid, sa.time DESC, sa.questionid
*/

Wiki Activity

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/> סמסטר ב'

Workshop Activity

There are currently no reports for the Workshop activity.

COURSE RESOURCES REPORTS (Book, File, Folder, Label, Page, URL)

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

NON-CORE MODULES

This is the section for non-core, contributed third party activity and resource plugin modules.

Elluminate (Blackboard Collaborate) - system wide usage

Editor's note: This is for the Blackboard Collaborate plugin.


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

List all the certificates issued, sort by variables in the custom profile fields

Editor note: This is for the classic Certificate module, which is no longer maintained since Moodle 3.3

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

Editor's note: This query is specific to the the Simple Certificate plugin.

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.

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

Student's posts content in all course blogs (oublog)

Editor's Note: This query is specific to the plugin OU Blog, not the standard Moodle blog tool.

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%%

SITE WIDE USER TOOLS

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,
IF(d.dateexpire IS NULL, 'Never', 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

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

Blogs

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


All site blogs posts by users

Contributed by: Randy Thornton

Shows all blog posts at site level by all users with dates, published status (draft, published to the site, or published publicly) along with links to the User blog profile and posts, and a link to delete any particular post. Known to work in 3.11.

SELECT
CONCAT('<a target="_new" href="%%WWWROOT%%/blog/index.php?id=',u.id,'">',CONCAT(u.firstname,' ',u.lastname),'</a>') AS "User (posts)",
b.subject,
b.summary,
# possible publish states are draft, site, public
b.publishstate,
DATE_FORMAT(FROM_UNIXTIME(b.created),'%Y-%m-%d %H:%i') AS "Created", 
DATE_FORMAT(FROM_UNIXTIME(b.lastmodified),'%Y-%m-%d %H:%i') AS "Last_modified",
CONCAT('<a target="_new" href="%%WWWROOT%%/blog/edit.php?action=',CHAR(ASCII('d')),'elete&entryid=',b.id,'">Remove this post</a>') AS "Remove_it"

FROM prefix_post b 
JOIN prefix_user u ON u.id = b.userid
WHERE b.module = 'blog' 

ORDER BY 1,2

Cohorts

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
WHERE e.enrol = 'cohort' AND e.roleid = 5

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

Site and Course level Competency Drill Down Reporting

Contributed by Ben Haensel

Competencies: Department Selection

This reporting drill down logic assumes there is a correlation between the Course Category (Department) name and the Competency name.

select concat('<a target="_blank" href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?id=117&filter_var=',cc.id,'">',cc.name,'</a>') Department
#Change the CR Report ID to go to your "Standards: All Site Standards with Course/Mod Counts" report (see below)
from prefix_course_categories cc
order by cc.name;
Competencies: All Site Standards with Course/Mod Counts

Parent Report: Department Selection This report provides a list of all competencies within a Framework with links to a report of which activities (mods) use the specific competency within a course.

select cmp.id CompID,
cmp.shortname Competency,
cmp.description Comp_Desc,
concat('<a target="_blank" href="%%WWWROOT%%/blocks/configurable_reports/viewreport.php?id=119&filter_var=',cmp.id,'">',
	#Change the CR Report ID to go to your "Course Level Report" report (see below)
	(select count(distinct c.id) 
	from prefix_course c
	join prefix_powerschool_course_fields pcf ON pcf.courseid = c.id
	join prefix_course_modules cm on c.id = cm.course
	join prefix_competency_modulecomp cmc on cm.id = cmc.cmid
	where cmc.competencyid = cmp.id
	group by cmp.id) ,'</a>') CrsCnt,
(select count(cmc.cmid) 
	from prefix_course c
	join prefix_powerschool_course_fields pcf ON pcf.courseid = c.id
	join prefix_course_modules cm on c.id = cm.course
	join prefix_competency_modulecomp cmc on cm.id = cmc.cmid
	where cmc.competencyid = cmp.id
	group by cmp.id) ActCnt,
#Modify this case statement for your departments based on compency shortname or remove
	case when cmp.shortname like 'ART%' then 'Art'
	when cmp.shortname like 'SOC%' then 'Social_Studies'
	when cmp.shortname like 'MTH%' then 'Math'
	when cmp.shortname like 'SCI%' then 'Science'
	when cmp.shortname like 'WL%' then 'World_Language'
	when cmp.shortname like 'ELA%' then 'English'
	else cmp.shortname
	end as Dept
from prefix_competency cmp
where cmp.competencyframeworkid = '%%FILTER_VAR%%';
Competencies: Course Level Report

Parent Report: All Site Standards with Course/Mod Counts This report provides a course level view of a specific competency and what activities it is connected to. Multiple courses may show activities (mods) that are connected to the selected competency. The link under the activity column goes to edit that selected activity.

select c.id courseid, 
c.fullname course, 
cmp.shortname competency,
concat('<a target="_blank" href="%%WWWROOT%%/course/modedit.php?update=',cm.id,'">',gi.itemname,'</a>') activity
from prefix_course c
join prefix_course_modules cm on c.id = cm.course
join prefix_modules m on cm.module = m.id
join prefix_grade_items gi on cm.instance = gi.iteminstance and gi.itemmodule = m.name
join prefix_competency_modulecomp cmc on cm.id = cmc.cmid
join prefix_competency cmp on cmc.competencyid = cmp.id
join prefix_powerschool_course_fields pcf on c.id = pcf.courseid
where '%%FILTER_VAR%%' = cmp.id
order by c.id, gi.itemname;

Messaging

The Messaging system received an overhaul in Moodle 3.5 (database changes) and in 3.6 (new interface).

Messages of All Users

Contributed by: Randy Thornton.

This version of the query has been updated for Moodle 3.6 and above, when the Messaging database structures were revamped and substantially changed. This is a version of this query that has been tested with Moodle 3.10 back to Moodle 3.6. Huge thank you to 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.


Private Files

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


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


Tags

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

ADMINISTRATOR REPORTS

Privacy Policy Details

Known to work in 3.11. May work in earlier versions of the Privacy policy system.

Contributed by: Randy Thornton

In the privacy policies management tools, you can see some but not all of the information about the various policies you have. Some key data is missing, including when and by whom policies were last changed. This report provides such information. It outputs the policy id, name, whether it is active or not, whether is archived or draft, what type it is, the audience, whether optional or required, dates, and who edited it last.


SELECT 
p.id AS "Policy id",
# v.id AS "Version id",
v.name AS "Name", 
IF(v.archived = 0,"Active", "Not active") AS "Activity status",
CASE 
 WHEN p.currentversionid IS NULL THEN 'Draft'
 WHEN p.currentversionid = v.id THEN 'Active'
 ELSE 'Archived'
END AS "Policy status",
# per /admin/tool/policy/classes/policy_version.php
CASE v.type 
 WHEN 0 THEN 'Site'
 WHEN 1 THEN 'Privacy'
 WHEN 2 THEN 'Third party'
 WHEN 99 THEN 'Other'
 ELSE 'Unknown policy type'
END AS "Type",
CASE v.audience
 WHEN 0 THEN 'All'
 WHEN 1 THEN 'Logged_in'
 WHEN 3 THEN 'Guest'
ELSE 'Unknown audience type'
END AS "Audience",
IF(v.optional = 0,"Required","Optional") AS "Required",
DATE_FORMAT(FROM_UNIXTIME(v.timecreated),'%Y-%m-%d %H:%i') AS "Created",
DATE_FORMAT(FROM_UNIXTIME(v.timemodified),'%Y-%m-%d %H:%i') AS "Last_modified",
u.username AS "Modified_by"
FROM prefix_tool_policy_versions v 
JOIN prefix_user u ON u.id = v.usermodified
JOIN prefix_tool_policy p ON p.id = v.policyid
ORDER BY p.id, v.id

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

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


This code will change the setting from 'en' to 'en_us' for all users: NOTE: UPDATE commands require the ability to alter the database directly via tools like Adminer or PHPMyAdmin or other db tools. You will not be able to do this with the two Moodle report plugins.

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

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)

Categories with id and name

Contributed by: Randy Thornton

This is intended to help with building the csv upload file for the Course upload process, where the category id number is required to identify the course category. It is a simple report with id and name of the category, and the id of its direct parent category. Known to work with 3.11.

SELECT
cat.id AS "Id",
cat.name AS "Category",
IF(cat.parent = 0,"0 (Top)",cat.parent) AS "Parent_id",
cat.path AS "Path_ids"
FROM prefix_course_categories cat
ORDER BY cat.id

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

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'

LOG REPORTS

Logs Skeleton Report Containing All Log Columns

Contributed by: Randy Thornton.

This query contains all the columns in the standard log table (as of Moodle 3.11 anyway). You can use this to uncomment the various fields that you want to have in a report. I have uncommented a few common columns (id, action, target, userid, courseid, etc.) so you can see how it works as well as adding some useful things such as grabbing user and course names, formatting times, etc. Note also: when commenting and uncomment near the end, be sure to take care with your final commas :)

WARNING: Do NOT use this query as is on the live site unless you are sure you know what you are doing! Logs can get really big and a log query could take a long time to run. Always add something to the WHERE clause or use other means to limit the results to what you really need.

SELECT
l.id,
# l.eventname,
# l.component,
l.action,
l.target,
# l.objecttable,
# l.objectid,
# l.crud,
# l.edulevel,
# l.contextid,
# l.contextlevel,
# l.contextinstanceid,
l.userid,
# (SELECT username FROM prefix_user WHERE id = l.userid) As "User" ,
l.courseid,
# CASE l.courseid
#  WHEN 0 THEN 'Not logged in'
#  WHEN 1 THEN 'Front page'
#  ELSE (SELECT shortname FROM prefix_course WHERE id = l.courseid)
# END AS "Course_Name" ,
# l.relateduserid,
# (SELECT username FROM prefix_user WHERE id = l.relateduserid) As "Related_User" ,
# l.anonymous,
# l.other,
# l.timecreated,
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%Y-%m-%d %H:%i') AS "Time_UTC"
# l.origin,
# l.ip,
# l.realuserid

FROM prefix_logstore_standard_log l
# you really want to add a WHERE clause to limit your results to your specific object to look for eg course, user, time frame etc
# WHERE something = something

# Sorting: TIP - time created seems more accurate than id oddly for the actual sequencing due to the way the events are logged
ORDER BY l.timecreated

Course Creation and Restore Times

Contributed by: Randy Thornton Versions: known to work in Moodle 3.8 to 3.11

When a course is created, the time and the person creating the course are logged by the event system, and the course itself also contains this time. However, when a course is restored, unfortunately, the course creation time is not updated to the time of the restore, but retains the time created for the original course you are restoring from. This can create lots of false data for course creation times (as discussed in this forum conversation and Tracker 70467.)

This report shows the actual creation time of all courses in your logs, whether created anew or restored, with the time and the user creating/restoring them. It also handles the cases where courses have been deleted or the user who created/restored them has been deleted as well.

SELECT
l.id AS "Log_id",
IF(c.id IS NULL,CONCAT("(deleted id: ",l.courseid, ")"),c.shortname) AS "Course",
IF(l.action='restored',"Restored","Created") AS "Action",
IF(u.id IS NULL,CONCAT("deleted id: ",l.userid, ")"),u.username) As "By",
DATE_FORMAT(FROM_UNIXTIME(l.timecreated),'%Y-%m-%d %H:%i') AS "At_UTC"
FROM prefix_logstore_standard_log l
LEFT JOIN prefix_course c ON c.id = l.courseid
LEFT JOIN prefix_user u ON u.id = l.userid
WHERE l.eventname =  '\\core\\event\\course_created' 
OR l.eventname = '\\core\\event\\course_restored'

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: 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: 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



Student Resource Usage for Standard Core Modules only

Updated version contributed by Randy Thornton, based on report above contributed by Elizabeth Dalton, Granite State College.

This is the same report as the above, but with thee changes so that it will work in any standard Moodle installation:

  • all the non-core, third party activity module references have been removed
  • the new core H5P Activity has been added
  • shows all the data in all courses with the course shortname (however if you want to limit it to the current course, then uncomment the "# AND c.id = %%COURSEID%%" statement in the WHERE clause)

Known to work in Moodle 3.11.

SELECT
c.shortname AS "Course",
cs.section AS "Section",
cs.name AS "Section_Name",
m.name AS "Activity_Type",
CONCAT(
COALESCE(a.name, ''),
COALESCE(b.name,''),
COALESCE(chat.name,''),
COALESCE(choice.name,''),
COALESCE(data.name,''),
COALESCE(feedback.name,''),
COALESCE(folder.name,''),
COALESCE(forum.name,''),
COALESCE(glossary.name,''),
COALESCE(h5pactivity.name,''),
COALESCE(imscp.name,''),
COALESCE(lesson.name,''),
COALESCE(p.name,''),
COALESCE(quiz.name,''),
COALESCE(cr.name,''),
COALESCE(scorm.name,''),
COALESCE(survey.name,''),
COALESCE(url.name,''),
COALESCE(wiki.name,''),
COALESCE(workshop.name,'')
) AS "Activity_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 
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_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_h5pactivity AS h5pactivity ON h5pactivity.id = cm.instance AND m.name = 'h5pactivity'
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_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_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 c.shortname, 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

Annual course/attendance report

This report is designed for a site where all students are always subscribed in every course divided in fix groups and where the lessons are organised by the teacher using the groups . The real participation is confirmed by the teacher. As also teachers are assigne to all courses, the teacher of a specific lesson is considered to be the user who created the lesson. An annual limitation parameter csnnot be added in this module, so I added a limitation to the current calendar year. Eventually a copy of the report is needed for the past year in order to be able to launch it in January, too.

SELECT CASE WHEN @date <> SESSION.sessdate OR NOT  @description = SESSION.description THEN @row := @row +1 ELSE @row END AS NR_CORSO,
FROM_UNIXTIME(SESSION.sessdate, '%d/%m/%Y') as DATA, CODAGE.data as COD_AGENZIA, AGENZIA.data as AGENZIA, 
CONCAT({user}.lastname, ' ', {user}.firstname) as NOMINATIVO, RUI.data as RUI, RUOLO.data as FUNZIONE,
REPLACE		( 
	REPLACE		( 
		REPLACE		(
			UNHEX( REPLACE( HEX( SESSION.description ), '3B', '' ) )
					, '<p dir="ltr" style="text-align: left">', '' 
				)
 	  ,  '</p>', '' )
   , '<br>', '' ) as INFO,
{course}.fullname as CORSO,
CASE WHEN upper({attendance}.name) like '%AULA%' THEN 'IN AULA' WHEN upper({attendance}.name) like '%LINE%' THEN 'WEBINAR' ELSE {attendance}.name END AS MODALITÀ_CORSO,
CONCAT(DOCENTE.lastname, ' ', DOCENTE.firstname) as DOCENTE, # ROUND(SESSION.duration/3600, 0) as ORE #, {groups}.name as Gruppo,
DURATA.charvalue as ORE, {groups}.name as Gruppo, UPPER(LEFT(RUI.data, 1)) as Categoria, STATUS.acronym as Partecipazione, # STATUS.grade	,  {user}.ID, {user}.username,
CASE WHEN {course_completions}.timecompleted is not null THEN 'SI' ELSE 'NO' END as COMPLETATO
,  @date := SESSION.sessdate AS DATUM, @description := SESSION.description AS INFO_LEZIONE, SESSION.id

FROM {attendance_sessions}  SESSION JOIN (SELECT @row := 0, @date := 0, @description := null) TEMP 
LEFT JOIN {attendance} ON {attendance}.id = SESSION.attendanceid
LEFT JOIN {attendance_log} LOG ON LOG.sessionid = SESSION.id # AND LOG.studentid = {user}.id
LEFT JOIN {attendance_statuses} STATUS ON STATUS.id = LOG.statusid 
LEFT JOIN {course_completions} ON {course_completions}.userid = LOG.studentid AND {course_completions}.course = {attendance}.course
LEFT JOIN {groups} ON {groups}.id = SESSION.groupid 
LEFT JOIN {user} ON {user}.id = LOG.studentid
LEFT JOIN {user_info_data} AGENZIA ON AGENZIA.userid = {user}.id AND AGENZIA.fieldid = 3   # AGENZIA
LEFT JOIN {user_info_data} RUI ON RUI.userid = {user}.id AND RUI.fieldid = 2    #  RUI
LEFT JOIN {user_info_data} RUOLO ON RUOLO.userid = {user}.id AND RUOLO.fieldid = 5    #  FUNZIONE
LEFT JOIN {user_info_data} CODAGE ON CODAGE.userid = {user}.id AND CODAGE.fieldid = 6    #  COD_AGE
LEFT JOIN {course}  ON {course}.id = {attendance}.course
LEFT JOIN {event} ON {event}.id = SESSION.caleventid
LEFT JOIN {user} DOCENTE ON DOCENTE.id = {event}.userid
LEFT JOIN {customfield_data} DURATA ON  INSTANCEID = {course}.id AND DURATA.FIELDID = 3	#	DURATA
WHERE NVL(STATUS.grade, 0) > 1   #   per filtrare i soli presenti
   AND FROM_UNIXTIME(SESSION.sessdate, '%d/%m/%Y') > CONCAT('01/01/', YEAR(CURDATE()))

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');


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

APPENDIX: OTHER USEFUL THINGS

Below are some sections on other items useful for building and using the reports. Feel free to share any useful items for building or using queries or the plugins here.


How-tos, sub queries and code snippets

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 or students 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. If you change the number to 5, it will list Students instead.

,(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

To get all Students instead, use the role id number of 5 instead of 3.

Forms of user names

There are a great variety of different ways to show the names of users in the reports above. Moodle, unlike some applications, does not have a single column for the users whole name, but has separate columns for first name and last name (or surname). If you just need to change the name formats, you can use any of these snippets:

SELECT
u.id AS "Internal id",
u.username,
u.firstname,
u.lastname,
CONCAT(u.firstname, ' ', u.lastname) AS "First name - last name",
CONCAT(u.lastname, ' ', u.firstname) AS "Last name - first name",
CONCAT(u.id, ' ', u.username, ' ',u.idnumber) AS "Id - username - idnumber",
u.email,
u.idnumber AS "User idnumber",
IF(u.deleted = 1, "Deleted","Not deleted") AS "Deletion status",
IF(u.suspended = 1, "Suspended","Active") AS "Suspension status"
FROM prefix_user u

Including and Excluding Deleted and Suspended Users

All users have two columns in their user entry in the prefix_user table: deleted and suspended. The value of 0 (false) means the user is not deleted or not suspended, respectively. A value of 1 (true) means the user is deleted or suspended, respectively. To exclude user accounts that have been deleted or suspended from any query, you can add a WHERE clause restriction (among other ways to do this).

To show only active users, use any of these equivalent forms:

WHERE u.deleted = 0 AND u.suspended = 0
WHERE u.deleted != 1 AND u.suspended != 1
WHERE u.deleted <> 1 AND u.suspended <> 1

To show active and suspended users, you can use:

WHERE u.deleted != 1

To show only suspended users, you can use:

WHERE u.suspended = 1

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'

Get custom User profile fields for a user Alternate (sub select) Method

If you have more than a couple of fields you need to use, then the query above using JOINs for all the custom fields may time out or not return data due to too many joins. The practical 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

Moodle Report Plugins Variables, Filters and Other Idiosyncracies

Shared variables

Both the plugins share this variable in common. Code that uses only these will run in both plugins without change:

  • %%WWWROOT%% - this substitutes the base url for your Moodle site exactly as set in the config.php file
  • %%USERID%% - this substitutes the user id (not idnumber!) of the current user running the report

Ad-hoc database queries plugin

AD variables

The following notes are taken directly from the documentation that shows up in each query right under the code edit box below the "Verify the SQL and update the form" button. Please carefully read the whole set of notes there if you think you are getting syntax or other error messages.

  • The token %%WWWROOT%% in the results will be replaced with [the root of your site as set in config.php].
  • The token %%USERID%% in the query will be replaced with the user id of the user viewing the report, before the report is executed.
  • For scheduled reports, the tokens %%STARTTIME%% and %%ENDTIME%% are replaced by the Unix timestamp at the start and end of the reporting week/month in the query before it is executed.

Forbidden URL Parameters

Pay particular attention to this section if you are constructing URLS in your code that may use parameters!

  • You cannot use the characters :, ; or ? in strings in your query. If you need them in output data (such as when outputting URLs), you can use the tokens %%C%%, %%S%% and %%Q%% respectively. If you need them in input data (such as in a regular expression or when querying for the characters), you will need to use a database function to get the characters and concatenate them yourself. In Postgres, respectively these are CHR(58), CHR(59) and CHR(63); in MySQL CHAR(58), CHAR(59) and CHAR(63).


Note that the question mark ? is often used as a url parameter in Moodle urls. Watch out for those. Please see the following forum post for more details and discussion on this: https://moodle.org/mod/forum/discuss.php?d=407295#p1648774

How AD Auto URL Linking Works

This plugin has its own method of creating links which avoids having to put any HTML in your SQL statement. Instead you designate two columns: one as the text and one as the link.

In the example below the column named "User" shows the username. The very next column is called "User_link_url" where this must be the same name as the column before but you add "_link_url" to the column name to tell the plugin this is how to build the url.

The user is the TEXT that you would normally build a link with: leave out all the HTML code, just put the link text. In the following example you will see it is a standard link to a user profile, where there are three variables: the root, a %%Q%% symbol that stands for ? and the user id. This will make a normal url of the form: https://example.com/user/profile.php?id=2 and so forth.

SELECT
u.username AS "User",
CONCAT("%%WWWROOT%%/user/profile.php%%Q%%id=", u.id) AS "User_link_url" 
FROM prefix_user u

Note that even though there are two columns defined in the SELECT statement, they are collapsed into one column by the plugin. The output of this sample will be a one column list of usernames, all linked to their user profile pages.

If you only want the full url to show up linkable, then use just the one column without designating the name, e.g.

SELECT
CONCAT("%%WWWROOT%%/user/profile.php%%Q%%id=", u.id) AS "User" 
FROM prefix_user u

The output of this query will be single column of full urls to the users profiles that are already linked.

Configurable Reports plugin

CR Variables

For fuller documentation and examples, please see the official Configurable Reports documentation page.

This is a list of the variables that you can use with the Configurable Reports plugin in your queries. Place the variable where you would the corresponding column. You will see numerous examples of these in the queries above.

  • %%CATEGORYID%%
  • %%COURSEID%%
  • %%CURRENTUSER%%
  • %%DEBUG%%
  • %%FILTER_VAR%%
  • %%STARTTIME%%
  • %%ENDTIME%%
  • %%USERID%%
  • %%WWWROOT%%


For example, to run a report that shows the current user their own profile information, you can use the %%USERID%% variable in place of the user id:

SELECT username, firstname, lastname, email
FROM prefix_user
WHERE id = %%USERID%%

To add logic to any query run inside a course to limit it to the data just for that course, use the %%COURSEID%% variable:

SELECT shortname, fullname
FROM prefix_course
WHERE id = %%COURSEID%%

(Tip: if you run this outside of a course on the front page or dashboard, it will return the name of the site, which is technically course id = 1)

CR Filters

If you know how these work and have some code examples, feel free to share your knowledge here. Meanwhile, for fuller documentation and examples, please see the official Configurable Reports documentation page.

List of CR Filters
  • %%FILTER_CATEGORIES:
  • %%FILTER_COURSEMODULEID:
  • %%FILTER_COURSEMODULEFIELDS:
  • %%FILTER_COURSEMODULE:
  • %%FILTER_COURSES:
  • %%FILTER_COURSEENROLLEDSTUDENTS:
  • %%FILTER_USERS:
  • %%FILTER_ROLE:
  • %%FILTER_SEARCHTEXT:
  • %%FILTER_SEMESTER:
  • %%FILTER_STARTTIME:
  • %%FILTER_ENDTIME:
  • %%FILTER_SUBCATEGORIES:
  • %%FILTER_COURSEUSER:
  • %%FILTER_SYSTEMUSER:
  • %%FILTER_YEARHEBREW:
  • %%FILTER_YEARNUMERIC:


CR Filters Location

Configurable Reports filters are part of the WHERE clause of your query. The CR code will take the filters it finds and then put in the proper syntax for the filters as it builds the query. Therefore, your filters have to be in the proper location as part of the WHERE clause, and so they must come before any other clauses that may follow such as GROUP BY, HAVING BY, or ORDER BY or others, in accordance with the SQL standards for syntax.

For example, the following is correct where the filters are after the WHERE clause and before any other clauses, in this case ORDER BY:

SELECT cat.name,
c.shortname,
c.fullname,
c.summary
FROM prefix_course c
JOIN prefix_course_categories cat
WHERE cat.id = 1
%%FILTER_SEARCHTEXT_S:c.summary:~%%
%%FILTER_COURSES:c.shortname%%
ORDER BY c.shortname

When this is run, it will be interpreted as:

WHERE cat.id =1 
AND {the text you have entered in the search box to find in the course summary}
AND {the course name you have chosen from the pull down menu}


What if you have no WHERE clause?

If your query doesn't have a WHERE clause, you MUST ADD a dummy WHERE clause in order to use the filters. A common form of which is just to use WHERE 1=1. For example, this is CORRECT:

WHERE 1=1
%%FILTER_SEARCHTEXT_S:c.summary:~%%
%%FILTER_COURSES:c.shortname%%
ORDER BY c.shortname

However, the following is INCORRECT and will not work: the query will appear to work but when you do anything with the filters, it will generate a SQL Error telling you there was a syntax error, because the "AND" comes immediately after the "JOIN" and that is a syntax error.

SELECT cat.name,
c.shortname,
c.fullname,
c.summary
FROM prefix_course c
JOIN prefix_course_categories cat
# ooops there's no WHERE statement here!
%%FILTER_SEARCHTEXT_S:c.summary:~%%
%%FILTER_COURSES:c.shortname%%
ORDER BY c.shortname

Moral of the story? IF you are using FILTERS you must always have a WHERE clause.

Using the Search Text filter

Contributed by: Randy Thornton

In the Configurable reports block for Moodle 3.11, CR version 3.9.0 (2020110390), there is a new way of naming the Search text filter. The goal of this new method is to allow you to now have more than one Search text filter for the same query, so that you can search more than one column from your report. The following shows how to do this.

In your code, you must add an identifier to your filter like this FILTER_SEARCHTEXT_ID1 where ID1 is just any arbitrary identifier you want. I usually just use _1 or _2 but you could use _username or to make it clearer just _U for username as a reminder.

Step 1: Add an ID to the end of the filter name %%FILTER_SEARCHTEXT_ID. The ID can be any one letter, number or word that you wish. Note that there must be an underscore!!. Also, the ID is case sensitive. For example:

SELECT
u.username,
u.firstname,
u.lastname
FROM prefix_user u
WHERE 1=1
%%FILTER_SEARCHTEXT_U:u.username:~%%

will let you search on the username field of your report. You could use _U or _u or _username or _1 or any indicator you want as long as it is not duplicated by any other SEARCHTEXT id you may add.


Step 2: In the filter tab for the ID, add ONLY the identifier part without the underscore line, so 1 or 2 or U or whatever you use. Do NOT use the whole filter starting with the %% or include the underscore, use only the ID itself. So, for this example, put the ID "U".


Adding Multiple Searches

This method allows you to have two filters to search with, so:

SELECT
u.username,
u.firstname,
u.lastname
FROM prefix_user u
WHERE 1=1
%%FILTER_SEARCHTEXT_U:u.username:~%%
%%FILTER_SEARCHTEXT_F:u.firstname:~%%

then you would add two filters in the Filters tab, one with an ID of U and the Second with the ID of F - and put Labels of "Username" and "Firstname" so that the user knows which is which.

Example Output with two Search Text filters:

cr-searchtextoutput.jpg


Backwards compatibility

For backwards compatibility and filters without idnumber, this old method of matching without idnumber still works if you are only using a single searchtext filter in your query.

Using the 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.)


CR Security setting and "Not Allowed Words" message

The CR plugin has two security modes, high and low.

In plugin versions 3.8 and below, this is controlled by the setting in Site administration > Plugins > Blocks > Configurable Reports > SQL Security. The default is On, which is the high security mode. Unchecking this will enable low security mode.

In plugin version 3.9 and above (released November 2020), you must also set a variable in your config.php file as follows for this feature to work, as per the documentation:

Starting this version for allowing SQL queries performing data insertion/creation the following configuration variable set to 1 is required in your site root /config.php:

$CFG->block_configurable_reports_enable_sql_execution = 1;

Otherwise, previous Custom SQL reports performing data insertion/creation will stop working.


In high security mode, the plugin blocks the following SQL keywords:

ALTER | CREATE | DELETE | DROP | GRANT | INSERT | INTO | TRUNCATE | UPDATE | SET | VACUUM | REINDEX | DISCARD | LOCK

If your code uses any of these keywords, you will receive a "Not allowed words" error message when trying to run the query.

In low security mode, the plugin will allow the keywords INSERT | INTO | CREATE but will continue to block those other keywords. This means that low security mode will allow you to CREATE new tables, including temporary ones, and insert data into them, but it will not allow you to use UPDATE to alter current table data.

For more, see the code in /components/customsql/form.php around lines 80.

Useful Constants

Role id numbers

The standard default roles as installed have the id numbers as follows:

  • 1 Manager
  • 2 Course creator
  • 3 Editing Teacher
  • 4 Non-editing Teacher
  • 5 Student
  • 6 Guest
  • 7 Authenticated user
  • 8 Authenticated user on the frontpage


You can see all your roles with the simple query:

SELECT * FROM prefix_role

Context level ids

These are the constants used in the context levels in the context table and elsewhere.

  • SYSTEM = 10
  • PERSONAL = 20
  • USER = 30
  • COURSECAT = 40
  • COURSE = 50
  • GROUP = 60
  • MODULE = 70
  • BLOCK = 80

The following snippet can be helpful (assuming an alias of ctx for the context table):

CASE ctx.contextlevel 
  WHEN 10 THEN 'System'
  WHEN 20 THEN 'Personal'
  WHEN 30 THEN 'User'
  WHEN 40 THEN 'Course_Category'
  WHEN 50 THEN 'Course'
  WHEN 60 THEN 'Group'
  WHEN 70 THEN 'Activity_Module'
  WHEN 80 THEN 'Block'
 ELSE CONCAT('Unknown context: ',ctx.contextlevel)
END AS "Context_level"

Constants for permission levels

Constants for permissions are:

  • 1 = Allow
  • -1 = Prevent
  • -1000 = Prohibit


"Not set" is NULL and will have no table entry in the role definition.

Constants for Course Restores

Constants that tell you what type of restore was being done. These are used in the logs in the 'Other' field for the 'target' parameter.

  • TARGET_CURRENT_DELETING = 0
  • TARGET_CURRENT_ADDING = 1
  • TARGET_NEW_COURSE = 2
  • TARGET_EXISTING_DELETING = 3
  • TARGET_EXISTING_ADDING = 4


So, a standard restore of a new course from backup is 2. ADDING is what is called in the Moodle interface as a "merge". DELETING is overwriting the current or another existing course with the backup.

Logs origin

Meaning of the strings in the origin field in the standard logs:

  • cli - command line interface, including scheduled tasks and cron events
  • restore - an event done during a course restore
  • web - normal events by users in the web interface
  • ws - web services calls, including those from the mobile app

See also

Database Schema

There is a version of the database schema located here on the Moodle DB schema explorer which you can use for searching and filtering tables, fields and external key connections between tables, and other information.

Adminer plugin

To help work with the database, you can use the Moodle Adminer plugin. This is especially useful if you do not have access to the database on your server via some third-party tool such as PhpMyAdmin.

Github repository

For more reports you can also check on the Configurable Reports Repository on GitHub.