Note: You are currently viewing documentation for Moodle 2.8. 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
(Number of distinct learners and teachers enrolled per category (including all its sub categories))
(Added report: Courses with Empty Groups & Forum in Group Mode)
 
(43 intermediate revisions by 12 users not shown)
Line 2: Line 2:
==User and Role Report==
==User and Role Report==


===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)===
SELECT COUNT(DISTINCT lra.userid) AS learners, COUNT(DISTINCT tra.userid) as teachers
<code sql>SELECT COUNT(DISTINCT lra.userid) AS learners, COUNT(DISTINCT tra.userid) as teachers
FROM prefix_course AS c #, mdl_course_categories AS cats
FROM prefix_course AS c #, mdl_course_categories AS cats
LEFT JOIN prefix_context AS ctx ON c.id = ctx.instanceid
LEFT JOIN prefix_context AS ctx ON c.id = ctx.instanceid
Line 11: Line 11:
WHERE c.category = cats.id
WHERE c.category = cats.id
AND (
AND (
cats.path LIKE '%/80/%'
cats.path LIKE '%/CATEGORYID/%' #Replace CATEGORYID with the category id you want to count (eg: 80)
OR cats.path LIKE '%/80'
OR cats.path LIKE '%/CATEGORYID'
)
)
AND lra.roleid=5
AND lra.roleid=5
AND tra.roleid=3
AND tra.roleid=3</code>


===Detailed ACTIONs for each ROLE (TEACHER, NON-EDITING TEACHER and STUDENT)===
===Detailed ACTIONs for each ROLE (TEACHER, NON-EDITING TEACHER and STUDENT)===
Line 42: Line 42:
GROUP BY course.id
GROUP BY course.id
ORDER BY COUNT(course.id) DESC
ORDER BY COUNT(course.id) DESC
</code>
=== Enrolment count in each Course ===
Shows the total number of enroled users of all roles in each course. Sorted by course name.
<code sql>
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
</code>
</code>


Line 95: Line 108:
WHERE c.id=16 AND ul.timeaccess IS NULL
WHERE c.id=16 AND ul.timeaccess IS NULL
%%FILTER_SEARCHTEXT:user2.firstname%%
%%FILTER_SEARCHTEXT:user2.firstname%%
</code>
===Role assignments on categories===
<code sql>
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
</code>
</code>


Line 111: Line 141:
(By: [http://moodle.org/mod/forum/discuss.php?d=153059#p712837 Séverin Terrier] )
(By: [http://moodle.org/mod/forum/discuss.php?d=153059#p712837 Séverin Terrier] )
<code sql>
<code sql>
SELECT id , category , fullname , shortname , enrollable
SELECT
FROM `prefix_course`
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS id,
WHERE `guest` =1
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS 'Course',
AND `password` = ""
concat('<a target="_new" href="%%WWWROOT%%/enrol/instances.php?id=',c.id,'">Méthodes inscription</a>') AS 'Enrollment plugins',
AND `visible` =1
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
</code>
</code>


Line 211: Line 243:
For Moodle 2.2 , by  Isuru Madushanka Weerarathna  
For Moodle 2.2 , by  Isuru Madushanka Weerarathna  
<code sql>
<code sql>
SELECT uenr.userid As User, IF(enr.courseid=enr.courseid ,'Y','N') As Enrolled,  
SELECT uenr.userid As User, IF(enr.courseid=uenr.courseid ,'Y','N') As Enrolled,  
IF(DATEDIFF(NOW(), FROM_UNIXTIME(uenr.timecreated))>=28,'Y','N') As EnrolledMoreThan4Weeks
IF(DATEDIFF(NOW(), FROM_UNIXTIME(uenr.timecreated))>=28,'Y','N') As EnrolledMoreThan4Weeks
FROM prefix_enrol As enr, prefix_user_enrolments AS uenr
FROM prefix_enrol As enr, prefix_user_enrolments AS uenr
Line 230: Line 262:
<code sql>
<code sql>
UPDATE prefix_user SET lang = 'en_us' WHERE lang = 'en'
UPDATE prefix_user SET lang = 'en_us' WHERE lang = 'en'
</code>
=== List of users with Authentication ===
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:
<code sql>
SELECT username, auth from prefix_user
</code>
This code will change the setting from 'manual' to 'ldap' for all users except for the first two accounts which are Guest and Admin. (WARNING: it is bad practice to change you admin account from manual to an external method as failure of that external method will lock you out of Moodle as admin.)
<code sql>
UPDATE prefix_user SET auth = 'ldap' WHERE auth = 'manual' AND id > 2
</code>
</code>


Line 252: Line 299:


==Log Activity Reports==
==Log Activity Reports==
===Count all Active Users by ROLE in a course category (including all of its sub-categories)===
<code sql>
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
</code>
===Detailed "VIEW" ACTION for each ROLE (TEACHER,NONE-EDITING TEACHER and STUDENT)===
===Detailed "VIEW" ACTION for each ROLE (TEACHER,NONE-EDITING TEACHER and STUDENT)===
<code sql>
<code sql>
Line 304: Line 366:
</code>
</code>


==Course Reports==
===Weekly Instructor Online Participation===
===Most Active courses===
Contributed by Elizabeth Dalton
 
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.
 
<code sql>
<code sql>
SELECT COUNT(l.id) hits, l.course courseId, c.fullname coursename
SELECT  
FROM prefix_log l INNER JOIN prefix_course c ON l.course = c.id
c.shortname AS CourseID
GROUP BY courseId
, cc.name AS Category
ORDER BY hits DESC
, CONCAT(u.firstname ,' ',u.lastname) AS Instructor
</code>
 
, (SELECT COUNT( ra2.userid ) AS Users2 FROM prefix_role_assignments AS ra2
JOIN prefix_context AS ctx2 ON ra2.contextid = ctx2.id
WHERE ra2.roleid = 5 AND ctx2.instanceid = c.id) AS Students
 
, c.startdate AS Course_Start_Date
 
, c.visible AS Visible
 
,  COUNT(l.id) AS Edits


===Active courses, advanced===
, SUM(IF(WEEK(FROM_UNIXTIME(l.time)) - WEEK(FROM_UNIXTIME(c.startdate))<0,1,0)) AS BeforeTerm
Including: Teacher's name, link to the course, All types of log activities, special YEAR generated field, Activities and Resource count, enrolled Student count
<code sql>
SELECT COUNT(l.id) hits, concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course


,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=0,1,0)) AS Week1
FROM prefix_role_assignments AS ra
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=1,1,0)) AS Week2
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=2,1,0)) AS Week3
JOIN prefix_user AS u ON u.id = ra.userid
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))=3,1,0)) AS Week4
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
, 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


,CASE
, SUM(IF(WEEK(FROM_UNIXTIME(l.time))-WEEK(FROM_UNIXTIME(c.startdate))>=12,1,0)) AS AfterTerm
  WHEN c.fullname LIKE '%תשע' THEN 'תשע'
  WHEN c.fullname LIKE '%תשעא' THEN 'תשעא'
  WHEN c.fullname LIKE '%תשעב' THEN 'תשעב'
END AS Year


,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = l.course) Modules
, 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


,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
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_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
JOIN prefix_course AS c ON c.id = ctx.instanceid
JOIN prefix_course_categories as cc ON c.category = cc.id


FROM prefix_log l  
LEFT JOIN prefix_log AS l ON l.userid = u.id AND l.course = c.id AND l.action NOT LIKE "view%"
INNER JOIN prefix_course c ON l.course = c.id
 
GROUP BY c.id
WHERE ra.roleid =3
HAVING Modules > 2
AND ctx.instanceid = c.id
ORDER BY Year DESC, hits DESC
AND c.shortname LIKE :course
AND u.lastname LIKE :last_name
 
GROUP BY u.idnumber, c.id
HAVING students > 0
ORDER BY c.shortname
</code>
</code>


===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.
===Module activity (Hits) between dates===
<code sql>
<code sql>
SELECT COUNT(*)
SELECT module, COUNT( * )  
FROM (SELECT c.id AS CourseID, c.fullname AS Course, ra.roleid AS RoleID, CONCAT(u.firstname, ' ', u.lastname) AS Teacher
FROM prefix_log AS l
,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = c.id) AS Modules
WHERE (FROM_UNIXTIME( l.`time` ) BETWEEN  '2012-10-01 00:00:00' AND  '2013-09-31 00:00:00')
FROM prefix_course AS c
GROUP BY module
JOIN prefix_context AS ctx ON c.id = ctx.instanceid AND ctx.contextlevel = 50
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE ra.roleid = 3
GROUP BY u.id
HAVING Modules > 5) AS ActiveTeachers
</code>
</code>


===RESOURCE count for each COURSE===
===Module activity (Instances and Hits) for each academic year===
<code sql>
<code sql>
SELECT COUNT(l.id) count, l.course, c.fullname coursename
SELECT name
FROM prefix_resource l INNER JOIN prefix_course c on l.course = c.id
GROUP BY course
ORDER BY count DESC
</code>


===Common resource types count for each Category (Moodle19)===
,(SELECT COUNT(*)
Including sub-categories in total count.
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2010-10-01 00:00:00' AND '2011-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2010"
 
,(SELECT COUNT(*)
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2010-10-01 00:00:00' AND '2011-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2010"
 
,(SELECT COUNT(*)  
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2011-10-01 00:00:00' AND '2012-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2011"
 
,(SELECT COUNT(*)
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2011-10-01 00:00:00' AND '2012-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2011"
 
 
,(SELECT COUNT(*)
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2012-10-01 00:00:00' AND '2013-09-31 00:00:00')
AND l.module = m.name AND l.action = 'add'
) AS "Added 2012"
 
,(SELECT COUNT(*)
FROM mdl_log AS l
WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2012-10-01 00:00:00' AND '2013-09-31 00:00:00')
AND l.module = m.name
) AS "Used 2012"
 
FROM mdl_modules AS m
</code>
 
===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)
<code 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))
</code>
 
==Course Reports==
===Most Active courses===
<code sql>
<code sql>
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category
SELECT count(l.userid) AS Views
,(SELECT COUNT( * )
FROM `mdl_logstore_standard_log` l, `mdl_user` u, `mdl_role_assignments` r
FROM prefix_resource AS r
WHERE l.courseid=35
JOIN prefix_course AS c ON c.id = r.course
AND l.userid = u.id
JOIN prefix_course_categories AS cc ON cc.id = c.category
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= (
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference LIKE 'http://%'
SELECT id
) AS Links
FROM mdl_context
WHERE contextlevel=50 AND instanceid=l.courseid
,(SELECT COUNT( * )  
  )
FROM prefix_resource AS r
AND r.roleid=5
JOIN prefix_course AS c ON c.id = r.course
AND r.userid = u.id
JOIN prefix_course_categories AS cc ON cc.id = c.category
</code>
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference NOT LIKE 'http://%'
) AS Files
,(SELECT COUNT( * )
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'directory'
) AS Folders
   
,(SELECT COUNT( * )  
FROM prefix_resource AS r
JOIN prefix_course AS c ON c.id = r.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'html'
) AS Pages
,(SELECT COUNT(*)
FROM stats_log_context_role_course
WHERE roleid = 5 AND module = 'resource' AND category = mcc.id
) AS Hits


FROM prefix_course_categories AS mcc
===Active courses, advanced===
ORDER BY mcc.path
Including: Teacher's name, link to the course, All types of log activities, special YEAR generated field, Activities and Resource count, enrolled Student count
</code>
Where "stats_log_context_role_course" (in the above SQL query) is a VIEW generated by:
<code sql>
<code sql>
CREATE VIEW stats_log_context_role_course AS
SELECT COUNT(l.id) hits, concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
SELECT l.course, c.category, cc.path, l.module, l.action, ra.userid, ra.roleid
FROM prefix_log AS l
JOIN prefix_context AS context ON context.instanceid = l.course AND context.contextlevel = 50
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid AND ra.contextid = context.id
JOIN prefix_course AS c ON c.id = l.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
</code>


Same query but for Moodle2+
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
<code sql>
FROM prefix_role_assignments AS ra
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category,
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
mcc.path,
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(*)
,CASE
FROM prefix_url AS u
  WHEN c.fullname LIKE '%תשע' THEN 'תשע'
JOIN prefix_course AS c ON c.id = u.course
  WHEN c.fullname LIKE '%תשעא' THEN 'תשעא'
JOIN prefix_course_categories AS cc ON cc.id = c.category
  WHEN c.fullname LIKE '%תשעב' THEN 'תשעב'
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
END AS Year
) AS URLs,


(SELECT COUNT(*)  
,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = l.course) Modules
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(*)  
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
FROM prefix_page AS p
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_course AS c ON c.id = p.course
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
) AS PAGEs,


(SELECT COUNT(*)
FROM prefix_log l
FROM prefix_book AS b
INNER JOIN prefix_course c ON l.course = c.id
JOIN prefix_course AS c ON c.id = b.course
GROUP BY c.id
JOIN prefix_course_categories AS cc ON cc.id = c.category
HAVING Modules > 2
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
ORDER BY Year DESC, hits DESC
) AS BOOKs,
</code>


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


===Detailed Resource COUNT by Teacher in each course===
===RESOURCE count for each COURSE===
 
<code sql>
Including (optional) filter by: year, semester and course id.
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
</code>


===Common resource types count for each Category (Moodle19)===
Including sub-categories in total count.
<code sql>
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS CourseID
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category
, c.id
,(SELECT COUNT( * )  
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
FROM prefix_resource AS r
  FROM prefix_role_assignments AS ra
JOIN prefix_course AS c ON c.id = r.course
  JOIN prefix_user AS u ON ra.userid = u.id
JOIN prefix_course_categories AS cc ON cc.id = c.category
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference LIKE 'http://%'
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
) AS Links
 
, (CASE
,(SELECT COUNT( * )
WHEN c.fullname LIKE '%תשעב%' THEN '2012'  
FROM prefix_resource AS r
WHEN c.fullname LIKE '%תשעא%' THEN '2011'
JOIN prefix_course AS c ON c.id = r.course
END ) as Year
JOIN prefix_course_categories AS cc ON cc.id = c.category
, (CASE
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference NOT LIKE 'http://%'
WHEN c.fullname LIKE '%סמסטר א%' THEN 'Semester A'
) AS Files
WHEN c.fullname LIKE '%סמסטר ב%' THEN 'Semester B'
WHEN c.fullname LIKE '%סמסטר ק%' THEN 'Semester C'
,(SELECT COUNT( * )  
END ) as Semester
FROM prefix_resource AS r
,COUNT(c.id) AS Total
JOIN prefix_course AS c ON c.id = r.course
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 20) AS TABs
JOIN prefix_course_categories AS cc ON cc.id = c.category
,(SELECT count(*) FROM prefix_course_modules AS cm WHERE cm.course = c.id AND cm.module= 33) AS BOOKs
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'directory'
 
) AS Folders
FROM `prefix_resource` as r  
JOIN `prefix_course` AS c on c.id = r.course
,(SELECT COUNT( * )  
#WHERE type= 'file' and reference NOT LIKE 'http://%'  
FROM prefix_resource AS r
 
JOIN prefix_course AS c ON c.id = r.course
#WHERE 1=1
JOIN prefix_course_categories AS cc ON cc.id = c.category
#%%FILTER_YEARS:c.fullname%%
WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'html'  
#AND c.fullname LIKE '%2013%'
) AS Pages
,(SELECT COUNT(*)
FROM stats_log_context_role_course
WHERE roleid = 5 AND module = 'resource' AND category = mcc.id
) AS Hits


GROUP BY course
FROM prefix_course_categories AS mcc
ORDER BY COUNT(c.id) DESC
ORDER BY mcc.path
</code>
</code>
 
Where "stats_log_context_role_course" (in the above SQL query) is a VIEW generated by:
===Courses that are defined as using GROUPs===
<code sql>
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/group/index.php?id=',c.id,'">',c.fullname,'</a>') AS Course
CREATE VIEW stats_log_context_role_course AS
,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = c.id) Modules
SELECT l.course, c.category, cc.path, l.module, l.action, ra.userid, ra.roleid
,(SELECT count(*) FROM prefix_groups g WHERE g.courseid = c.id) Groups
FROM prefix_log AS l
FROM `prefix_course` AS c
JOIN prefix_context AS context ON context.instanceid = l.course AND context.contextlevel = 50
WHERE groupmode > 0
JOIN prefix_role_assignments AS ra ON ra.userid = l.userid AND ra.contextid = context.id
JOIN prefix_course AS c ON c.id = l.course
JOIN prefix_course_categories AS cc ON cc.id = c.category
</code>
</code>


===Courses with Groups===
Same query but for Moodle2+
 
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.
 
<code sql>
<code sql>
SELECT c.shortname, g.name, c.groupmode
SELECT mcc.id AS mccid, CONCAT( LPAD( '', mcc.depth, '.' ) , mcc.name ) AS Category,
FROM prefix_course AS c
mcc.path,
JOIN prefix_groups AS g ON c.id = g.courseid
WHERE c.groupmode > 0
</code>


===Groups in course with member list===
(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,


List the groups in a course (replace the # by the course id number) with the members of each group.
(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,


<code sql>
(SELECT COUNT(*)
SELECT c.shortname, g.name AS Groupname, u.username
FROM prefix_page AS p
FROM prefix_course AS c
JOIN prefix_course AS c ON c.id = p.course
JOIN prefix_groups AS g
JOIN prefix_course_categories AS cc ON cc.id = c.category
JOIN prefix_groups_members AS m ON g.id = m.groupid
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
JOIN prefix_user AS u ON m.userid = u.id
) AS PAGEs,
WHERE c.id = #
</code>


===Group Export===
(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,


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


<code sql>
(SELECT COUNT(*)
SELECT g.name AS groupname, g.description, g.enrolmentkey
FROM prefix_tab AS t
FROM prefix_groups AS g
JOIN prefix_course AS c ON c.id = t.course
JOIN prefix_course as c ON g.courseid = c.id
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE c.id = #
WHERE cc.path LIKE CONCAT( '%/', mccid, '%' )
</code>
) AS TABs


===List all Courses in and below a certain category===
FROM prefix_course_categories AS mcc
Use this SQL code to retrieve all courses that exist in or under a set category.
ORDER BY mcc.path
 
$s should be the id of the category you want to know about...
<code 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'
)
</code>
</code>


===List all Categories in one level below a certain category===
===Detailed Resource COUNT by Teacher in each course===
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.
Including (optional) filter by: year, semester and course id.
<code php>
<?php


require_once('./config.php');
<code sql>
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


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


$categories= array();
FROM `prefix_resource` as r
JOIN `prefix_course` AS c on c.id = r.course
#WHERE type= 'file' and reference NOT LIKE 'http://%'


$categories = get_categories($parent_id);
#WHERE 1=1
#%%FILTER_YEARS:c.fullname%%
#AND c.fullname LIKE '%2013%'


echo '<ol>';
GROUP BY course
foreach ($categories as $category)
ORDER BY COUNT(c.id) DESC
        {
        echo '<li><a href="'.$CFG->wwwroot.'/course/category.php?id='.$category->id.'">'.$category->name.'</a></li>';
        }
echo '</ol>';
 
?>
</code>
</code>


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


===All Courses which uploaded a Syllabus file===
===Courses with Groups===
+ under specific Category
 
+ show first Teacher in that 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.
+ link Course's fullname to actual course
 
<code sql>
<code sql>
SELECT
SELECT c.shortname, g.name, c.groupmode
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
FROM prefix_course AS c
,c.shortname,r.name
JOIN prefix_groups AS g ON c.id = g.courseid
,(SELECT CONCAT(u.firstname,' ', u.lastname) as Teacher
WHERE c.groupmode > 0
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user as u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) as Teacher
FROM prefix_resource as r
JOIN prefix_course as c ON r.course = c.id
WHERE ( r.name LIKE '%סילבוס%' OR r.name LIKE '%סילאבוס%' OR r.name LIKE '%syllabus%' OR r.name LIKE '%תכנית הקורס%' )
AND c.category IN (10,18,26,13,28)
</code>
</code>
 
===Site-wide completed SCORM activities by Course name===
===Users enrolled in a course with groups but not assigned a group ===
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.
 
Displays by course all enrolled users that have not been assigned a group.  
 
<code sql>
<code sql>
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
SELECT
FROM prefix_scorm_scoes_track AS st
course.fullname AS Course,
JOIN prefix_user AS u ON st.userid=u.id
user.firstname AS Firstname,
JOIN prefix_scorm AS sc ON sc.id=st.scormid
user.lastname AS Lastname,
JOIN prefix_course AS c ON c.id=sc.course
user.email AS Email,
WHERE st.value='completed'
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt
</code>


==Grade and Course Completion Reports==
FROM prefix_course AS course
===Site-Wide Grade Report with All Items===
JOIN prefix_enrol AS en ON en.courseid = course.id
Shows grades for all course items along with course totals for each student. Works with ad-hoc reports or Configurable Reports
JOIN prefix_user_enrolments AS ue ON ue.enrolid = en.id
<code sql>
JOIN prefix_user as user ON user.id = ue.userid
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
WHERE user.id NOT IN (
  WHEN gi.itemtype = 'course'
SELECT u.id
  THEN c.fullname + ' Course Total'
FROM prefix_course AS c
  ELSE gi.itemname
JOIN prefix_groups AS g ON c.id = g.courseid
END AS 'Item Name',
JOIN prefix_groups_members AS m ON g.id = m.groupid
JOIN prefix_user AS u ON m.userid = u.id
WHERE c.id = course.id
)


ROUND(gg.finalgrade,2) AS Grade,
ORDER BY Course, Lastname, Firstname
DATEADD(ss,gi.timemodified,'1970-01-01') AS Time
</code>


===Groups in course with member list===
List the groups in a course (replace the # by the course id number) with the members of each group.
<code sql>
SELECT c.shortname, g.name AS Groupname, u.username
FROM prefix_course AS c
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_groups AS g ON g.courseid = c.id
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_groups_members AS m ON g.id = m.groupid
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_user AS u ON m.userid = u.id
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
WHERE c.id = #
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
</code>
JOIN prefix_course_categories as cc ON cc.id = c.category


WHERE  gi.courseid = c.id
===Group Export===
ORDER BY lastname
</code>
For MySQL users, you'll need to use the MySQL DATE_ADD function instead of DATEADD. Replace the line
<code>
DATEADD(ss,gi.timemodified,'1970-01-01') AS Time
</code>
with
<code>
DATE_ADD('1970-01-01', INTERVAL gi.timemodified SECOND) AS Time
</code>


===Site-Wide Grade Report with Just Course Totals===
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.
A second site-wide grade report for all students that just shows course totals. Works with ad-hoc reports or Configurable Reports
<code sql>
SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name',  
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,
<code sql>
DATEADD(ss,gg.timemodified,'1970-01-01') AS Time
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 = #
</code>


FROM prefix_course AS c
===List all Courses in and below a certain category===
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
Use this SQL code to retrieve all courses that exist in or under a set category.
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'
$s should be the id of the category you want to know about...
 
<code sql>
ORDER BY lastname
SELECT prefix_course. * , prefix_course_categories. *
</code>
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'
)
</code>


For MySQL users:
===List all Categories in one level below a certain category===
<code sql>
Use this PHP code to retrieve a list of all categories below a certain category.
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,
$s should be the id of the top level category you are interested in.
FROM_UNIXTIME(gg.timemodified) AS TIME
<code php>
<?php
FROM prefix_course AS c
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE  gi.courseid = c.id
ORDER BY lastname
</code>


===Learner report by Learner with grades===
require_once('./config.php');
Which Learners in which course and what are the grades
<code sql>
SELECT u.firstname AS 'Name' , u.lastname AS 'Surname', c.fullname AS 'Course', cc.name AS 'Category',
CASE WHEN gi.itemtype = 'Course'   
THEN c.fullname + ' Course Total' 
ELSE gi.itemname
END AS 'Item Name', ROUND(gg.finalgrade,2) AS Score,ROUND(gg.rawgrademax,2) AS Max, ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) as Percentage,


if (ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) > 79,'Yes' , 'No') as Pass
$parent_id = $s;


FROM prefix_course AS c
$categories= array();
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE  gi.courseid = c.id and gi.itemname != 'Attendance'
ORDER BY `Name` ASC
</code>


===User Course Completion===
$categories = get_categories($parent_id);


A very simple report with list of course completion status by username. Completions are noted by date, blank otherwise.  
echo '<ol>';
foreach ($categories as $category)
        {
        echo '<li><a href="'.$CFG->wwwroot.'/course/category.php?id='.$category->id.'">'.$category->name.'</a></li>';
        }
echo '</ol>';


<code sql>
?>
SELECT u.username, c.shortname, 
DATE_FORMAT(FROM_UNIXTIME(p.timecompleted
),'%Y-%m-%d')
AS completed
FROM prefix_course_completions AS p
JOIN prefix_course AS c ON p.course = c.id
JOIN prefix_user AS u ON p.userid = u.id
WHERE c.enablecompletion = 1
ORDER BY u.username
</code>
</code>


===User Course Completion with Criteria===
===Blog activity per Course (not including VIEW)===
 
Filter activity logging to some specific Course Categories!
A report with course completions by username, with Aggregation method, Criteria types, and Criteria detail where available.
+ link course name to actual course (for quick reference)
 
(you can change %blog% to %wiki% to filter down all wiki activity or any other module you wish)
<code sql>
<code sql>
SELECT u.username AS user,  
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID
c.shortname AS course,
,m.name ,count(cm.id) as counter
DATE_FORMAT(FROM_UNIXTIME(t.timecompleted),'%Y-%m-%d') AS completed,
,(SELECT Count( ra.userid ) AS Users
CASE
FROM prefix_role_assignments AS ra
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"
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
ELSE "All"
WHERE ra.roleid = 5
END AS aggregation,
AND ctx.instanceid = c.id
CASE
) AS Students
WHEN p.criteriatype = 1 THEN "Self"
, ( SELECT count(id) FROM prefix_log WHERE `module` LIKE '%blog%' AND course = c.id AND action NOT LIKE '%view%' ) as BlogActivity
WHEN p.criteriatype = 2 THEN "By Date"
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
WHEN p.criteriatype = 3 THEN "Unenrol Status"
WHERE m.name LIKE '%blog%' AND c.category IN ( 8,13,15)
WHEN p.criteriatype = 4 THEN "Activity"
GROUP BY cm.course,cm.module order by counter desc
WHEN p.criteriatype = 5 THEN "Duration"
</code>
WHEN p.criteriatype = 6 THEN "Course Grade"
 
WHEN p.criteriatype = 7 THEN "Approve by Role"
===Student's posts content in all course blogs (oublog)===
WHEN p.criteriatype = 8 THEN "Previous Course"
<code sql>
END AS criteriatype,
SELECT
CASE
b.name
WHEN p.criteriatype = 1 THEN "*"
,op.title
WHEN p.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(p.timeend),'%Y-%m-%d')
,op.message
WHEN p.criteriatype = 3 THEN t.unenroled
,( SELECT CONCAT(u.firstname, ' ',u.lastname) FROM prefix_user AS u WHERE u.id = oi.userid) AS "Username"
WHEN p.criteriatype = 4 THEN
 
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',p.module,'/view.php?id=',p.moduleinstance,'">',p.module,'</a>')
FROM prefix_oublog_posts AS op
WHEN p.criteriatype = 5 THEN p.enrolperiod
JOIN prefix_oublog_instances AS oi ON oi.id = op.oubloginstancesid
WHEN p.criteriatype = 6 THEN CONCAT('Needed: ',ROUND(p.gradepass,2),' Achieved: ',ROUND(t.gradefinal,2))  
JOIN prefix_oublog as b ON b.id = oi.oublogid
WHEN p.criteriatype = 7 THEN p.role
JOIN prefix_course AS c ON b.course = c.id
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


WHERE c.id = %%COURSEID%%
</code>
</code>


===Courses with Completion Enabled and their settings===
===All Courses which uploaded a Syllabus file===
 
+ under specific Category
List of all courses with completion enabled and their Aggregation setting, Criteria types, and Criteria details.
+ show first Teacher in that course
 
+ link Course's fullname to actual course
<code sql>
<code sql>
 
SELECT
SELECT c.shortname AS Course,  
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
CASE
,c.shortname,r.name
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"
,(SELECT CONCAT(u.firstname,' ', u.lastname) as Teacher
ELSE "Any"
FROM prefix_role_assignments AS ra
END AS Course_Aggregation,
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
CASE
JOIN prefix_user as u ON u.id = ra.userid
WHEN t.criteriatype = 1 THEN "Self completion"
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) as Teacher
WHEN t.criteriatype = 2 THEN "Date done by"
FROM prefix_resource as r
WHEN t.criteriatype = 3 THEN "Unenrolement"
JOIN prefix_course as c ON r.course = c.id
WHEN t.criteriatype = 4 THEN "Activity completion" 
WHERE ( r.name LIKE '%סילבוס%' OR r.name LIKE '%סילאבוס%' OR r.name LIKE '%syllabus%' OR r.name LIKE '%תכנית הקורס%' )
WHEN t.criteriatype = 5 THEN "Duration in days"
AND c.category IN (10,18,26,13,28)
WHEN t.criteriatype = 6 THEN "Final grade"   
</code>
WHEN t.criteriatype = 7 THEN "Approve by role"
WHEN t.criteriatype = 8 THEN "Previous course"
===Site-wide completed SCORM activities by Course name===
END AS Criteria_type,
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.
CASE
<code sql>
WHEN t.criteriatype = 1 THEN "On"
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
WHEN t.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(t.timeend),'%Y-%m-%d')
FROM prefix_scorm_scoes_track AS st
WHEN t.criteriatype = 3 THEN "On"
JOIN prefix_user AS u ON st.userid=u.id
WHEN t.criteriatype = 4 THEN
JOIN prefix_scorm AS sc ON sc.id=st.scormid
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',t.module,'/view.php?id=',t.moduleinstance,'">',t.module,'</a>')
JOIN prefix_course AS c ON c.id=sc.course
WHEN t.criteriatype = 5 THEN ROUND(t.enrolperiod/86400)
WHERE st.value='completed'
WHEN t.criteriatype = 6 THEN ROUND(t.gradepass,2)
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt
WHEN t.criteriatype = 7 THEN (SELECT r.shortname FROM prefix_role AS r WHERE r.id = t.role)
WHEN t.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = t.courseinstance)
END AS Criteria_detail
FROM prefix_course_completion_criteria as t
JOIN prefix_course AS c ON t.course = c.id
WHERE c.enablecompletion = 1
ORDER BY course
</code>
</code>


===Scales used in activities===
===Courses without Groups using Forum in Group Mode===
Contributed by Eric Strom
 
This report identifies courses that have no groups created yet have forum activities (other than Announcements) set to use either 'Visible groups' or 'Separate groups'. Actions to take for these courses (choose one):
1) Forum activity should be set to 'No groups'
2) Groups need to be created in the course and populated with students to make use of the forums in group mode. Otherwise, students may not be able to see or reply to discussions in these forums.
Links go to edit course settings and forum module settings.
 
NOTES: This does not catch the scenario when courses have groups and some or all students are not assigned to a group. You may want to also run the report: "Courses with Empty Groups & Forum in Group Mode"
 
<code sql>
<code sql>
SELECT scale.name
SELECT
,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"
(SELECT cat.name FROM prefix_course_categories cat WHERE cat.id = c.category) AS Dept,
,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
concat('<a target="_new" href="%%WWWROOT%%/course/edit.php',CHAR(63),'id=',
JOIN prefix_course AS c ON c.id = gi.courseid
c.id,'">',c.idnumber,'</a>') AS CourseID_Number,
JOIN prefix_course_modules AS cm ON cm.course = gi.courseid AND cm.instance = gi.iteminstance
( CASE
JOIN prefix_scale AS scale ON scale.id = gi.scaleid
WHEN c.groupmode = 0 THEN "no groups"
WHERE gi.scaleid IS NOT NULL
WHEN c.groupmode = 1 THEN "separate groups"
WHEN c.groupmode = 2 THEN "visible groups"
END ) AS Course_Group_Mode
concat('<a target="_new" href="%%WWWROOT%%/course/modedit.php',CHAR(63),'upd','ate=',cm.id,'">',f.name,'</a>') AS Forum_Name,
 
( CASE
WHEN cm.groupmode = 0 THEN "no groups"
WHEN cm.groupmode = 1 THEN "separate groups"
WHEN cm.groupmode = 2 THEN "visible groups"
END ) AS Module_Group_Mode
 
, cm.visible AS Forum_Visible
, now() AS Report_Timestamp
 
FROM prefix_course AS c  
LEFT OUTER JOIN prefix_forum as f
ON c.id = f.course
JOIN prefix_course_modules AS cm
ON cm.instance = f.id
 
WHERE NOT(f.TYPE = 'news') AND cm.module = 9 and cm.course = c.id AND cm.groupmode > 0
AND (c.id NOT IN
(SELECT c.id
FROM prefix_course AS c
JOIN prefix_groups AS g ON c.id = g.courseid
WHERE c.id = g.courseid))
 
GROUP BY cm.id
ORDER BY c.idnumber
</code>
</code>


==Activity Module Reports==
===Courses with Empty Groups & Forum in Group Mode===
Contributed by Eric Strom
 
This report identifies courses that have groups with no students in them yet have forum activities (other than Announcements) set to use either 'Visible groups' or 'Separate groups'. Actions to take for these courses (choose one):
1) Forum activity should be set to 'No groups'
2) Groups need to be populated with students to make use of the forums in group mode. Otherwise, students may not be able to see or reply to discussions in these forums.
Links go to edit course settings and forum module settings.
 
NOTES: This does not catch the scenario when courses have groups and some but not all students are not assigned to a group. You may want to also run the report: "Courses without Groups using Forum in Group Mode"


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


===Detailed ACTIONs for each MODULE===
(SELECT cat.name FROM prefix_course_categories cat WHERE cat.id = c.category) AS Dept,
<code sql>
 
SELECT module,action,count(id) as counter
concat('<a target="_new" href="%%WWWROOT%%/course/edit.php',CHAR(63),'id=',c.id,'">',c.idnumber,'</a>') AS CourseID_Number,
FROM prefix_log
 
GROUP BY module,action
concat('<a target="_new" href="%%WWWROOT%%/course/modedit.php',CHAR(63),'upd','ate=',cm.id,'">',
ORDER BY module,counter desc
f.name,'</a>') AS Forum_Name,
 
( CASE
WHEN cm.groupmode = 0 THEN "no groups"
WHEN cm.groupmode = 1 THEN "separate groups"
WHEN cm.groupmode = 2 THEN "visible groups"
END ) AS Module_Group_Mode,
 
cm.visible AS Forum_Visible,  
COUNT(gm.id) AS Group_Members,
now() AS Report_Timestamp
 
FROM prefix_course AS c
LEFT OUTER JOIN prefix_forum as f
ON c.id = f.course
JOIN prefix_course_modules AS cm
ON cm.instance = f.id
JOIN prefix_groups AS g
ON c.id = g.courseid
LEFT OUTER JOIN prefix_groups_members AS gm
ON g.id = gm.groupid
 
WHERE NOT(f.TYPE = 'news') AND cm.module = 9 and cm.course = c.id AND cm.groupmode > 0
 
GROUP BY c.idnumber, cm.id
 
Having Group_Members = 0
 
ORDER BY c.idnumber
</code>
</code>


===Most popular ACTIVITY===
<code sql>
SELECT COUNT(l.id) hits, module
FROM prefix_log l
WHERE module != 'login' AND module != 'course' AND module != 'role'
GROUP BY module
ORDER BY hits DESC
</code>


===System wide use of ACTIVITIES and RESOURCES===
 
 
==Module instances + Module HITs by role teacher and student in course==
<code sql>
<code sql>
SELECT count( cm.id ) AS counter, m.name
SELECT  
FROM `prefix_course_modules` AS cm
m.name AS "Module name"
JOIN prefix_modules AS m ON cm.module = m.id
, COUNT(*) AS "Module count"
GROUP BY cm.module
ORDER BY counter DESC
</code>


===LOG file ACTIONS per MODULE per COURSE (IDs)===
,(SELECT COUNT(*)  
<code sql>
FROM prefix_log AS l
select course,module,action,count(action) as summa from prefix_log
WHERE l.course = cm.course AND l.module = m.name ) AS "Hits"
where action <> 'new'
group by course,action,module
order by course,module,action
</code>


===System Wide usage count of various course Activities===
,(SELECT COUNT(*)
(Tested and works fine in Moodle 2.x)
FROM prefix_log AS l
Like: Forum, Wiki, Blog, Assignment, Database,
JOIN prefix_context AS con ON con.instanceid= l.course AND con.contextlevel=50
#Within specific category
JOIN prefix_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 5
#Teacher name in course
WHERE l.course = cm.course AND l.module = m.name) AS "Students HITs"


<code sql>
,(SELECT COUNT(*)
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
FROM prefix_log AS l
JOIN prefix_context AS con ON con.instanceid= l.course AND con.contextlevel=50
JOIN prefix_role_assignments AS ra ON ra.contextid= con.id AND ra.userid= l.userid AND ra.roleid = 3
WHERE l.course = cm.course AND l.module = m.name) AS "Teachers HITs"


,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM mdl_course_modules AS cm
FROM prefix_role_assignments AS ra
JOIN mdl_modules AS m on m.id = cm.module
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE cm.course = '%%COURSEID%%'
JOIN prefix_user AS u ON u.id = ra.userid
GROUP BY cm.module
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
</code>


,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
==Grade and Course Completion Reports==
JOIN prefix_modules AS m ON cm.module = m.id
===Site-Wide Grade Report with All Items===
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
Shows grades for all course items along with course totals for each student. Works with ad-hoc reports or Configurable Reports
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
<code sql>
JOIN prefix_modules AS m ON cm.module = m.id
SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name',
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs
c.fullname AS 'Course',
cc.name AS 'Category',


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


,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
ROUND(gg.finalgrade,2) AS Grade,
JOIN prefix_modules AS m ON cm.module = m.id
DATEADD(ss,gi.timemodified,'1970-01-01') AS Time
WHERE cm.course = c.id AND m.name LIKE '%data%') AS Databses


,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
FROM prefix_course AS c
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
WHERE cm.course = c.id AND m.name LIKE '%assignment%') AS Assignments
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
</code>
 
For MySQL users, you'll need to use the MySQL DATE_ADD function instead of DATEADD. Replace the line
FROM prefix_course AS c
<code>
WHERE c.category IN ( 18)
DATEADD(ss,gi.timemodified,'1970-01-01') AS Time
ORDER BY Wikis DESC,Blogs DESC, Forums DESC
</code>
with
<code>
DATE_ADD('1970-01-01', INTERVAL gi.timemodified SECOND) AS Time
</code>
</code>


===Course wiki usage/activity over the last 6 semesters===
===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
<code sql>
<code sql>
SELECT "Courses with Wikis"
SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name',  
 
cc.name AS 'Category',
,(SELECT count( m.name ) AS count FROM
CASE
prefix_course_modules AS cm
  WHEN gi.itemtype = 'course'  
JOIN prefix_modules AS m ON cm.module = m.id
  THEN c.fullname + ' Course Total'
JOIN prefix_course AS c ON c.id = cm.course
  ELSE gi.itemname
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
END AS 'Item Name',
and c.fullname LIKE CONCAT('%','2010','%') and c.fullname LIKE '%Semester A%') AS '2010 <br/> Semester A'


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


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


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


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


,(SELECT count( m.name ) AS count FROM
For MySQL users:
prefix_course_modules AS cm
<code sql>
JOIN prefix_modules AS m ON cm.module = m.id
SELECT u.firstname AS 'First' , u.lastname AS 'Last', CONCAT(u.firstname , ' ' , u.lastname) AS 'Display Name',  
JOIN prefix_course AS c ON c.id = cm.course
c.fullname AS 'Course',
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
cc.name AS 'Category',
and c.fullname LIKE CONCAT('%','תשעב','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעב <br/> סמסטר ב'
CASE
 
  WHEN gi.itemtype = 'course'  
,(SELECT count( m.name ) AS count FROM
  THEN CONCAT(c.fullname, ' - Total')
prefix_course_modules AS cm
  ELSE gi.itemname
JOIN prefix_modules AS m ON cm.module = m.id
END AS 'Item Name',
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  
ROUND(gg.finalgrade,2) AS Grade,
prefix_course_modules AS cm
FROM_UNIXTIME(gg.timemodified) AS TIME
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_course AS c ON c.id = cm.course
FROM prefix_course AS c
WHERE cm.course = c.id AND m.name LIKE '%wiki%'
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
  and c.fullname LIKE CONCAT('%','תשעג','%') and c.fullname LIKE '%סמסטר ב%') AS 'תשעג <br/> סמסטר ב'
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE gi.courseid = c.id
ORDER BY lastname
</code>
</code>


===Detailed WIKI activity (per wiki per course)===
===Learner report by Learner with grades===
Including Number of Students in course (for reference)
Which Learners in which course and what are the grades
<code sql>
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID 
SELECT u.firstname AS 'Name' , u.lastname AS 'Surname', c.fullname AS 'Course', cc.name AS 'Category',
,(SELECT Count( ra.userid ) AS Users
CASE WHEN gi.itemtype = 'Course'   
FROM prefix_role_assignments AS ra
THEN c.fullname + ' Course Total' 
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
ELSE gi.itemname
WHERE ra.roleid = 5 AND ctx.instanceid = c.id ) AS Students
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,
,m.name
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%updat%' ) as 'UPDAT E'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%annotate%' ) as ANNOTATE
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%comment%' ) as COMMENT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%add%' ) as 'A DD'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%edit%' ) as EDIT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action NOT LIKE '%view%' ) as 'All (NO View)'
FROM `prefix_course_modules` as cm
JOIN prefix_modules as m ON cm.module=m.id
JOIN prefix_course as c ON cm.course = c.id
WHERE m.name LIKE '%wiki%'
GROUP BY cm.course,cm.module
ORDER BY 'All (NO View)' DESC
</code>


===Wiki usage, system wide===
if (ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) > 79,'Yes' , 'No') as Pass
(you can filter the output by selecting some specific course categories : "WHERE c.category IN ( 8,13,15)")


<code sql>
FROM prefix_course AS c
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
JOIN prefix_context AS ctx ON c.id = ctx.instanceid
JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
JOIN prefix_grade_grades AS gg ON gg.userid = u.id
JOIN prefix_grade_items AS gi ON gi.id = gg.itemid
JOIN prefix_course_categories AS cc ON cc.id = c.category
WHERE  gi.courseid = c.id and gi.itemname != 'Attendance'
ORDER BY `Name` ASC
</code>


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


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


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


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


,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%annotate%' ) AS 'WikiActivity<br/>ANNOTATE'
A report with course completions by username, with Aggregation method, Criteria types, and Criteria detail where available.
 
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%comments%' ) AS 'WikiActivity<br/>Comments'
 
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
 
,(SELECT count(*) FROM prefix_ouwiki_pages as ouwp
JOIN prefix_ouwiki as ouw ON ouw.id = ouwp.subwikiid
WHERE ouw.course = c.id GROUP BY ouw.course  ) as OUWikiPages
 
,(SELECT count( DISTINCT nwp.pagename ) FROM prefix_wiki_pages AS nwp
JOIN prefix_wiki AS nw ON nw.id = nwp.dfwiki WHERE nw.course = c.id ) As NWikiPages
 
FROM prefix_course AS c
WHERE c.category IN ( 8,13,15)
HAVING Wikis > 0
ORDER BY 'WikiActivity<br/>ALL' DESC
</code>


===Aggregated Teacher activity by "WEB2" Modules===
(Tested and works fine in Moodle 2.x)
The NV column shows activity without VIEW log activity
<code sql>
<code sql>
SELECT ra.userid, u.firstname,u.lastname
SELECT u.username AS user,  
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%') AS Wiki
c.shortname AS course,
,(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
DATE_FORMAT(FROM_UNIXTIME(t.timecompleted),'%Y-%m-%d') AS completed,
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%') AS Forum
CASE
,(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
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"
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%') AS Blog
ELSE "All"
,(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
END AS aggregation,
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%') AS Assignment
CASE
,(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
WHEN p.criteriatype = 1 THEN "Self"
FROM prefix_role_assignments AS ra
WHEN p.criteriatype = 2 THEN "By Date"
JOIN prefix_user AS u ON u.id = ra.userid
WHEN p.criteriatype = 3 THEN "Unenrol Status"
WHERE ra.roleid = 3
WHEN p.criteriatype = 4 THEN "Activity"
GROUP BY ra.userid
WHEN p.criteriatype = 5 THEN "Duration"
</code>
WHEN p.criteriatype = 6 THEN "Course Grade"
 
WHEN p.criteriatype = 7 THEN "Approve by Role"
===List all the certificates issued, sort by variables in the custom profile fields===
WHEN p.criteriatype = 8 THEN "Previous Course"
Note: The SQL queries look intimidating at first, but isn't really that difficult to learn. I've seen in the forums that users wanted to do 'site-wide' groups in 1.9x. This is sort of the idea. It pulls all the certificates issued to all users sorted by the custom profile fields, which in my case is the Units or Depts (i.e. my site wide groups). Why certificates? I've explored with both grades and quizzes, the course admins are not really interested in the actual grades but whether the learner received a certificate (i.e. passed the course with x, y, z activities). It also saves me from creating groups and assigning them into the right groups. Even assigning in bulk is not efficient, since I have upward of 25 groups per course and constantly new learners enrolling in courses. The limitation is something to do with the server? as it only pull 5000 rows of data. If anyone figured out how to change this, please let me know. In the meantime, the work around is to pull only a few units/depts at a time to limit the number of rows. This is fine at the moment, since each course admin are only responsible for certain units/depts.
END AS criteriatype,
CASE
WHEN p.criteriatype = 1 THEN "*"
WHEN p.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(p.timeend),'%Y-%m-%d')
WHEN p.criteriatype = 3 THEN t.unenroled
WHEN p.criteriatype = 4 THEN
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',p.module,'/view.php?id=',p.moduleinstance,'">',p.module,'</a>')
WHEN p.criteriatype = 5 THEN p.enrolperiod
WHEN p.criteriatype = 6 THEN CONCAT('Needed: ',ROUND(p.gradepass,2),' Achieved: ',ROUND(t.gradefinal,2))  
WHEN p.criteriatype = 7 THEN p.role
WHEN p.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = p.courseinstance)
END AS criteriadetail
FROM prefix_course_completion_crit_compl AS t
JOIN prefix_user AS u ON t.userid = u.id
JOIN prefix_course AS c ON t.course = c.id
JOIN prefix_course_completion_criteria AS p ON t.criteriaid = p.id


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


INNER JOIN prefix_user_info_data
List of all courses with completion enabled and their Aggregation setting, Criteria types, and Criteria details.
on prefix_certificate_issues.userid = prefix_user_info_data.userid


INNER JOIN prefix_certificate
<code sql>
on prefix_certificate_issues.certificateid = prefix_certificate.id


WHERE prefix_user_info_data.data='Unit 1'
SELECT c.shortname AS Course,
OR prefix_user_info_data.data='Unit 2'
CASE
OR prefix_user_info_data.data='Unit 3'
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"
ORDER BY Units, Name, Topic ASC
END AS Course_Aggregation,
</code>
CASE
 
WHEN t.criteriatype = 1 THEN "Self completion"
===Counter Blog usage in Courses,system wide===
WHEN t.criteriatype = 2 THEN "Date done by"
What teachers in what courses, uses blogs and how many + student count in that course.
WHEN t.criteriatype = 3 THEN "Unenrolement"
<code sql>
WHEN t.criteriatype = 4 THEN "Activity completion" 
 
WHEN t.criteriatype = 5 THEN "Duration in days"
SELECT ( @counter := @counter+1) as counter,  
WHEN t.criteriatype = 6 THEN "Final grade"   
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
WHEN t.criteriatype = 7 THEN "Approve by role"
 
WHEN t.criteriatype = 8 THEN "Previous course"
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
END AS Criteria_type,
  FROM prefix_role_assignments AS ra
CASE
  JOIN prefix_user AS u ON ra.userid = u.id
WHEN t.criteriatype = 1 THEN "On"
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
WHEN t.criteriatype = 2 THEN DATE_FORMAT(FROM_UNIXTIME(t.timeend),'%Y-%m-%d')
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
WHEN t.criteriatype = 3 THEN "On"
WHEN t.criteriatype = 4 THEN
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',t.module,'/view.php?id=',t.moduleinstance,'">',t.module,'</a>')
WHEN t.criteriatype = 5 THEN ROUND(t.enrolperiod/86400)
WHEN t.criteriatype = 6 THEN ROUND(t.gradepass,2)
WHEN t.criteriatype = 7 THEN (SELECT r.shortname FROM prefix_role AS r WHERE r.id = t.role)
WHEN t.criteriatype = 8 THEN (SELECT pc.shortname FROM prefix_course AS pc WHERE pc.id = t.courseinstance)
END AS Criteria_detail
FROM prefix_course_completion_criteria as t
JOIN prefix_course AS c ON t.course = c.id
WHERE c.enablecompletion = 1
ORDER BY course
</code>
 
===Course Completion Report with custom dates===


,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
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
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
<code sql>
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
 
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
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


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


=== Elluminate (Blackboard Collaborate) - system wide usage===
===Scales used in activities===
<code sql>
<code sql>
SELECT e.name As Session ,er.recordingsize
SELECT scale.name
,c.fullname As Course
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,u.firstname,u.lastname
,CONCAT('<a target="_new" href="%%WWWROOT%%/mod/',gi.itemmodule,'/view.php?id=',cm.id,'">',gi.itemname,'</a>') AS "Module View"
,DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%d-%m-%Y') AS dTimeStart
,CONCAT('<a target="_new" href="%%WWWROOT%%/course/modedit.php?up','date=',cm.id,'">',gi.itemname,'</a>') AS "Module Settings"
,concat('<a target="_new" href="%%WWWROOT%%/moodle/mod/elluminate/loadrecording.php?id=',er.id,'">Show</a>') AS RecordedSession


FROM prefix_elluminate_recordings AS er
FROM prefix_grade_items AS gi
JOIN prefix_elluminate AS e ON e.meetingid = er.meetingid
JOIN prefix_course AS c ON c.id = gi.courseid
JOIN prefix_course as c ON c.id = e.course
JOIN prefix_course_modules AS cm ON cm.course = gi.courseid AND cm.instance = gi.iteminstance
JOIN prefix_user AS u ON u.id = e.creator
JOIN prefix_scale AS scale ON scale.id = gi.scaleid
ORDER BY er.recordingsize DESC
WHERE gi.scaleid IS NOT NULL
</code>
</code>


==Activity Module Reports==


=== Choice ===
===How many SCORM activities are used in each Course===
 
<code sql>
Results of the Choice activity. For all courses, shows course shortname, username, the Choice text, and the answer chosen by the user.
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
</code>


===Detailed ACTIONs for each MODULE===
<code sql>
<code sql>
SELECT c.shortname AS course, u.username, h.name as question, o.text AS answer
SELECT module,action,count(id) as counter
FROM prefix_choice AS h
FROM prefix_log
JOIN prefix_course AS c ON h.course = c.id
GROUP BY module,action
JOIN prefix_choice_answers AS a ON h.id = a.choiceid
ORDER BY module,counter desc
JOIN prefix_user AS u ON a.userid = u.id
JOIN prefix_choice_options AS o ON a.optionid = o.id
</code>
</code>


=== Assignment type usage in courses ===
===Most popular ACTIVITY===
<code sql>
<code sql>
SELECT  
SELECT COUNT(l.id) hits, module
 
FROM prefix_log l
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/assign/index.php?id=',c.id,'">',c.fullname,'</a>') AS "List assignments"
WHERE module != 'login' AND module != 'course' AND module != 'role'
GROUP BY module
ORDER BY hits DESC
</code>


,(SELECT COUNT(*) FROM prefix_assign WHERE c.id = course) AS Assignments
===System wide use of ACTIVITIES and RESOURCES===
<code sql>
SELECT count( cm.id ) AS counter, m.name
FROM `prefix_course_modules` AS cm
JOIN prefix_modules AS m ON cm.module = m.id
GROUP BY cm.module
ORDER BY counter DESC
</code>


,(SELECT COUNT(*)
===LOG file ACTIONS per MODULE per COURSE (IDs)===
FROM prefix_assign_plugin_config AS apc
<code sql>
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
select course,module,action,count(action) as summa from prefix_log
WHERE iassign.course = c.id AND apc.plugin = 'file' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
where action <> 'new'
#GROUP BY apc.plugin
group by course,action,module
) AS "File Assignments"
order by course,module,action
</code>


,(SELECT COUNT(*)
===System Wide usage count of various course Activities===
FROM prefix_assign_plugin_config AS apc
(Tested and works fine in Moodle 2.x)
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
Like: Forum, Wiki, Blog, Assignment, Database,
WHERE iassign.course = c.id AND apc.plugin = 'onlinetext' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
#Within specific category
) AS "Online Assignments"
#Teacher name in course


,(SELECT COUNT(*)
<code sql>
FROM prefix_assign_plugin_config AS apc
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
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(*)  
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_assign_plugin_config AS apc
FROM prefix_role_assignments AS ra
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE iassign.course = c.id AND apc.plugin = 'offline' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
JOIN prefix_user AS u ON u.id = ra.userid
) AS "Offline Assignments"
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher


,(SELECT COUNT(*)  
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
FROM prefix_assign_plugin_config AS apc
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE cm.course = c.id AND m.name LIKE '%wiki%') AS Wikis
WHERE iassign.course = c.id AND apc.plugin = 'comments' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
) AS "Assignments Comments"
JOIN prefix_modules AS m ON cm.module = m.id
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs


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


==Assignment Module Reports==
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
===All Ungraded Assignments===
JOIN prefix_modules AS m ON cm.module = m.id
Returns all the submitted assignments that still need grading
WHERE cm.course = c.id AND m.name LIKE '%data%') AS Databses
<code sql>
select
u.firstname AS "First",
u.lastname AS "Last",
c.fullname AS "Course",
a.name AS "Assignment"


from prefix_assignment_submissions as asb
,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm
join prefix_assignment as a ON a.id = asb.assignment
JOIN prefix_modules AS m ON cm.module = m.id
join prefix_user as u ON u.id = asb.userid
WHERE cm.course = c.id AND m.name LIKE '%assignment%') AS Assignments
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
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
and cm.module = 1
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students


order by c.fullname, a.name, u.lastname
FROM prefix_course AS c
WHERE c.category IN ( 18)
ORDER BY Wikis DESC,Blogs DESC, Forums DESC
</code>
</code>


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


'<a href="http://education.varonis.com/mod/assignment/submissions.php' + char(63) +
,(SELECT count( m.name ) AS count FROM
+ 'id=' + cast(cm.id as varchar) + '&userid=' + cast(u.id as varchar)
prefix_course_modules AS cm
+ '&mode=single&filter=0&offset=2">' + a.name + '</a>'
JOIN prefix_modules AS m ON cm.module = m.id
AS "Assignmentlink"
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'


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


where asb.grade < 0 and cm.instance = a.id and cm.module = 1
,(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/> סמסטר ב'


order by c.fullname, a.name, u.lastname
,(SELECT count( m.name ) AS count FROM
</code>
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/> סמסטר א'


===Assignments (and Quizzes) waiting to be graded===
,(SELECT count( m.name ) AS count FROM
This report requires a YEAR filter to be added (Available when using the latest block/configurable_reports)
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/> סמסטר ב'


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
</code>
*number of unchecked assignments (waiting for the Teacher) in a Course.


===Detailed WIKI activity (per wiki per course)===
Including Number of Students in course (for reference)
<code sql>
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',cm.course,'">',c.fullname,'</a>') as CourseID 
 
,(SELECT Count( ra.userid ) AS Users
,(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
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 5 AND ctx.instanceid = c.id ) AS Students
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
,m.name
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%updat%' ) as 'UPDAT E'
,concat('<a target="_new" href="%%WWWROOT%%/mod/assignment/index.php?id=',c.id,'">מטלות</a>') AS Assignments
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%annotate%' ) as ANNOTATE
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%comment%' ) as COMMENT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%add%' ) as 'A DD'
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action LIKE '%edit%' ) as EDIT
, ( SELECT count(id) FROM prefix_log WHERE cmid = cm.id AND action NOT LIKE '%view%' ) as 'All (NO View)'
FROM `prefix_course_modules` as cm
JOIN prefix_modules as m ON cm.module=m.id
JOIN prefix_course as c ON cm.course = c.id  
WHERE m.name LIKE '%wiki%'
GROUP BY cm.course,cm.module
ORDER BY 'All (NO View)' DESC
</code>


,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">בחנים</a>') AS 'Quizzes'
===Wiki usage, system wide===
(you can filter the output by selecting some specific course categories : "WHERE c.category IN ( 8,13,15)")
 
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course


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


,(SELECT COUNT(*)
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%') AS 'WikiActivity<br/>ALL'
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(*)
,(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'
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
,(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_role_assignments AS ra
 
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%annotate%' ) AS 'WikiActivity<br/>ANNOTATE'
 
,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%comments%' ) AS 'WikiActivity<br/>Comments'
 
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid = 5
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
AND ctx.instanceid = c.id
) AS nStudents


,(
,(SELECT count(*) FROM prefix_ouwiki_pages as ouwp
SELECT count(a.id)
JOIN prefix_ouwiki as ouw ON ouw.id = ouwp.subwikiid
FROM prefix_assignment AS a
WHERE ouw.course = c.id GROUP BY ouw.course ) as OUWikiPages
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( DISTINCT nwp.pagename ) FROM prefix_wiki_pages AS nwp
SELECT count(*)
JOIN prefix_wiki AS nw ON nw.id = nwp.dfwiki WHERE nw.course = c.id ) As NWikiPages
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
FROM prefix_course AS c
LEFT JOIN (
WHERE c.category IN ( 8,13,15)
SELECT course, count(*) AS iAssignments
HAVING Wikis > 0
FROM prefix_assignment AS a
ORDER BY 'WikiActivity<br/>ALL' DESC
GROUP BY a.course
</code>
) AS tblAssignmentsCount ON tblAssignmentsCount.course = c.id


LEFT JOIN (
===Aggregated Teacher activity by "WEB2" Modules===
SELECT course, count(*) AS iOpenAssignments
(Tested and works fine in Moodle 2.x)
FROM prefix_assignment AS a
The NV column shows activity without VIEW log activity
WHERE FROM_UNIXTIME(a.timedue) > NOW()
<code sql>
GROUP BY a.course
SELECT ra.userid, u.firstname,u.lastname
) AS tblOpenAssignmentsCount ON tblOpenAssignmentsCount.course = c.id
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%') AS Wiki
 
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%wiki%' AND l.action NOT LIKE '%view%') AS Wiki_NV
WHERE 1=
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%forum%') AS Forum
#AND c.fullname LIKE '%תשעג%'
,(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
%%FILTER_YEARS:c.fullname%%
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%blog%') AS Blog
## You can enable the SEMESTER filter as well,
,(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
## by uncommenting the following line:
,(SELECT count(*) FROM prefix_log as l WHERE l.userid = u.id AND l.module LIKE '%assignment%') AS Assignment
## %%FILTER_SEMESTERS:c.fullname%%
,(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
ORDER BY 'Open <br/>Assignments' DESC
FROM prefix_role_assignments AS ra
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3
GROUP BY ra.userid
</code>
</code>


===Who is using "Single File Upload" assignment===
===List all the certificates issued, sort by variables in the custom profile fields===
Note: The SQL queries look intimidating at first, but isn't really that difficult to learn. I've seen in the forums that users wanted to do 'site-wide' groups in 1.9x. This is sort of the idea. It pulls all the certificates issued to all users sorted by the custom profile fields, which in my case is the Units or Depts (i.e. my site wide groups). Why certificates? I've explored with both grades and quizzes, the course admins are not really interested in the actual grades but whether the learner received a certificate (i.e. passed the course with x, y, z activities). It also saves me from creating groups and assigning them into the right groups. Even assigning in bulk is not efficient, since I have upward of 25 groups per course and constantly new learners enrolling in courses. The limitation is something to do with the server? as it only pull 5000 rows of data. If anyone figured out how to change this, please let me know. In the meantime, the work around is to pull only a few units/depts at a time to limit the number of rows. This is fine at the moment, since each course admin are only responsible for certain units/depts.
 
<code sql>
<code sql>
SELECT  
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
DATE_FORMAT( FROM_UNIXTIME(prefix_certificate_issues.timecreated), '%Y-%m-%d' ) AS Date,
prefix_certificate_issues.classname AS Topic,
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
prefix_certificate.name AS Certificate,
FROM prefix_role_assignments AS ra
prefix_certificate_issues.studentname as Name,
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
prefix_user_info_data.data AS Units
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_certificate_issues


FROM
INNER JOIN prefix_user_info_data
prefix_assignment as ass
on prefix_certificate_issues.userid = prefix_user_info_data.userid


JOIN  
INNER JOIN prefix_certificate
prefix_course as c ON c.id = ass.course
on prefix_certificate_issues.certificateid = prefix_certificate.id


WHERE `assignmenttype` LIKE 'uploadsingle'
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
</code>
</code>


==Resource Module Reports==
===Counter Blog usage in Courses,system wide===
===List "Recently uploaded files"===
What teachers in what courses, uses blogs and how many + student count in that course.
see what users are uploading
<code sql>
<code sql>
SELECT FROM_UNIXTIME(time,'%Y %M %D %h:%i:%s') as time ,ip,userid,url,info 
FROM `prefix_log`
WHERE `action` LIKE 'upload'
ORDER BY `prefix_log`.`time`  DESC
</code>


===List Courses that loaded a specific file: "X"===
SELECT ( @counter := @counter+1) as counter,
Did the Teacher (probably) uploaded course's Syllabus ?
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course
<code sql>
SELECT c.id, c.fullname  FROM `prefix_log` as l
JOIN prefix_course as c ON c.id = l.course
WHERE `action` LIKE '%upload%' AND ( info LIKE '%Syllabus%' OR info LIKE '%Sylabus%' ) GROUP BY c.id
</code>


===All resources that link to some specific external website===
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
+ link to course
  FROM prefix_role_assignments AS ra
+ who's the teacher
  JOIN prefix_user AS u ON ra.userid = u.id
+ link to external resource
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
<code sql>
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
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
,c.shortname,r.name
JOIN prefix_modules AS m ON cm.module = m.id
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs
FROM prefix_role_assignments AS ra
 
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students
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_course AS c, (SELECT @counter := 0) as s_init
FROM prefix_resource AS r
WHERE c.category IN ( 8,13,15)
JOIN prefix_course AS c ON r.course = c.id
HAVING Blogs > 0
WHERE r.reference LIKE 'http://info.oranim.ac.il/home%'
ORDER BY Blogs DESC
</code>
</code>


==="Compose Web Page" RESOURCE count===
=== Elluminate (Blackboard Collaborate) - system wide usage===
<code sql>
<code sql>
SELECT course,prefix_course.fullname, COUNT(*) AS Total
SELECT e.name As Session ,er.recordingsize
FROM `prefix_resource`
,c.fullname As Course
JOIN `prefix_course` ON prefix_course.id = prefix_resource.course
,u.firstname,u.lastname
WHERE type='html'
,DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%d-%m-%Y') AS dTimeStart
GROUP BY course
,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
</code>
</code>


===Resource count in courses===
 
+ (First)Teacher name
=== Choice ===
+ Where course is inside some specific Categories
 
Results of the Choice activity. For all courses, shows course shortname, username, the Choice text, and the answer chosen by the user.
 
<code sql>
<code sql>
SELECT  
SELECT c.shortname AS course, u.username, h.name as question, o.text AS answer
COUNT(*) AS count
FROM prefix_choice AS h
,r.course
JOIN prefix_course AS c ON h.course = c.id
,c.shortname shortname
JOIN prefix_choice_answers AS a ON h.id = a.choiceid
,c.fullname coursename
JOIN prefix_user AS u ON a.userid = u.id
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
JOIN prefix_choice_options AS o ON a.optionid = o.id
  FROM prefix_role_assignments AS ra
  JOIN prefix_user as u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = r.course AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
FROM prefix_resource r
JOIN prefix_course c ON r.course = c.id
WHERE c.category IN (10,13,28,18,26)
GROUP BY r.course
ORDER BY COUNT(*) DESC
</code>
</code>


==Forum Module Reports==
=== Assignment type usage in courses ===
===print all User's post in course Forums===
@@COURSEID@@ is a variable the is replace by the current CourseID you are running the sql report from. if you are using the latest block/configurable_reports ! (You can always change it to a fixed course or remove it to display all courses.)
<code sql>
<code 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
,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
CONCAT('<a target="_new" href="%%WWWROOT%%/mod/assign/index.php?id=',c.id,'">',c.fullname,'</a>') AS "List assignments"
JOIN prefix_user as u ON u.id = fp.userid
 
JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id
,(SELECT COUNT(*) FROM prefix_assign WHERE c.id = course) AS Assignments
JOIN prefix_forum AS f ON f.id = fd.forum
 
JOIN prefix_course as c ON c.id = fd.course
,(SELECT COUNT(*)
WHERE fd.course = '@@COURSEID@@'  
FROM prefix_assign_plugin_config AS apc
GROUP BY f.id,u.id
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
ORDER BY u.id
WHERE iassign.course = c.id AND apc.plugin = 'file' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
</code>
#GROUP BY apc.plugin
===FORUM use Count per COURSE -- not including NEWS Forum!===
) AS "File Assignments"
<code sql>
 
SELECT prefix_course.fullname, prefix_forum.course, count(*) as total FROM prefix_forum
,(SELECT COUNT(*)  
INNER JOIN prefix_course
FROM prefix_assign_plugin_config AS apc
ON prefix_course.id = prefix_forum.course
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
WHERE NOT(prefix_forum.type = 'news')
WHERE iassign.course = c.id AND apc.plugin = 'onlinetext' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
GROUP BY prefix_forum.course
) AS "Online Assignments"
ORDER BY total desc
</code>


===FORUM use Count per COURSE by type -- not including NEWS Forum!===
,(SELECT COUNT(*)
<code sql>
FROM prefix_assign_plugin_config AS apc
SELECT prefix_course.fullname, prefix_forum.course, prefix_forum.type, count(*) as total FROM prefix_forum
JOIN prefix_assign AS iassign ON iassign.id = apc.assignment
INNER JOIN prefix_course
WHERE iassign.course = c.id AND apc.plugin = 'pdf' AND apc.subtype = 'assignsubmission' AND apc.name = 'enabled' AND apc.value = '1'
ON prefix_course.id = prefix_forum.course
) AS "PDF Assignments"
WHERE NOT(prefix_forum.type = 'news')
 
GROUP BY prefix_forum.course,prefix_forum.type
,(SELECT COUNT(*)
ORDER BY total desc
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
</code>
</code>


===Forum activity - system wide===
==Assignment Module Reports==
===All Ungraded Assignments===
Returns all the submitted assignments that still need grading
<code sql>
<code 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)
u.firstname AS "First",
  FROM prefix_role_assignments AS ra
u.lastname AS "Last",
  JOIN prefix_user AS u ON ra.userid = u.id
c.fullname AS "Course",
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
a.name AS "Assignment"
  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
from prefix_assignment_submissions as asb
ORDER BY count( * ) DESC
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
</code>
</code>


===Activity In Forums===
===All Ungraded Assignments w/ Link===
Trying to figure out how much real activity we have in Forums by aggregating:
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.
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...
<code sql>
<code sql>
SELECT c.fullname,f.name,f.type
select
,(SELECT count(id) FROM prefix_forum_discussions as fd WHERE f.id = fd.forum) as Discussions
u.firstname AS "First",
,(SELECT count(distinct fd.userid) FROM prefix_forum_discussions as fd WHERE fd.forum = f.id) as UniqueUsersDiscussions
u.lastname AS "Last",
,(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
c.fullname AS "Course",
,(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
a.name AS "Assignment",
,(SELECT Count( ra.userid ) AS Students
 
FROM prefix_role_assignments AS ra
'<a href="http://education.varonis.com/mod/assignment/submissions.php' + char(63) +
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
+ 'id=' + cast(cm.id as varchar) + '&userid=' + cast(u.id as varchar)  
WHERE ra.roleid =5
+ '&mode=single&filter=0&offset=2">' + a.name + '</a>'
AND ctx.instanceid = c.id
AS "Assignmentlink"
) 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
</code>


===All Forum type:NEWS===
from prefix_assignment_submissions as asb
<code sql>
join prefix_assignment as a ON a.id = asb.assignment
SELECT f.id, f.name
join prefix_user as u ON u.id = asb.userid
FROM prefix_course_modules AS cm
join prefix_course as c ON c.id = a.course
JOIN prefix_modules AS m ON cm.module = m.id
join prefix_course_modules as cm ON c.id = cm.course
JOIN prefix_forum AS f ON cm.instance = f.id
 
WHERE m.name = 'forum'
where asb.grade < 0 and cm.instance = a.id and cm.module = 1
AND f.type = 'news'
 
order by c.fullname, a.name, u.lastname
</code>
</code>


===All new forum NEWS items (discussions) from all my Courses===
===Assignments (and Quizzes) waiting to be graded===
change "userid = 26" and "id = 26" to a new user id
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.
 
<code sql>
<code sql>
SELECT c.shortname,f.name,fd.name,FROM_UNIXTIME(fd.timemodified ,"%d %M %Y ") as Date
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
FROM prefix_forum_discussions as fd
 
JOIN prefix_forum as f ON f.id = fd.forum
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
JOIN prefix_course as c ON c.id = f.course
FROM prefix_role_assignments AS ra
JOIN prefix_user_lastaccess as ul ON (c.id = ul.courseid AND ul.userid = 26)
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE fd.timemodified > ul.timeaccess 
JOIN prefix_user AS u ON u.id = ra.userid
AND fd.forum IN (SELECT f.id
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
,concat('<a target="_new" href="%%WWWROOT%%/mod/assignment/index.php?id=',c.id,'">מטלות</a>') AS Assignments
JOIN prefix_forum AS f ON cm.instance = f.id
WHERE m.name = 'forum'
AND f.type = 'news')
  AND c.id IN (SELECT c.id
  FROM prefix_course AS c
  JOIN prefix_context AS ctx ON c.id = ctx.instanceid
  JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
  JOIN prefix_user AS u ON u.id = ra.userid
  WHERE u.id = 26) ORDER BY `fd`.`timemodified` DESC
</code>


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


===News Forum - Discussions COUNT===
,(SELECT COUNT(*)  
Which is actually... How much instructions students get from their teachers
FROM prefix_course_modules cm
<code sql>
JOIN prefix_modules as m ON m.id = cm.module
SELECT c.shortname ,
WHERE m.name LIKE 'quiz' AND cm.course = c.id  
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
GROUP BY cm.course
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
) AS 'nQuizzes'
  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
</code>


==Quiz Module Reports==
,(SELECT COUNT(*)
===Generate a list of instructors and their email addresses for those courses that has "essay questions" in their quizzes===
FROM prefix_quiz_attempts AS qa
<code sql>
JOIN prefix_quiz AS q ON q.id = qa.quiz
SELECT qu.id AS quiz_id, qu.course AS course_id, qu.questions,
WHERE q.course = c.id
                co.fullname AS course_fullname, co.shortname AS course_shortname,
AND qa.timefinish = 0
                qu.name AS quiz_name, FROM_UNIXTIME(qu.timeopen) AS quiz_timeopen, FROM_UNIXTIME(qu.timeclose) AS quiz_timeclose,
GROUP BY q.course) AS 'unFinished Quiz attempts'
                u.firstname, u.lastname, u.email,
FROM prefix_quiz qu, prefix_course co, prefix_role re, prefix_context ct, prefix_role_assignments ra, prefix_user u
WHERE FROM_UNIXTIME(timeopen) > '2008-05-14' AND
                qu.course = co.id AND
                co.id = ct.instanceid AND
                ra.roleid = re.id AND
                re.name = 'Teacher' AND
                ra.contextid = ct.id AND
                ra.userid = u.id
SELECT Count('x') As NumOfStudents
                                FROM prefix_role_assignments a
                                JOIN prefix_user u ON userid = u.id
                                WHERE roleid = 5 AND contextid = (SELECT id FROM prefix_context WHERE instanceid = 668 AND contextlevel = 50)
</code>


===Number of Quizes per Course===
,(SELECT COUNT(*)
<code sql>
FROM prefix_quiz_attempts AS qa
SELECT count(*)
JOIN prefix_quiz AS q ON q.id = qa.quiz
,concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
WHERE q.course = c.id
,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">Link</a>') AS Quizes
AND qa.timefinish > 0
GROUP BY q.course) AS 'finished quiz attempts'


FROM prefix_course_modules cm
,(SELECT Count( ra.userid ) AS Users
JOIN prefix_course c ON c.id = cm.course
FROM prefix_role_assignments AS ra
JOIN prefix_modules as m ON m.id = cm.module
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE m.name LIKE 'quiz'
WHERE ra.roleid = 5
GROUP BY c.id
AND ctx.instanceid = c.id
</code>
) AS nStudents


===List all MultiAnswer (Cloze) Questions===
,(
<code sql>
SELECT count(a.id)
SELECT concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/attempt.php?q=', quiz.id, '">', quiz.name, '</a>') AS Quiz
FROM prefix_assignment AS a
,question.id question_id, question.questiontext
JOIN prefix_course_modules AS cm ON a.course = cm.course
FROM prefix_question question
WHERE cm.instance = a.id AND cm.module = 1 AND a.course = c.id
JOIN prefix_quiz_question_instances qqi ON question.id = qqi.question
) nAssignments
JOIN prefix_quiz quiz ON qqi.quiz = quiz.id
WHERE  `qtype` LIKE  'multianswer'
</code>


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


==SCORM Activity Reports==
===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/28/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.


===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.
<code sql>
<code sql>
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
SELECT cat.name AS Department, concat('<a target="_new" href="%%WWWROOT%%/course/view.php',CHAR(63),'id=',
FROM prefix_scorm_scoes_track AS st
c.id,'">',c.idnumber,'</a>') AS Course_ID,  
JOIN prefix_user AS u ON st.userid=u.id
c.fullname AS Course_Name,  
JOIN prefix_scorm AS sc ON sc.id=st.scormid
concat('<a target="_new" href="%%WWWROOT%%/grade/grading/form/rubric/edit.php',CHAR(63),'areaid=',gd.areaid,'">',gd.areaid,'</a>') AS Rubric
JOIN prefix_course AS c ON c.id=sc.course
FROM prefix_course AS c
WHERE st.value='completed'  
JOIN prefix_course_categories AS cat
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt
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:~%%
</code>
</code>


== Badges==
===Who is using "Single File Upload" assignment===
<code sql>
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


=== All badges issued, by User ===
JOIN
prefix_course as c ON c.id = ass.course


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.
WHERE `assignmenttype` LIKE 'uploadsingle'
</code>


==Resource Module Reports==
===List "Recently uploaded files"===
see what users are uploading
<code sql>
<code sql>
SELECT u.username, b.name AS badgename,
SELECT FROM_UNIXTIME(time,'%Y %M %D %h:%i:%s') as time ,ip,userid,url,info 
CASE
FROM `prefix_log`
WHEN b.courseid IS NOT NULL THEN
WHERE `action` LIKE 'upload'
(SELECT c.shortname
ORDER BY `prefix_log`.`time`  DESC
    FROM prefix_course AS c
    WHERE c.id = b.courseid)
WHEN b.courseid IS NULL THEN "*"
END AS Context,
CASE
  WHEN t.criteriatype = 1 AND t.method = 1 THEN "Activity Completion (All)"
  WHEN t.criteriatype = 1 AND t.method = 2 THEN "Activity Completion (Any)"
  WHEN t.criteriatype = 2 AND t.method = 2 THEN "Manual Award"
  WHEN t.criteriatype = 4 AND t.method = 1 THEN "Course Completion (All)"
  WHEN t.criteriatype = 4 AND t.method = 2 THEN "Course Completion (Any)"
  ELSE CONCAT ('Other: ', t.criteriatype)
END AS Criteriatype,
DATE_FORMAT( FROM_UNIXTIME( d.dateissued ) , '%Y-%m-%d' ) AS dateissued,
DATE_FORMAT( FROM_UNIXTIME( d.dateexpire ), '%Y-%m-%d' ) AS dateexpires,
CONCAT ('<a target="_new" href="%%WWWROOT%%/badges/badge.php?hash=',d.uniquehash,'">link</a>') AS Details
FROM prefix_badge_issued AS d
JOIN prefix_badge AS b ON d.badgeid = b.id
JOIN prefix_user AS u ON d.userid = u.id
JOIN prefix_badge_criteria AS t on b.id = t.badgeid
WHERE t.criteriatype <> 0
ORDER BY u.username
</code>
</code>


Please note: the FROM_UNIXTIME command is for MySQL.
===List Courses that loaded a specific file: "X"===
Did the Teacher (probably) uploaded course's Syllabus ?
<code sql>
SELECT c.id, c.fullname  FROM `prefix_log` as l
JOIN prefix_course as c ON c.id = l.course
WHERE `action` LIKE '%upload%' AND ( info LIKE '%Syllabus%' OR info LIKE '%Sylabus%' ) GROUP BY c.id
</code>


=== All badges available in the system, with Earned count ===
===All resources that link to some specific external website===
 
+ link to course
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.
+ who's the teacher
+ link to external resource
<code sql>
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,c.shortname,r.name
,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
JOIN prefix_user AS u ON u.id = ra.userid
WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher
,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%'
</code>


==="Compose Web Page" RESOURCE count===
<code sql>
<code sql>
SELECT b.id, b.name, b.description,
SELECT course,prefix_course.fullname, COUNT(*) AS Total
CASE
FROM `prefix_resource`
WHEN b.type = 1 THEN "System"
JOIN `prefix_course` ON prefix_course.id = prefix_resource.course
WHEN b.type = 2 THEN "Course"
WHERE type='html'
END AS Context,
GROUP BY course
CASE
</code>
WHEN b.courseid IS NOT NULL THEN
 
(SELECT c.shortname  
===Resource count in courses===
    FROM prefix_course AS c  
+ (First)Teacher name
    WHERE c.id = b.courseid)
+ Where course is inside some specific Categories
WHEN b.courseid IS NULL THEN "*"
<code sql>
END AS Course,
SELECT  
CASE
COUNT(*) AS count
WHEN b.status = 0 OR b.status = 2 THEN "No"
,r.course
WHEN b.status = 1 OR b.status = 3 THEN "Yes"
,c.shortname shortname
WHEN b.status = 4 THEN "x"
,c.fullname coursename
END AS Available,
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
CASE
  FROM prefix_role_assignments AS ra
WHEN b.status = 0 OR b.status = 1 THEN "0"
  JOIN prefix_user as u ON ra.userid = u.id
WHEN b.status = 2 OR b.status = 3 OR b.status = 4 THEN
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
(SELECT COUNT(*)  
  WHERE ra.roleid = 3 AND ctx.instanceid = r.course AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
  FROM prefix_badge_issued AS d
FROM prefix_resource r
  WHERE d.badgeid = b.id
JOIN prefix_course c ON r.course = c.id
)
WHERE c.category IN (10,13,28,18,26)
END AS Earned
GROUP BY r.course
FROM prefix_badge AS b
ORDER BY COUNT(*) DESC
</code>


===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)
<code sql>
SELECT CONCAT( 'rm -f /var/moodledatanew/filedir/', SUBSTRING( contenthash, 1, 2 ) , '/', SUBSTRING( contenthash, 3, 2 ) , '/', contenthash )
FROM `mdl_files`
WHERE `filename` LIKE '%mbz%'
AND filearea = 'automated'
</code>
</code>


=== Badges Leaderboard ===
Find out how much disk space is used by all automated backup files:
 
A simple list of usernames and how many badges they have earned overall.
 
<code sql>
<code sql>
SELECT u.username, (SELECT COUNT(*) FROM prefix_badge_issued AS d WHERE d.userid = u.id) AS earned
SELECT SUM(filesize)/(1024*1024*1024) FROM `mdl_files` WHERE `filename` LIKE '%mbz%' AND filearea = 'automated'
FROM prefix_user AS u
ORDER BY earned DESC, u.username ASC
</code>
</code>


==Administrator Reports==
==Forum Module Reports==
 
===print all User's post in course Forums===
===Config changes in Export friendly form===
@@COURSEID@@ is a variable the is replace by the current CourseID you are running the sql report from. if you are using the latest block/configurable_reports ! (You can always change it to a fixed course or remove it to display all courses.)
 
<code sql>
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
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
</code>
===FORUM use Count per COURSE -- not including NEWS Forum!===
<code sql>
<code sql>
SELECT  
SELECT prefix_course.fullname, prefix_forum.course, count(*) as total FROM prefix_forum
DATE_FORMAT( FROM_UNIXTIME( g.timemodified ) , '%Y-%m-%d' ) AS date,  
INNER JOIN prefix_course
u.username AS user,  
ON prefix_course.id = prefix_forum.course
g.name AS setting,  
WHERE NOT(prefix_forum.type = 'news')
CASE  
GROUP BY prefix_forum.course
  WHEN g.plugin IS NULL THEN "core"
ORDER BY total desc
  ELSE g.plugin
</code>
END AS plugin,  
 
g.value AS new_value,  
===FORUM use Count per COURSE by type -- not including NEWS Forum!===
g.oldvalue AS original_value
<code sql>
FROM prefix_config_log  AS g
SELECT prefix_course.fullname, prefix_forum.course, prefix_forum.type, count(*) as total FROM prefix_forum
INNER JOIN prefix_course
ON prefix_course.id = prefix_forum.course
WHERE NOT(prefix_forum.type = 'news')
GROUP BY prefix_forum.course,prefix_forum.type
ORDER BY total desc
</code>
 
===Forum activity - system wide===
<code sql>
SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS CourseID
,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)
  FROM prefix_role_assignments AS ra
  JOIN prefix_user AS u ON ra.userid = u.id
  JOIN prefix_context AS ctx ON ctx.id = ra.contextid
  WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher
,c.fullname as Course
,f.type
,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra
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
</code>
 
===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...
<code sql>
SELECT c.fullname,f.name,f.type
,(SELECT count(id) FROM prefix_forum_discussions as fd WHERE f.id = fd.forum) as Discussions
,(SELECT count(distinct fd.userid) FROM prefix_forum_discussions as fd WHERE fd.forum = f.id) as UniqueUsersDiscussions
,(SELECT count(fp.id) FROM prefix_forum_discussions fd JOIN prefix_forum_posts as fp ON fd.id = fp.discussion WHERE f.id = fd.forum) as Posts
,(SELECT count(distinct fp.userid) FROM prefix_forum_discussions fd JOIN prefix_forum_posts as fp ON fd.id = fp.discussion WHERE f.id = fd.forum) as UniqueUsersPosts
,(SELECT Count( ra.userid ) AS Students
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid =5
AND ctx.instanceid = c.id
) AS StudentsCount
,(SELECT Count( ra.userid ) AS Teachers
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid =3
AND ctx.instanceid = c.id
) AS 'Teacher<br/>Count'
,(SELECT Count( ra.userid ) AS Users
FROM prefix_role_assignments AS ra
JOIN prefix_context AS ctx ON ra.contextid = ctx.id
WHERE ra.roleid IN (3,5)
AND ctx.instanceid = c.id
) AS UserCount
, (SELECT (UniqueUsersDiscussions / StudentsCount )) as StudentDissUsage
, (SELECT (UniqueUsersPosts /StudentsCount)) as StudentPostUsage
FROM prefix_forum as f
JOIN prefix_course as c ON f.course = c.id
WHERE `type` != 'news'
ORDER BY StudentPostUsage DESC
</code>
 
===All Forum type:NEWS===
<code 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'
</code>
 
===All new forum NEWS items (discussions) from all my Courses===
change "userid = 26" and "id = 26" to a new user id
<code sql>
SELECT c.shortname,f.name,fd.name,FROM_UNIXTIME(fd.timemodified ,"%d %M %Y ") as Date
FROM prefix_forum_discussions as fd
JOIN prefix_forum as f ON f.id = fd.forum
JOIN prefix_course as c ON c.id = f.course
JOIN prefix_user_lastaccess as ul ON (c.id = ul.courseid AND ul.userid = 26)
WHERE fd.timemodified > ul.timeaccess 
AND fd.forum IN (SELECT f.id
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_forum AS f ON cm.instance = f.id
WHERE m.name = 'forum'
AND f.type = 'news')
  AND c.id IN (SELECT c.id
  FROM prefix_course AS c
  JOIN prefix_context AS ctx ON c.id = ctx.instanceid
  JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
  JOIN prefix_user AS u ON u.id = ra.userid
  WHERE u.id = 26) ORDER BY `fd`.`timemodified` DESC
</code>
 
 
===News Forum - Discussions COUNT===
Which is actually... How much instructions students get from their teachers
<code 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
</code>
 
===Cantidad de foros que han sido posteados por profesor===
Queriamos saber cuales son las acciones del profesor dentro de los foros de cada curso, por ello se hizo este informe.
<code sql>
SELECT
concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.shortname,'</a>') AS curso,
CONCAT(u.firstname ,' ',u.lastname) AS Facilitador,
 
(SELECT COUNT( m.name ) AS COUNT FROM
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
</code>
 
==Quiz Module Reports==
===Generate a list of instructors and their email addresses for those courses that has "essay questions" in their quizzes===
<code sql>
SELECT qu.id AS quiz_id, qu.course AS course_id, qu.questions,
                co.fullname AS course_fullname, co.shortname AS course_shortname,
                qu.name AS quiz_name, FROM_UNIXTIME(qu.timeopen) AS quiz_timeopen, FROM_UNIXTIME(qu.timeclose) AS quiz_timeclose,
                u.firstname, u.lastname, u.email,
FROM prefix_quiz qu, prefix_course co, prefix_role re, prefix_context ct, prefix_role_assignments ra, prefix_user u
WHERE FROM_UNIXTIME(timeopen) > '2008-05-14' AND
                qu.course = co.id AND
                co.id = ct.instanceid AND
                ra.roleid = re.id AND
                re.name = 'Teacher' AND
                ra.contextid = ct.id AND
                ra.userid = u.id
SELECT Count('x') As NumOfStudents
                                FROM prefix_role_assignments a
                                JOIN prefix_user u ON userid = u.id
                                WHERE roleid = 5 AND contextid = (SELECT id FROM prefix_context WHERE instanceid = 668 AND contextlevel = 50)
</code>
 
===Number of Quizes per Course===
<code sql>
SELECT count(*)
,concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">Link</a>') AS Quizes
 
FROM prefix_course_modules cm
JOIN prefix_course c ON c.id = cm.course
JOIN prefix_modules as m ON m.id = cm.module
WHERE m.name LIKE 'quiz'
GROUP BY c.id
</code>
 
===List all MultiAnswer (Cloze) Questions===
<code 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'
</code>
 
===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.
<code sql>
SELECT COUNT( * )
,concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php?showadvanced=1&id=',c.id,'">',c.fullname,'</a>') AS Course
FROM  prefix_grade_items AS gi
JOIN prefix_course as c ON c.id = gi.courseid
WHERE  `itemtype` =  'manual'
GROUP BY courseid
</code>
===List the users that did not took the Quiz===
Do not forget to change "c.id = 14" and q.name LIKE '%quiz name goes here%'
<code sql>
SELECT
user2.id AS ID,
ul.timeaccess,
user2.firstname AS Firstname,
user2.lastname AS Lastname,
user2.email AS Email,
user2.username AS IDNumber,
user2.institution AS Institution,
IF (user2.lastaccess = 0,'never',
DATE_FORMAT(FROM_UNIXTIME(user2.lastaccess),'%Y-%m-%d')) AS dLastAccess
,(SELECT DATE_FORMAT(FROM_UNIXTIME(timeaccess),'%Y-%m-%d') FROM prefix_user_lastaccess WHERE userid=user2.id AND courseid=c.id) AS CourseLastAccess
,(SELECT r.name
FROM  prefix_user_enrolments AS uenrol
JOIN prefix_enrol AS e ON e.id = uenrol.enrolid
JOIN prefix_role AS r ON e.id = r.id
WHERE uenrol.userid=user2.id AND e.courseid = c.id) AS RoleName
FROM prefix_user_enrolments AS ue
JOIN prefix_enrol AS e ON e.id = ue.enrolid
JOIN prefix_course AS c ON c.id = e.courseid
JOIN prefix_user AS user2 ON user2 .id = ue.userid
LEFT JOIN prefix_user_lastaccess AS ul ON ul.userid = user2.id
WHERE c.id=14 and ue.userid NOT IN (SELECT qa.userid FROM prefix_quiz_attempts AS qa
JOIN prefix_quiz AS q ON qa.quiz = q.id
JOIN prefix_course AS c ON q.course = c.id
WHERE c.id = 14 AND q.name LIKE '%quiz name goes here%')
</code>
 
 
===List Questions in each Quiz===
 
<code 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
</code>
 
 
===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)
 
<code sql>
SELECT
cm.course "course_id", cm.id "moduel_id", q.id "quiz_id", q.name "quiz_name",
CASE q.grademethod
      WHEN 1 THEN "GRADEHIGHEST"
      WHEN 2 THEN "GRADEAVERAGE"
      WHEN 3 THEN "ATTEMPTFIRST"
      WHEN 4 THEN "ATTEMPTLAST"
END "grade method"
 
, q.attempts "quiz_attempts_allowed", cm.groupmode "group_mode"
, qa.id "attempt_id", qa.state "attempt_state", qa.sumgrades "attempt_grade", qg.grade "user_final_grade", q.grade "quiz_max_grade"
,(SELECT GROUP_CONCAT(g.name) FROM mdl_groups AS g
JOIN mdl_groups_members AS m ON g.id = m.groupid WHERE g.courseid = q.course AND m.userid = u.id) "user_groups",
DATE_FORMAT(FROM_UNIXTIME(qa.timestart), '%d-%m-%Y %h:%k') "attempt_start",
DATE_FORMAT(FROM_UNIXTIME(qa.timefinish), '%d-%m-%Y %h:%k') "attempt_finish",
u.id "user_id", u.firstname, u.lastname,
question.id "question_id", question.name "question_name",
qas.state "question_step_state",qas.fraction "question_grade", qh.hint, question.qtype "question_type"
 
FROM mdl_quiz as q
JOIN mdl_course_modules as cm ON cm.instance = q.id and cm.module = 14
JOIN mdl_quiz_attempts qa ON q.id = qa.quiz
LEFT JOIN mdl_quiz_grades as qg ON qg.quiz = q.id and qg.userid = qa.userid
JOIN mdl_user as u ON u.id = qa.userid
JOIN mdl_question_usages as qu ON qu.id = qa.uniqueid
JOIN mdl_question_attempts as qatt ON qatt.questionusageid = qu.id
JOIN mdl_question as question ON question.id = qatt.questionid
JOIN mdl_question_attempt_steps as qas ON qas.questionattemptid = qatt.id
LEFT JOIN mdl_question_hints as qh ON qh.questionid = q.id
#WHERE q.id = "SOME QUIZ ID"
WHERE cm.course = "SOME COURSE ID"
</code>
 
==SCORM Activity Reports==
 
===Lists All completed SCORM activites by Course name===
This report will list all completed attempts for all SCORM activities. It is ordered first by Course name, then student's last name, then student's first name, then attempt number. Please note: the FROM_UNIXTIME command is for MySQL.
<code sql>
SELECT u.firstname First,u.lastname Last,c.fullname Course, st.attempt Attempt,st.value Status,FROM_UNIXTIME(st.timemodified,"%m-%d-%Y") Date
FROM prefix_scorm_scoes_track AS st
JOIN prefix_user AS u ON st.userid=u.id
JOIN prefix_scorm AS sc ON sc.id=st.scormid
JOIN prefix_course AS c ON c.id=sc.course
WHERE st.value='completed'
ORDER BY c.fullname, u.lastname,u.firstname, st.attempt
</code>
 
== Badges==
 
=== All badges issued, by User ===
 
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.
 
<code sql>
SELECT u.username, b.name AS badgename,
CASE
WHEN b.courseid IS NOT NULL THEN
(SELECT c.shortname
    FROM prefix_course AS c
    WHERE c.id = b.courseid)
WHEN b.courseid IS NULL THEN "*"
END AS Context,
CASE
  WHEN t.criteriatype = 1 AND t.method = 1 THEN "Activity Completion (All)"
  WHEN t.criteriatype = 1 AND t.method = 2 THEN "Activity Completion (Any)"
  WHEN t.criteriatype = 2 AND t.method = 2 THEN "Manual Award"
  WHEN t.criteriatype = 4 AND t.method = 1 THEN "Course Completion (All)"
  WHEN t.criteriatype = 4 AND t.method = 2 THEN "Course Completion (Any)"
  ELSE CONCAT ('Other: ', t.criteriatype)
END AS Criteriatype,
DATE_FORMAT( FROM_UNIXTIME( d.dateissued ) , '%Y-%m-%d' ) AS dateissued,
DATE_FORMAT( FROM_UNIXTIME( d.dateexpire ), '%Y-%m-%d' ) AS dateexpires,
CONCAT ('<a target="_new" href="%%WWWROOT%%/badges/badge.php?hash=',d.uniquehash,'">link</a>') AS Details
FROM prefix_badge_issued AS d
JOIN prefix_badge AS b ON d.badgeid = b.id
JOIN prefix_user AS u ON d.userid = u.id
JOIN prefix_badge_criteria AS t on b.id = t.badgeid
WHERE t.criteriatype <> 0
ORDER BY u.username
</code>
 
Please note: the FROM_UNIXTIME command is for MySQL.
 
=== All badges available in the system, with Earned count ===
 
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.
 
<code 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
 
</code>
 
=== Badges Leaderboard ===
 
A simple list of usernames and how many badges they have earned overall.
 
<code 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
</code>
 
==Administrator Reports==
 
===Config changes in Export friendly form===
 
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.
 
<code sql>
SELECT  
DATE_FORMAT( FROM_UNIXTIME( g.timemodified ) , '%Y-%m-%d' ) AS date,  
u.username AS user,  
g.name AS setting,  
CASE  
  WHEN g.plugin IS NULL THEN "core"
  ELSE g.plugin
END AS plugin,  
g.value AS new_value,  
g.oldvalue AS original_value
FROM prefix_config_log  AS g
JOIN prefix_user AS u ON g.userid = u.id
JOIN prefix_user AS u ON g.userid = u.id
ORDER BY date DESC
ORDER BY date DESC
</code>
</code>
 
 
===Cohorts by user===
===Cohorts by user===
 
 
How to get a list of all users and which cohorts they belong to.
How to get a list of all users and which cohorts they belong to.
 
 
<code sql>
<code sql>
SELECT u.firstname, u.lastname, h.idnumber, h.name
SELECT u.firstname, u.lastname, h.idnumber, h.name
FROM prefix_cohort AS h
FROM prefix_cohort AS h
JOIN prefix_cohort_members AS hm ON h.id = hm.cohortid
JOIN prefix_cohort_members AS hm ON h.id = hm.cohortid
JOIN prefix_user AS u ON hm.userid = u.id
JOIN prefix_user AS u ON hm.userid = u.id
ORDER BY u.firstname
ORDER BY u.firstname
</code>
</code>
 
 
== Useful sub queries ==
 
===Courses created And Active courses by Year===
Active courses is counting course that have at least one Hit, And "Active_MoreThan100Hits" counts courses that have at least 100 Hits
<code sql>
SELECT
 
YEAR( FROM_UNIXTIME( `timecreated` ) ) AS YEAR, COUNT( * ) AS Counter
 
, (SELECT COUNT( DISTINCT course )
FROM prefix_log AS l
WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
) AS "Active"
 
,(SELECT COUNT(*) FROM (
SELECT COUNT( * ),time
FROM prefix_log AS l
GROUP BY course
HAVING COUNT(*) > 100) AS courses_log
WHERE YEAR( FROM_UNIXTIME( courses_log.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) )
) AS "Active_MoreThan100Hits"
 
FROM `prefix_course`
GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )
</code>
 
===Users created And Active users by Year===
Active users is counting users that have at least one Hit, And "Active_MoreThan500Hits" counts users that have at least 500 Hits
<code 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` ) )
</code>
 
== Useful sub queries ==
 
=== All teachers in the course ===
<code sql>
,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) )
FROM prefix_course ic
JOIN prefix_context con ON con.instanceid = ic.id
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
JOIN prefix_role r ON ra.roleid = r.id
JOIN prefix_user u ON u.id = ra.userid
WHERE r.id = 3 AND ic.id = c.id
GROUP BY ic.id
) AS TeacherNames
</code>
 
==See also==
[https://github.com/jleyva/moodle-configurable_reports_repository Configurable Reports Repository on GitHub]
 
[[Category:Contributed code]]


=== All teachers in the course ===
[[es:Reportes específicos hechos por usuarios]]
<code sql>
,(SELECT GROUP_CONCAT( CONCAT( u.firstname,  " ", u.lastname ) )
FROM prefix_course ic
JOIN prefix_context con ON con.instanceid = ic.id
JOIN prefix_role_assignments ra ON con.id = ra.contextid AND con.contextlevel = 50
JOIN prefix_role r ON ra.roleid = r.id
JOIN prefix_user u ON u.id = ra.userid
WHERE r.id = 3 AND ic.id = c.id
GROUP BY ic.id
) AS TeacherNames
</code>
 
[[Category:Contributed code]]

Latest revision as of 19:28, 25 November 2015

User and Role Report

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

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

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

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

Student (user) COUNT in each Course

Including (optional) filter by: year (if included in course fullname). SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',course.id,'">',course.fullname,'</a>') AS Course ,concat('<a target="_new" href="%%WWWROOT%%/user/index.php?contextid=',context.id,'">Show users</a>') AS Users , COUNT(course.id) AS Students FROM prefix_role_assignments AS asg JOIN prefix_context AS context ON asg.contextid = context.id AND context.contextlevel = 50 JOIN prefix_user AS user ON user.id = asg.userid JOIN prefix_course AS course ON context.instanceid = course.id WHERE asg.roleid = 5

  1. 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%%

Role assignments on categories

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

Permissions Overides on Categories

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

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

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

Lists "loggedin users" from the last 120 days

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

and user count for that same population: SELECT COUNT(id) as Users FROM `prefix_user` WHERE DATEDIFF( NOW(),FROM_UNIXTIME(`lastlogin`) ) < 120

Lists the users who have only logged into the site once

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

Students in all courses of some institute

What is the status (deleted or not) of all Students (roleid = 5) in all courses of some Institute SELECT c.id, c.fullname, u.firstname, u.lastname, u.deleted FROM prefix_course AS c JOIN prefix_context AS ctx ON c.id = ctx.instanceid JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id JOIN prefix_user AS u ON u.id = ra.userid WHERE ra.roleid =5 AND ctx.instanceid = c.id AND u.institution = 'please enter school name here'

Full User info (for deleted users)

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

User's courses

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

List Users with extra info (email) in current course

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

Special Roles

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

Courses without Teachers

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

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

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

List of users with language

An issue with systems that do not have their default language set up properly is the need to do a mass change for all users to a localization. A common case is changing default English to American English.

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:

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

List of users with Authentication

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

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

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

Compare role capability and permissions

SELECT DISTINCT mrc.capability ,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability

 AND rc.roleid = '1' AND rc.contextid = '1') AS Manager

,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability

 AND rc.roleid = '2' AND rc.contextid = '1') AS CourseCreator

,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability

 AND rc.roleid = '3' AND rc.contextid = '1') AS Teacher

,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability

 AND rc.roleid = '4' AND rc.contextid = '1') AS AssistantTeacher

,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability

 AND rc.roleid = '5' AND rc.contextid = '1') AS Student

,(SELECT rc.permission FROM `mdl_role_capabilities` AS rc WHERE rc.capability = mrc.capability

 AND rc.roleid = '6' AND rc.contextid = '1') AS Guest

FROM `mdl_role_capabilities` AS mrc

Log Activity Reports

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

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

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

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

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

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

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

How many LOGINs per user and user's Activity

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

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

Select

    Count(Distinct userid) As countUsers
  , Count(course) As countVisits
  , concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course
From prefix_log as l
JOIN prefix_course as c on c.id = l.course
Where course > 0 and FROM_UNIXTIME(time) >= DATE_SUB(NOW(), INTERVAL 1 DAY) and c.fullname LIKE '%תשעג%'
Group By course

ORDER BY countVisits DESC

Weekly Instructor Online Participation

Contributed by Elizabeth Dalton

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.

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

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

, c.startdate AS Course_Start_Date

, c.visible AS Visible

, COUNT(l.id) AS Edits

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

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

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

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

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

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

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

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


Module activity (Hits) between dates

SELECT module, COUNT( * ) FROM prefix_log AS l WHERE (FROM_UNIXTIME( l.`time` ) BETWEEN '2012-10-01 00:00:00' AND '2013-09-31 00:00:00') GROUP BY module

Module activity (Instances and Hits) for each academic year

SELECT name

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

,(SELECT COUNT(*) FROM mdl_log AS l WHERE (FROM_UNIXTIME(l.`time`) BETWEEN '2010-10-01 00:00:00' AND '2011-09-31 00:00:00') AND l.module = m.name ) AS "Used 2010"

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

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


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

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

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'

  1. AND timecreated > UNIX_TIMESTAMP('2015-01-01 00:00:00') # optional start date
  2. 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))

Course Reports

Most Active courses

SELECT count(l.userid) AS Views FROM `mdl_logstore_standard_log` l, `mdl_user` u, `mdl_role_assignments` r WHERE l.courseid=35 AND l.userid = u.id AND (l.timecreated > UNIX_TIMESTAMP('2015-01-01 00:00:00') AND l.timecreated <= UNIX_TIMESTAMP('2015-01-31 23:59:59'))AND r.contextid= ( SELECT id FROM mdl_context WHERE contextlevel=50 AND instanceid=l.courseid

)

AND r.roleid=5 AND r.userid = u.id

Active courses, advanced

Including: Teacher's name, link to the course, All types of log activities, special YEAR generated field, Activities and Resource count, enrolled Student count SELECT COUNT(l.id) hits, concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course

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

,CASE

 WHEN c.fullname LIKE '%תשע' THEN 'תשע'
 WHEN c.fullname LIKE '%תשעא' THEN 'תשעא'
 WHEN c.fullname LIKE '%תשעב' THEN 'תשעב'

END AS Year

,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = l.course) Modules

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

FROM prefix_log l INNER JOIN prefix_course c ON l.course = c.id GROUP BY c.id HAVING Modules > 2 ORDER BY Year DESC, hits DESC

Count unique teachers with courses that use at least X module (Moodle19)

You can remove the outer "SELECT COUNT(*) FROM (...) AS ActiveTeachers" SQL query and get the list of the Teachers and Courses. SELECT COUNT(*) FROM (SELECT c.id AS CourseID, c.fullname AS Course, ra.roleid AS RoleID, CONCAT(u.firstname, ' ', u.lastname) AS Teacher ,(SELECT COUNT(*) FROM prefix_course_modules cm WHERE cm.course = c.id) AS Modules FROM prefix_course AS c JOIN prefix_context AS ctx ON c.id = ctx.instanceid AND ctx.contextlevel = 50 JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id JOIN prefix_user AS u ON u.id = ra.userid JOIN prefix_course_categories AS cc ON cc.id = c.category WHERE ra.roleid = 3 GROUP BY u.id HAVING Modules > 5) AS ActiveTeachers

RESOURCE count for each COURSE

SELECT COUNT(l.id) count, l.course, c.fullname coursename FROM prefix_resource l INNER JOIN prefix_course c on l.course = c.id GROUP BY course ORDER BY count DESC

Common resource types count for each Category (Moodle19)

Including sub-categories in total count. SELECT mcc.id AS mccid, CONCAT( LPAD( , mcc.depth, '.' ) , mcc.name ) AS Category ,(SELECT COUNT( * ) FROM prefix_resource AS r JOIN prefix_course AS c ON c.id = r.course JOIN prefix_course_categories AS cc ON cc.id = c.category WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference LIKE 'http://%' ) AS Links

,(SELECT COUNT( * ) FROM prefix_resource AS r JOIN prefix_course AS c ON c.id = r.course JOIN prefix_course_categories AS cc ON cc.id = c.category WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'file' AND r.reference NOT LIKE 'http://%' ) AS Files

,(SELECT COUNT( * ) FROM prefix_resource AS r JOIN prefix_course AS c ON c.id = r.course JOIN prefix_course_categories AS cc ON cc.id = c.category WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'directory' ) AS Folders

,(SELECT COUNT( * ) FROM prefix_resource AS r JOIN prefix_course AS c ON c.id = r.course JOIN prefix_course_categories AS cc ON cc.id = c.category WHERE cc.path LIKE CONCAT( '%', mccid, '%' ) AND r.TYPE = 'html' ) AS Pages

,(SELECT COUNT(*) FROM stats_log_context_role_course WHERE roleid = 5 AND module = 'resource' AND category = mcc.id ) AS Hits

FROM prefix_course_categories AS mcc ORDER BY mcc.path Where "stats_log_context_role_course" (in the above SQL query) is a VIEW generated by: CREATE VIEW stats_log_context_role_course AS SELECT l.course, c.category, cc.path, l.module, l.action, ra.userid, ra.roleid FROM prefix_log AS l JOIN prefix_context AS context ON context.instanceid = l.course AND context.contextlevel = 50 JOIN prefix_role_assignments AS ra ON ra.userid = l.userid AND ra.contextid = context.id JOIN prefix_course AS c ON c.id = l.course JOIN prefix_course_categories AS cc ON cc.id = c.category

Same query but for Moodle2+ SELECT mcc.id AS mccid, CONCAT( LPAD( , mcc.depth, '.' ) , mcc.name ) AS Category, mcc.path,

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

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

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

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

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

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

FROM prefix_course_categories AS mcc ORDER BY mcc.path

Detailed Resource COUNT by Teacher in each course

Including (optional) filter by: year, semester and course id.

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS CourseID , c.id ,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)

 FROM prefix_role_assignments AS ra
 JOIN prefix_user AS u ON ra.userid = u.id
 JOIN prefix_context AS ctx ON ctx.id = ra.contextid
 WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher

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

FROM `prefix_resource` as r JOIN `prefix_course` AS c on c.id = r.course

  1. WHERE type= 'file' and reference NOT LIKE 'http://%'
  1. WHERE 1=1
  2. %%FILTER_YEARS:c.fullname%%
  3. AND c.fullname LIKE '%2013%'

GROUP BY course ORDER BY COUNT(c.id) DESC

Courses that are defined as using GROUPs

SELECT concat('<a target="_new" href="%%WWWROOT%%/group/index.php?id=',c.id,'">',c.fullname,'</a>') AS Course ,(SELECT count(*) FROM prefix_course_modules cm WHERE cm.course = c.id) Modules ,(SELECT count(*) FROM prefix_groups g WHERE g.courseid = c.id) Groups

FROM `prefix_course` AS c

WHERE groupmode > 0

Courses with Groups

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.

SELECT course.fullname AS Course, user.firstname AS Firstname, user.lastname AS Lastname, user.email AS Email,

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_groups AS g ON c.id = g.courseid JOIN prefix_groups_members AS m ON g.id = m.groupid JOIN prefix_user AS u ON m.userid = u.id WHERE c.id = course.id )

ORDER BY Course, Lastname, Firstname

Groups in course with member list

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

Group Export

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

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 '

    '; foreach ($categories as $category) { echo '
  1. <a href="'.$CFG->wwwroot.'/course/category.php?id='.$category->id.'">'.$category->name.'</a>
  2. '; } echo '

';

?>

Blog activity per Course (not including VIEW)

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

Student's posts content in all course blogs (oublog)

SELECT b.name ,op.title ,op.message ,( SELECT CONCAT(u.firstname, ' ',u.lastname) FROM prefix_user AS u WHERE u.id = oi.userid) AS "Username"

FROM prefix_oublog_posts AS op JOIN prefix_oublog_instances AS oi ON oi.id = op.oubloginstancesid JOIN prefix_oublog as b ON b.id = oi.oublogid JOIN prefix_course AS c ON b.course = c.id

WHERE c.id = %%COURSEID%%

All Courses which uploaded a Syllabus file

+ under specific Category + show first Teacher in that course + link Course's fullname to actual course SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') as Course ,c.shortname,r.name ,(SELECT CONCAT(u.firstname,' ', u.lastname) as Teacher FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id JOIN prefix_user as u ON u.id = ra.userid WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) as Teacher FROM prefix_resource as r JOIN prefix_course as c ON r.course = c.id WHERE ( r.name LIKE '%סילבוס%' OR r.name LIKE '%סילאבוס%' OR r.name LIKE '%syllabus%' OR r.name LIKE '%תכנית הקורס%' ) AND c.category IN (10,18,26,13,28)

Site-wide completed SCORM activities by Course name

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

Courses without Groups using Forum in Group Mode

Contributed by Eric Strom

This report identifies courses that have no groups created yet have forum activities (other than Announcements) set to use either 'Visible groups' or 'Separate groups'. Actions to take for these courses (choose one): 1) Forum activity should be set to 'No groups' 2) Groups need to be created in the course and populated with students to make use of the forums in group mode. Otherwise, students may not be able to see or reply to discussions in these forums. Links go to edit course settings and forum module settings.

NOTES: This does not catch the scenario when courses have groups and some or all students are not assigned to a group. You may want to also run the report: "Courses with Empty Groups & Forum in Group Mode"

SELECT

(SELECT cat.name FROM prefix_course_categories cat WHERE cat.id = c.category) AS Dept,

concat('<a target="_new" href="%%WWWROOT%%/course/edit.php',CHAR(63),'id=', c.id,'">',c.idnumber,'</a>') AS CourseID_Number, ( CASE WHEN c.groupmode = 0 THEN "no groups" WHEN c.groupmode = 1 THEN "separate groups" WHEN c.groupmode = 2 THEN "visible groups" END ) AS Course_Group_Mode , concat('<a target="_new" href="%%WWWROOT%%/course/modedit.php',CHAR(63),'upd','ate=',cm.id,'">',f.name,'</a>') AS Forum_Name,

( CASE WHEN cm.groupmode = 0 THEN "no groups" WHEN cm.groupmode = 1 THEN "separate groups" WHEN cm.groupmode = 2 THEN "visible groups" END ) AS Module_Group_Mode

, cm.visible AS Forum_Visible , now() AS Report_Timestamp

FROM prefix_course AS c LEFT OUTER JOIN prefix_forum as f ON c.id = f.course JOIN prefix_course_modules AS cm ON cm.instance = f.id

WHERE NOT(f.TYPE = 'news') AND cm.module = 9 and cm.course = c.id AND cm.groupmode > 0 AND (c.id NOT IN (SELECT c.id FROM prefix_course AS c JOIN prefix_groups AS g ON c.id = g.courseid WHERE c.id = g.courseid))

GROUP BY cm.id ORDER BY c.idnumber

Courses with Empty Groups & Forum in Group Mode

Contributed by Eric Strom

This report identifies courses that have groups with no students in them yet have forum activities (other than Announcements) set to use either 'Visible groups' or 'Separate groups'. Actions to take for these courses (choose one): 1) Forum activity should be set to 'No groups' 2) Groups need to be populated with students to make use of the forums in group mode. Otherwise, students may not be able to see or reply to discussions in these forums. Links go to edit course settings and forum module settings.

NOTES: This does not catch the scenario when courses have groups and some but not all students are not assigned to a group. You may want to also run the report: "Courses without Groups using Forum in Group Mode"

SELECT

(SELECT cat.name FROM prefix_course_categories cat WHERE cat.id = c.category) AS Dept,

concat('<a target="_new" href="%%WWWROOT%%/course/edit.php',CHAR(63),'id=',c.id,'">',c.idnumber,'</a>') AS CourseID_Number,

concat('<a target="_new" href="%%WWWROOT%%/course/modedit.php',CHAR(63),'upd','ate=',cm.id,'">', f.name,'</a>') AS Forum_Name,

( CASE WHEN cm.groupmode = 0 THEN "no groups" WHEN cm.groupmode = 1 THEN "separate groups" WHEN cm.groupmode = 2 THEN "visible groups" END ) AS Module_Group_Mode,

cm.visible AS Forum_Visible, COUNT(gm.id) AS Group_Members, now() AS Report_Timestamp

FROM prefix_course AS c LEFT OUTER JOIN prefix_forum as f ON c.id = f.course JOIN prefix_course_modules AS cm ON cm.instance = f.id JOIN prefix_groups AS g ON c.id = g.courseid LEFT OUTER JOIN prefix_groups_members AS gm ON g.id = gm.groupid

WHERE NOT(f.TYPE = 'news') AND cm.module = 9 and cm.course = c.id AND cm.groupmode > 0

GROUP BY c.idnumber, cm.id

Having Group_Members = 0

ORDER BY c.idnumber



Module instances + Module HITs by role teacher and student in course

SELECT m.name AS "Module name" , COUNT(*) AS "Module count"

,(SELECT COUNT(*) FROM prefix_log AS l WHERE l.course = cm.course AND l.module = m.name ) AS "Hits"

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

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

FROM mdl_course_modules AS cm JOIN mdl_modules AS m on m.id = cm.module WHERE cm.course = '%%COURSEID%%' GROUP BY cm.module

Grade and Course Completion Reports

Site-Wide Grade Report with All Items

Shows grades for all course items along with course totals for each student. Works with ad-hoc reports or Configurable Reports SELECT u.firstname AS 'First' , u.lastname AS 'Last', u.firstname + ' ' + u.lastname AS 'Display Name', c.fullname AS 'Course', cc.name AS 'Category',

CASE

 WHEN gi.itemtype = 'course' 
  THEN c.fullname + ' Course Total'
 ELSE gi.itemname

END AS 'Item Name',

ROUND(gg.finalgrade,2) AS Grade, DATEADD(ss,gi.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,gi.timemodified,'1970-01-01') AS Time with DATE_ADD('1970-01-01', INTERVAL gi.timemodified SECOND) AS Time

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 ORDER BY lastname

Learner report by Learner with grades

Which Learners in which course and what are the grades SELECT u.firstname AS 'Name' , u.lastname AS 'Surname', c.fullname AS 'Course', cc.name AS 'Category', CASE WHEN gi.itemtype = 'Course' THEN c.fullname + ' Course Total' ELSE gi.itemname END AS 'Item Name', ROUND(gg.finalgrade,2) AS Score,ROUND(gg.rawgrademax,2) AS Max, ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) as Percentage,

if (ROUND(gg.finalgrade / gg.rawgrademax * 100 ,2) > 79,'Yes' , 'No') as Pass

FROM prefix_course AS c JOIN prefix_context AS ctx ON c.id = ctx.instanceid JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id JOIN prefix_user AS u ON u.id = ra.userid JOIN prefix_grade_grades AS gg ON gg.userid = u.id JOIN prefix_grade_items AS gi ON gi.id = gg.itemid JOIN prefix_course_categories AS cc ON cc.id = c.category WHERE gi.courseid = c.id and gi.itemname != 'Attendance' ORDER BY `Name` ASC

User Course Completion

A very simple report with list of course completion status by username. Completions are noted by date, blank otherwise.

SELECT u.username, c.shortname, DATE_FORMAT(FROM_UNIXTIME(p.timecompleted ),'%Y-%m-%d') AS completed FROM prefix_course_completions AS p JOIN prefix_course AS c ON p.course = c.id JOIN prefix_user AS u ON p.userid = u.id WHERE c.enablecompletion = 1 ORDER BY u.username

User Course Completion with Criteria

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

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

Activity Module Reports

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

Detailed ACTIONs for each MODULE

SELECT module,action,count(id) as counter FROM prefix_log GROUP BY module,action ORDER BY module,counter desc

Most popular ACTIVITY

SELECT COUNT(l.id) hits, module FROM prefix_log l WHERE module != 'login' AND module != 'course' AND module != 'role' GROUP BY module ORDER BY hits DESC

System wide use of ACTIVITIES and RESOURCES

SELECT count( cm.id ) AS counter, m.name FROM `prefix_course_modules` AS cm JOIN prefix_modules AS m ON cm.module = m.id GROUP BY cm.module ORDER BY counter DESC

LOG file ACTIONS per MODULE per COURSE (IDs)

select course,module,action,count(action) as summa from prefix_log where action <> 'new' group by course,action,module order by course,module,action

System Wide usage count of various course Activities

(Tested and works fine in Moodle 2.x) Like: Forum, Wiki, Blog, Assignment, Database,

  1. Within specific category
  2. Teacher name in course

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

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

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

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%forum%') AS Forums

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%data%') AS Databses

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%assignment%') AS Assignments

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

FROM prefix_course AS c WHERE c.category IN ( 18) ORDER BY Wikis DESC,Blogs DESC, Forums DESC

Course wiki usage/activity over the last 6 semesters

SELECT "Courses with Wikis"

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

and c.fullname LIKE CONCAT('%','2010','%') and c.fullname LIKE '%Semester A%') AS '2010 
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 
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 'תשעא 
סמסטר א'

,(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 'תשעא 
סמסטר ב'

,(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 'תשעב 
סמסטר א'

,(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 'תשעב 
סמסטר ב'

,(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 'תשעג 
סמסטר א'

,(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 'תשעג 
סמסטר ב'

Detailed WIKI activity (per wiki per course)

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

Wiki usage, system wide

(you can filter the output by selecting some specific course categories : "WHERE c.category IN ( 8,13,15)")

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

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

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%') AS 'WikiActivity
ALL'

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%add%' ) AS 'WikiActivity
ADD'

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%edit%' ) AS 'WikiActivity
EDIT'

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%annotate%' ) AS 'WikiActivity
ANNOTATE'

,(SELECT count(*) FROM prefix_log as l WHERE l.course = c.id AND l.module LIKE '%wiki%' and l.action LIKE '%comments%' ) AS 'WikiActivity
Comments'

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

,(SELECT count(*) FROM prefix_ouwiki_pages as ouwp JOIN prefix_ouwiki as ouw ON ouw.id = ouwp.subwikiid WHERE ouw.course = c.id GROUP BY ouw.course ) as OUWikiPages

,(SELECT count( DISTINCT nwp.pagename ) FROM prefix_wiki_pages AS nwp JOIN prefix_wiki AS nw ON nw.id = nwp.dfwiki WHERE nw.course = c.id ) As NWikiPages

FROM prefix_course AS c WHERE c.category IN ( 8,13,15) HAVING Wikis > 0 ORDER BY 'WikiActivity
ALL' DESC

Aggregated Teacher activity by "WEB2" Modules

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

List all the certificates issued, sort by variables in the custom profile fields

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

SELECT DATE_FORMAT( FROM_UNIXTIME(prefix_certificate_issues.timecreated), '%Y-%m-%d' ) AS Date, prefix_certificate_issues.classname AS Topic, prefix_certificate.name AS Certificate, prefix_certificate_issues.studentname as Name, prefix_user_info_data.data AS Units

FROM prefix_certificate_issues

INNER JOIN prefix_user_info_data on prefix_certificate_issues.userid = prefix_user_info_data.userid

INNER JOIN prefix_certificate on prefix_certificate_issues.certificateid = prefix_certificate.id

WHERE prefix_user_info_data.data='Unit 1' OR prefix_user_info_data.data='Unit 2' OR prefix_user_info_data.data='Unit 3'

ORDER BY Units, Name, Topic ASC

Counter Blog usage in Courses,system wide

What teachers in what courses, uses blogs and how many + student count in that course.

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

,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)

 FROM prefix_role_assignments AS ra
 JOIN prefix_user AS u ON ra.userid = u.id
 JOIN prefix_context AS ctx ON ctx.id = ra.contextid
 WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher

,(SELECT count( m.name ) AS count FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id WHERE cm.course = c.id AND m.name LIKE '%blog%') AS Blogs

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

FROM prefix_course AS c, (SELECT @counter := 0) as s_init WHERE c.category IN ( 8,13,15) HAVING Blogs > 0 ORDER BY Blogs DESC

Elluminate (Blackboard Collaborate) - system wide usage

SELECT e.name As Session ,er.recordingsize ,c.fullname As Course ,u.firstname,u.lastname ,DATE_FORMAT(FROM_UNIXTIME(e.timestart),'%d-%m-%Y') AS dTimeStart ,concat('<a target="_new" href="%%WWWROOT%%/moodle/mod/elluminate/loadrecording.php?id=',er.id,'">Show</a>') AS RecordedSession

FROM prefix_elluminate_recordings AS er JOIN prefix_elluminate AS e ON e.meetingid = er.meetingid JOIN prefix_course as c ON c.id = e.course JOIN prefix_user AS u ON u.id = e.creator ORDER BY er.recordingsize DESC


Choice

Results of the Choice activity. For all courses, shows course shortname, username, the Choice text, and the answer chosen by the user.

SELECT c.shortname AS course, u.username, h.name as question, o.text AS answer FROM prefix_choice AS h JOIN prefix_course AS c ON h.course = c.id JOIN prefix_choice_answers AS a ON h.id = a.choiceid JOIN prefix_user AS u ON a.userid = u.id JOIN prefix_choice_options AS o ON a.optionid = o.id

Assignment type usage in courses

SELECT

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

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

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

  1. GROUP BY apc.plugin

) AS "File Assignments"

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

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

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

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

FROM prefix_assign AS assign JOIN prefix_course AS c ON c.id = assign.course GROUP BY c.id

Assignment Module Reports

All Ungraded Assignments

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 the submitted assignments that still need grading, along with a link that goes directly to the submission to grade it. The links work if you view the report within Moodle. select u.firstname AS "First", u.lastname AS "Last", c.fullname AS "Course", a.name AS "Assignment",

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


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

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

order by c.fullname, a.name, u.lastname

Assignments (and Quizzes) waiting to be graded

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

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

  1. AND c.fullname LIKE '%תשעג%'

%%FILTER_YEARS:c.fullname%%

    1. You can enable the SEMESTER filter as well,
    2. by uncommenting the following line:
    3. %%FILTER_SEMESTERS:c.fullname%%

ORDER BY 'Open
Assignments' DESC

Rubrics without zero values in criteria

Contributed by Eric Strom

Rubric calculations in Moodle can fail to align with instructors expectations if they lack a zero value for each criterion used in the assessment. From documentation at https://docs.moodle.org/28/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'

Resource Module Reports

List "Recently uploaded files"

see what users are uploading SELECT FROM_UNIXTIME(time,'%Y %M %D %h:%i:%s') as time ,ip,userid,url,info FROM `prefix_log` WHERE `action` LIKE 'upload' ORDER BY `prefix_log`.`time` DESC

List Courses that loaded a specific file: "X"

Did the Teacher (probably) uploaded course's Syllabus ? SELECT c.id, c.fullname FROM `prefix_log` as l JOIN prefix_course as c ON c.id = l.course WHERE `action` LIKE '%upload%' AND ( info LIKE '%Syllabus%' OR info LIKE '%Sylabus%' ) GROUP BY c.id

All resources that link to some specific external website

+ link to course + who's the teacher + link to external resource SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course ,c.shortname,r.name ,(SELECT CONCAT(u.firstname,' ', u.lastname) AS Teacher FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id JOIN prefix_user AS u ON u.id = ra.userid WHERE ra.roleid = 3 AND ctx.instanceid = c.id LIMIT 1) AS Teacher ,concat('<a target="_new" href="%%WWWROOT%%/mod/resource/view.php?id=',r.id,'">',r.name,'</a>') AS Resource FROM prefix_resource AS r JOIN prefix_course AS c ON r.course = c.id WHERE r.reference LIKE 'http://info.oranim.ac.il/home%'

"Compose Web Page" RESOURCE count

SELECT course,prefix_course.fullname, COUNT(*) AS Total FROM `prefix_resource` JOIN `prefix_course` ON prefix_course.id = prefix_resource.course WHERE type='html' GROUP BY course

Resource count in courses

+ (First)Teacher name + Where course is inside some specific Categories SELECT COUNT(*) AS count ,r.course ,c.shortname shortname ,c.fullname coursename ,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)

 FROM prefix_role_assignments AS ra
 JOIN prefix_user as u ON ra.userid = u.id
 JOIN prefix_context AS ctx ON ctx.id = ra.contextid
 WHERE ra.roleid = 3 AND ctx.instanceid = r.course AND ctx.contextlevel = 50 LIMIT 1) AS Teacher

FROM prefix_resource r JOIN prefix_course c ON r.course = c.id WHERE c.category IN (10,13,28,18,26) GROUP BY r.course ORDER BY COUNT(*) DESC

Delete all the automated backup files

Prepare bash cli script to delete all the automated backup files on the file system. (clean up some disk space) SELECT CONCAT( 'rm -f /var/moodledatanew/filedir/', SUBSTRING( contenthash, 1, 2 ) , '/', SUBSTRING( contenthash, 3, 2 ) , '/', contenthash ) FROM `mdl_files` WHERE `filename` LIKE '%mbz%' AND filearea = 'automated'

Find out how much disk space is used by all automated backup files: SELECT SUM(filesize)/(1024*1024*1024) FROM `mdl_files` WHERE `filename` LIKE '%mbz%' AND filearea = 'automated'

Forum Module Reports

print all User's post in course Forums

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

FROM prefix_forum_posts AS fp JOIN prefix_user as u ON u.id = fp.userid JOIN prefix_forum_discussions AS fd ON fp.discussion = fd.id JOIN prefix_forum AS f ON f.id = fd.forum JOIN prefix_course as c ON c.id = fd.course WHERE fd.course = '@@COURSEID@@' GROUP BY f.id,u.id ORDER BY u.id

FORUM use Count per COURSE -- not including NEWS Forum!

SELECT prefix_course.fullname, prefix_forum.course, count(*) as total FROM prefix_forum INNER JOIN prefix_course ON prefix_course.id = prefix_forum.course WHERE NOT(prefix_forum.type = 'news') GROUP BY prefix_forum.course ORDER BY total desc

FORUM use Count per COURSE by type -- not including NEWS Forum!

SELECT prefix_course.fullname, prefix_forum.course, prefix_forum.type, count(*) as total FROM prefix_forum INNER JOIN prefix_course ON prefix_course.id = prefix_forum.course WHERE NOT(prefix_forum.type = 'news') GROUP BY prefix_forum.course,prefix_forum.type ORDER BY total desc

Forum activity - system wide

SELECT concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.id,'</a>') AS CourseID ,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)

 FROM prefix_role_assignments AS ra
 JOIN prefix_user AS u ON ra.userid = u.id
 JOIN prefix_context AS ctx ON ctx.id = ra.contextid
 WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher

,c.fullname as Course ,f.type ,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id WHERE ra.roleid = 5 AND ctx.instanceid = c.id) AS Students , fd.forum, f.name,count(*) AS cPostAndDisc ,(SELECT count(*) FROM prefix_forum_discussions AS ifd WHERE ifd.forum = f.id) AS cDiscussion FROM prefix_forum_posts AS fp JOIN prefix_forum_discussions AS fd ON fd.id = fp.discussion JOIN prefix_forum AS f ON f.id = fd.forum JOIN prefix_course AS c ON c.id = f.course WHERE f.type != 'news' AND c.fullname LIKE '%2013%'

    1. WHERE 1=1
    2. %%FILTER_YEARS:c.fullname%%
    3. You can enable the SEMESTER filter as well,
    4. by uncommenting the following line:
    5. %%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
Count' ,(SELECT Count( ra.userid ) AS Users FROM prefix_role_assignments AS ra JOIN prefix_context AS ctx ON ra.contextid = ctx.id WHERE ra.roleid IN (3,5) AND ctx.instanceid = c.id ) AS UserCount , (SELECT (UniqueUsersDiscussions / StudentsCount )) as StudentDissUsage , (SELECT (UniqueUsersPosts /StudentsCount)) as StudentPostUsage FROM prefix_forum as f JOIN prefix_course as c ON f.course = c.id WHERE `type` != 'news' ORDER BY StudentPostUsage DESC

All Forum type:NEWS

SELECT f.id, f.name FROM prefix_course_modules AS cm JOIN prefix_modules AS m ON cm.module = m.id JOIN prefix_forum AS f ON cm.instance = f.id WHERE m.name = 'forum' AND f.type = 'news'

All new forum NEWS items (discussions) from all my Courses

change "userid = 26" and "id = 26" to a new user id SELECT c.shortname,f.name,fd.name,FROM_UNIXTIME(fd.timemodified ,"%d %M %Y ") as Date FROM prefix_forum_discussions as fd JOIN prefix_forum as f ON f.id = fd.forum JOIN prefix_course as c ON c.id = f.course JOIN prefix_user_lastaccess as ul ON (c.id = ul.courseid AND ul.userid = 26) WHERE fd.timemodified > ul.timeaccess

AND fd.forum IN (SELECT f.id
FROM prefix_course_modules AS cm
JOIN prefix_modules AS m ON cm.module = m.id
JOIN prefix_forum AS f ON cm.instance = f.id
WHERE m.name = 'forum'
AND f.type = 'news')
 AND c.id IN (SELECT c.id
  FROM prefix_course AS c
  JOIN prefix_context AS ctx ON c.id = ctx.instanceid
  JOIN prefix_role_assignments AS ra ON ra.contextid = ctx.id
  JOIN prefix_user AS u ON u.id = ra.userid
  WHERE u.id = 26) ORDER BY `fd`.`timemodified` DESC


News Forum - Discussions COUNT

Which is actually... How much instructions students get from their teachers SELECT c.shortname , concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course ,( SELECT DISTINCT CONCAT(u.firstname,' ',u.lastname)

 FROM prefix_role_assignments AS ra
 JOIN prefix_user AS u ON ra.userid = u.id
 JOIN prefix_context AS ctx ON ctx.id = ra.contextid
 WHERE ra.roleid = 3 AND ctx.instanceid = c.id AND ctx.contextlevel = 50 LIMIT 1) AS Teacher

,concat('<a target="_new" href="%%WWWROOT%%/mod/forum/view.php?f=',fd.forum,'">',count(fd.id),'</a>') AS DiscussionsSum FROM prefix_forum_discussions AS fd INNER JOIN prefix_forum AS f ON f.id = fd.forum INNER JOIN prefix_course AS c ON c.id = f.course WHERE f.type = 'news' AND c.category IN (10,13,28,18,26) GROUP BY fd.forum ORDER BY count(fd.id) DESC

Cantidad de foros que han sido posteados por profesor

Queriamos saber cuales son las acciones del profesor dentro de los foros de cada curso, por ello se hizo este informe. 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

Quiz Module Reports

Generate a list of instructors and their email addresses for those courses that has "essay questions" in their quizzes

SELECT qu.id AS quiz_id, qu.course AS course_id, qu.questions,

               co.fullname AS course_fullname, co.shortname AS course_shortname,
               qu.name AS quiz_name, FROM_UNIXTIME(qu.timeopen) AS quiz_timeopen, FROM_UNIXTIME(qu.timeclose) AS quiz_timeclose,
               u.firstname, u.lastname, u.email,

FROM prefix_quiz qu, prefix_course co, prefix_role re, prefix_context ct, prefix_role_assignments ra, prefix_user u WHERE FROM_UNIXTIME(timeopen) > '2008-05-14' AND

               qu.course = co.id AND
               co.id = ct.instanceid AND
               ra.roleid = re.id AND
               re.name = 'Teacher' AND
               ra.contextid = ct.id AND
               ra.userid = u.id

SELECT Count('x') As NumOfStudents

                               FROM prefix_role_assignments a
                               JOIN prefix_user u ON userid = u.id
                               WHERE roleid = 5 AND contextid = (SELECT id FROM prefix_context WHERE instanceid = 668 AND contextlevel = 50)

Number of Quizes per Course

SELECT count(*) ,concat('<a target="_new" href="%%WWWROOT%%/course/view.php?id=',c.id,'">',c.fullname,'</a>') AS Course ,concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/index.php?id=',c.id,'">Link</a>') AS Quizes

FROM prefix_course_modules cm JOIN prefix_course c ON c.id = cm.course JOIN prefix_modules as m ON m.id = cm.module WHERE m.name LIKE 'quiz' GROUP BY c.id

List all MultiAnswer (Cloze) Questions

SELECT concat('<a target="_new" href="%%WWWROOT%%/mod/quiz/attempt.php?q=', quiz.id, '">', quiz.name, '</a>') AS Quiz ,question.id question_id, question.questiontext FROM prefix_question question JOIN prefix_quiz_question_instances qqi ON question.id = qqi.question JOIN prefix_quiz quiz ON qqi.quiz = quiz.id WHERE `qtype` LIKE 'multianswer'

List courses with MANUAL grades

Which is basically and indication to teachers using Moodle to hold offline grades inside Moodle's Gradebook, So grades could be uploaded into an administrative SIS. Use with Configurable Reports. SELECT COUNT( * ) ,concat('<a target="_new" href="%%WWWROOT%%/grade/edit/tree/index.php?showadvanced=1&id=',c.id,'">',c.fullname,'</a>') AS Course FROM prefix_grade_items AS gi JOIN prefix_course as c ON c.id = gi.courseid WHERE `itemtype` = 'manual' GROUP BY courseid

List the users that did not took the Quiz

Do not forget to change "c.id = 14" and q.name LIKE '%quiz name goes here%' SELECT user2.id AS ID, ul.timeaccess, user2.firstname AS Firstname, user2.lastname AS Lastname, user2.email AS Email, user2.username AS IDNumber, user2.institution AS Institution,

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

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

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

FROM prefix_user_enrolments AS ue JOIN prefix_enrol AS e ON e.id = ue.enrolid JOIN prefix_course AS c ON c.id = e.courseid JOIN prefix_user AS user2 ON user2 .id = ue.userid LEFT JOIN prefix_user_lastaccess AS ul ON ul.userid = user2.id WHERE c.id=14 and ue.userid NOT IN (SELECT qa.userid FROM prefix_quiz_attempts AS qa JOIN prefix_quiz AS q ON qa.quiz = q.id JOIN prefix_course AS c ON q.course = c.id WHERE c.id = 14 AND q.name LIKE '%quiz name goes here%')


List Questions in each Quiz

SELECT quiz.id,quiz.name, q.id, q.name FROM mdl_quiz AS quiz JOIN mdl_question AS q ON FIND_IN_SET(q.id, quiz.questions) WHERE quiz.course = %%COURSEID%% ORDER BY quiz.id ASC


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

  1. WHERE q.id = "SOME QUIZ ID"

WHERE cm.course = "SOME COURSE ID"

SCORM Activity Reports

Lists All completed SCORM activites by Course name

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

Badges

All badges issued, by User

This report will show you all the badges on a site that have been issued, both site and all courses, by the username of each user issued a badge. Includes the type of criteria passed (activity, course completion, manual), date issued, date expires, and a direct link to that issued badge page so you can see all the other details for that badge.

SELECT u.username, b.name AS badgename, CASE WHEN b.courseid IS NOT NULL THEN (SELECT c.shortname

   FROM prefix_course AS c
   WHERE c.id = b.courseid)

WHEN b.courseid IS NULL THEN "*" END AS Context, CASE

 WHEN t.criteriatype = 1 AND t.method = 1 THEN "Activity Completion (All)"
 WHEN t.criteriatype = 1 AND t.method = 2 THEN "Activity Completion (Any)"
 WHEN t.criteriatype = 2 AND t.method = 2 THEN "Manual Award"
 WHEN t.criteriatype = 4 AND t.method = 1 THEN "Course Completion (All)"
 WHEN t.criteriatype = 4 AND t.method = 2 THEN "Course Completion (Any)"
 ELSE CONCAT ('Other: ', t.criteriatype)

END AS Criteriatype, DATE_FORMAT( FROM_UNIXTIME( d.dateissued ) , '%Y-%m-%d' ) AS dateissued, DATE_FORMAT( FROM_UNIXTIME( d.dateexpire ), '%Y-%m-%d' ) AS dateexpires, CONCAT ('<a target="_new" href="%%WWWROOT%%/badges/badge.php?hash=',d.uniquehash,'">link</a>') AS Details FROM prefix_badge_issued AS d JOIN prefix_badge AS b ON d.badgeid = b.id JOIN prefix_user AS u ON d.userid = u.id JOIN prefix_badge_criteria AS t on b.id = t.badgeid WHERE t.criteriatype <> 0 ORDER BY u.username

Please note: the FROM_UNIXTIME command is for MySQL.

All badges available in the system, with Earned count

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

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

Administrator Reports

Config changes in Export friendly form

The Administrative report Config changes is very useful but it would be nice to have it in a format that could be easily exported in one listing. Here is code to do that.

SELECT DATE_FORMAT( FROM_UNIXTIME( g.timemodified ) , '%Y-%m-%d' ) AS date, u.username AS user, g.name AS setting, CASE

WHEN g.plugin IS NULL THEN "core"
ELSE g.plugin

END AS plugin, g.value AS new_value, g.oldvalue AS original_value FROM prefix_config_log AS g JOIN prefix_user AS u ON g.userid = u.id ORDER BY date DESC

Cohorts by user

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


Courses created And Active courses by Year

Active courses is counting course that have at least one Hit, And "Active_MoreThan100Hits" counts courses that have at least 100 Hits SELECT

YEAR( FROM_UNIXTIME( `timecreated` ) ) AS YEAR, COUNT( * ) AS Counter

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

,(SELECT COUNT(*) FROM ( SELECT COUNT( * ),time FROM prefix_log AS l GROUP BY course HAVING COUNT(*) > 100) AS courses_log WHERE YEAR( FROM_UNIXTIME( courses_log.`time` ) ) = YEAR( FROM_UNIXTIME( `timecreated` ) ) ) AS "Active_MoreThan100Hits"

FROM `prefix_course` GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )

Users created And Active users by Year

Active users is counting users that have at least one Hit, And "Active_MoreThan500Hits" counts users that have at least 500 Hits SELECT

YEAR( FROM_UNIXTIME( `firstaccess` ) ) AS YEAR, COUNT( * ) AS Counter

, (SELECT COUNT( DISTINCT userid ) FROM prefix_log AS l WHERE YEAR( FROM_UNIXTIME( l.`time` ) ) = YEAR( FROM_UNIXTIME( `firstaccess` ) ) ) AS "Active"

,(SELECT COUNT(*) FROM ( SELECT COUNT( * ),time FROM prefix_log AS l GROUP BY userid HAVING COUNT(*) > 500) AS users_log WHERE YEAR( FROM_UNIXTIME( users_log.`time` ) ) = YEAR( FROM_UNIXTIME( `firstaccess` ) ) ) AS "Active_MoreThan500Hits"

FROM `prefix_user` GROUP BY YEAR( FROM_UNIXTIME( `timecreated` ) )

Useful sub queries

All teachers in the course

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

See also

Configurable Reports Repository on GitHub