@@ -82,78 +82,72 @@ private function find_orphaned_questions(): array {
8282 FROM_UNIXTIME(q.timemodified) as modified,
8383 CASE
8484 WHEN q.qtype = 'ddimageortext' THEN
85- CASE WHEN EXISTS(SELECT 1 FROM {{ qtype_ddimageortext} } WHERE questionid = q.id)
85+ CASE WHEN EXISTS(SELECT 1 FROM {qtype_ddimageortext} WHERE questionid = q.id)
8686 THEN 'EXISTS' ELSE 'MISSING' END
8787 WHEN q.qtype = 'gapselect' THEN
88- CASE WHEN EXISTS(SELECT 1 FROM {{ question_gapselect} } WHERE questionid = q.id)
88+ CASE WHEN EXISTS(SELECT 1 FROM {question_gapselect} WHERE questionid = q.id)
8989 THEN 'EXISTS' ELSE 'MISSING' END
9090 WHEN q.qtype = 'ddmarker' THEN
91- CASE WHEN EXISTS(SELECT 1 FROM {{ qtype_ddmarker} } WHERE questionid = q.id)
91+ CASE WHEN EXISTS(SELECT 1 FROM {qtype_ddmarker} WHERE questionid = q.id)
9292 THEN 'EXISTS' ELSE 'MISSING' END
9393 WHEN q.qtype = 'ddwtos' THEN
94- CASE WHEN EXISTS(SELECT 1 FROM {{ question_ddwtos} } WHERE questionid = q.id)
94+ CASE WHEN EXISTS(SELECT 1 FROM {question_ddwtos} WHERE questionid = q.id)
9595 THEN 'EXISTS' ELSE 'MISSING' END
9696 WHEN q.qtype = 'essay' THEN
97- CASE WHEN EXISTS(SELECT 1 FROM {{ qtype_essay_options} } WHERE questionid = q.id)
97+ CASE WHEN EXISTS(SELECT 1 FROM {qtype_essay_options} WHERE questionid = q.id)
9898 THEN 'EXISTS' ELSE 'MISSING' END
9999 ELSE 'UNKNOWN_TYPE'
100100 END as qtype_record_status,
101101
102- -- 1. Question Bank Usage: Questions referenced in quiz slots
103102 (SELECT COUNT(DISTINCT qz.id)
104- FROM {{ quiz_slots} } slot
105- JOIN {{ quiz} } qz ON qz.id = slot.quizid
106- JOIN {{ question_references} } qr ON qr.itemid = slot.id
107- JOIN {{ question_bank_entries} } qbe2 ON qbe2.id = qr.questionbankentryid
108- JOIN {{ question_versions} } qv2 ON qv2.questionbankentryid = qbe2.id
103+ FROM {quiz_slots} slot
104+ JOIN {quiz} qz ON qz.id = slot.quizid
105+ JOIN {question_references} qr ON qr.itemid = slot.id
106+ JOIN {question_bank_entries} qbe2 ON qbe2.id = qr.questionbankentryid
107+ JOIN {question_versions} qv2 ON qv2.questionbankentryid = qbe2.id
109108 WHERE qv2.questionbankentryid = qbe.id
110109 AND qr.component = 'mod_quiz'
111110 AND qr.questionarea = 'slot') as usage_quiz_slots,
112111
113- -- 2. Question Attempt Usage: Questions that have been attempted (even if not in current quiz)
114112 (SELECT COUNT(DISTINCT qz.id)
115- FROM {{ quiz} } qz
116- JOIN {{ quiz_attempts} } qa ON qa.quiz = qz.id
117- JOIN {{ question_usages} } qu ON qu.id = qa.uniqueid
118- JOIN {{ question_attempts} } qatt ON qatt.questionusageid = qu.id
119- JOIN {{ question_versions} } qv2 ON qv2.questionid = qatt.questionid
120- JOIN {{ question_versions} } qv3 ON qv2.questionbankentryid = qv3.questionbankentryid
113+ FROM {quiz} qz
114+ JOIN {quiz_attempts} qa ON qa.quiz = qz.id
115+ JOIN {question_usages} qu ON qu.id = qa.uniqueid
116+ JOIN {question_attempts} qatt ON qatt.questionusageid = qu.id
117+ JOIN {question_versions} qv2 ON qv2.questionid = qatt.questionid
118+ JOIN {question_versions} qv3 ON qv2.questionbankentryid = qv3.questionbankentryid
121119 WHERE qa.preview = 0
122120 AND qv3.questionbankentryid = qbe.id) as usage_quiz_attempts,
123121
124- -- Combined usage count (matches Moodle's Usage column - unique quizzes)
125122 (SELECT COUNT(DISTINCT quizid) FROM (
126- -- Question Bank Usage
127123 SELECT qz.id as quizid
128- FROM {{ quiz_slots} } slot
129- JOIN {{ quiz} } qz ON qz.id = slot.quizid
130- JOIN {{ question_references} } qr ON qr.itemid = slot.id
131- JOIN {{ question_bank_entries} } qbe2 ON qbe2.id = qr.questionbankentryid
132- JOIN {{ question_versions} } qv2 ON qv2.questionbankentryid = qbe2.id
124+ FROM {quiz_slots} slot
125+ JOIN {quiz} qz ON qz.id = slot.quizid
126+ JOIN {question_references} qr ON qr.itemid = slot.id
127+ JOIN {question_bank_entries} qbe2 ON qbe2.id = qr.questionbankentryid
128+ JOIN {question_versions} qv2 ON qv2.questionbankentryid = qbe2.id
133129 WHERE qv2.questionbankentryid = qbe.id
134130 AND qr.component = 'mod_quiz'
135131 AND qr.questionarea = 'slot'
136132
137133 UNION
138134
139- -- Question Attempt Usage
140135 SELECT qz.id as quizid
141- FROM {{ quiz} } qz
142- JOIN {{ quiz_attempts} } qa ON qa.quiz = qz.id
143- JOIN {{ question_usages} } qu ON qu.id = qa.uniqueid
144- JOIN {{ question_attempts} } qatt ON qatt.questionusageid = qu.id
145- JOIN {{ question_versions} } qv2 ON qv2.questionid = qatt.questionid
146- JOIN {{ question_versions} } qv3 ON qv2.questionbankentryid = qv3.questionbankentryid
136+ FROM {quiz} qz
137+ JOIN {quiz_attempts} qa ON qa.quiz = qz.id
138+ JOIN {question_usages} qu ON qu.id = qa.uniqueid
139+ JOIN {question_attempts} qatt ON qatt.questionusageid = qu.id
140+ JOIN {question_versions} qv2 ON qv2.questionid = qatt.questionid
141+ JOIN {question_versions} qv3 ON qv2.questionbankentryid = qv3.questionbankentryid
147142 WHERE qa.preview = 0
148143 AND qv3.questionbankentryid = qbe.id
149144 ) as usage_combined) as usage_count,
150145
151- -- Category and course info
152146 qc.id as categoryid,
153147 qc.name as categoryname,
154148 CASE ctx.contextlevel
155- WHEN 50 THEN CONCAT('Course: ', (SELECT shortname FROM {{ course} } WHERE id = ctx.instanceid))
156- WHEN 40 THEN CONCAT('Category: ', (SELECT name FROM {{ course_categories} } WHERE id = ctx.instanceid))
149+ WHEN 50 THEN CONCAT('Course: ', (SELECT shortname FROM {course} WHERE id = ctx.instanceid))
150+ WHEN 40 THEN CONCAT('Category: ', (SELECT name FROM {course_categories} WHERE id = ctx.instanceid))
157151 WHEN 10 THEN 'System'
158152 ELSE 'Other'
159153 END as location,
@@ -162,32 +156,67 @@ private function find_orphaned_questions(): array {
162156 ELSE NULL
163157 END as courseid,
164158
165- -- Summary: Is it safe to delete? (Usage count = 0 means not used anywhere)
166159 CASE
167- WHEN usage_count = 0 OR usage_count IS NULL THEN 'SAFE_TO_DELETE'
160+ WHEN (SELECT COUNT(DISTINCT quizid) FROM (
161+ SELECT qz.id as quizid
162+ FROM {quiz_slots} slot
163+ JOIN {quiz} qz ON qz.id = slot.quizid
164+ JOIN {question_references} qr ON qr.itemid = slot.id
165+ JOIN {question_bank_entries} qbe2 ON qbe2.id = qr.questionbankentryid
166+ JOIN {question_versions} qv2 ON qv2.questionbankentryid = qbe2.id
167+ WHERE qv2.questionbankentryid = qbe.id
168+ AND qr.component = 'mod_quiz'
169+ AND qr.questionarea = 'slot'
170+ UNION
171+ SELECT qz.id as quizid
172+ FROM {quiz} qz
173+ JOIN {quiz_attempts} qa ON qa.quiz = qz.id
174+ JOIN {question_usages} qu ON qu.id = qa.uniqueid
175+ JOIN {question_attempts} qatt ON qatt.questionusageid = qu.id
176+ JOIN {question_versions} qv2 ON qv2.questionid = qatt.questionid
177+ JOIN {question_versions} qv3 ON qv2.questionbankentryid = qv3.questionbankentryid
178+ WHERE qa.preview = 0
179+ AND qv3.questionbankentryid = qbe.id
180+ ) as usage_combined) = 0 THEN 'SAFE_TO_DELETE'
168181 ELSE 'IN_USE'
169182 END as deletion_status
170183
171- FROM {{ question} } q
172- JOIN {{ question_versions} } qv ON qv.questionid = q.id
173- JOIN {{ question_bank_entries} } qbe ON qbe.id = qv.questionbankentryid
174- JOIN {{ question_categories} } qc ON qc.id = qbe.questioncategoryid
175- JOIN {{ context} } ctx ON ctx.id = qc.contextid
184+ FROM {question} q
185+ JOIN {question_versions} qv ON qv.questionid = q.id
186+ JOIN {question_bank_entries} qbe ON qbe.id = qv.questionbankentryid
187+ JOIN {question_categories} qc ON qc.id = qbe.questioncategoryid
188+ JOIN {context} ctx ON ctx.id = qc.contextid
176189WHERE
177- -- Only question types that use MUST_EXIST and will throw error
178190 q.qtype IN ('ddimageortext', 'gapselect', 'ddmarker', 'ddwtos', 'essay')
179- -- Missing qtype record (orphaned)
180191 AND (
181- (q.qtype = 'ddimageortext' AND NOT EXISTS(SELECT 1 FROM {{ qtype_ddimageortext} } WHERE questionid = q.id))
182- OR (q.qtype = 'gapselect' AND NOT EXISTS(SELECT 1 FROM {{ question_gapselect} } WHERE questionid = q.id))
183- OR (q.qtype = 'ddmarker' AND NOT EXISTS(SELECT 1 FROM {{ qtype_ddmarker} } WHERE questionid = q.id))
184- OR (q.qtype = 'ddwtos' AND NOT EXISTS(SELECT 1 FROM {{ question_ddwtos} } WHERE questionid = q.id))
185- OR (q.qtype = 'essay' AND NOT EXISTS(SELECT 1 FROM {{ qtype_essay_options} } WHERE questionid = q.id))
192+ (q.qtype = 'ddimageortext' AND NOT EXISTS(SELECT 1 FROM {qtype_ddimageortext} WHERE questionid = q.id))
193+ OR (q.qtype = 'gapselect' AND NOT EXISTS(SELECT 1 FROM {question_gapselect} WHERE questionid = q.id))
194+ OR (q.qtype = 'ddmarker' AND NOT EXISTS(SELECT 1 FROM {qtype_ddmarker} WHERE questionid = q.id))
195+ OR (q.qtype = 'ddwtos' AND NOT EXISTS(SELECT 1 FROM {question_ddwtos} WHERE questionid = q.id))
196+ OR (q.qtype = 'essay' AND NOT EXISTS(SELECT 1 FROM {qtype_essay_options} WHERE questionid = q.id))
186197 )
187- ) as subquery
188- WHERE usage_count = 0 OR usage_count IS NULL
189- ORDER BY qtype, questionid;
190- " ;
198+ AND (SELECT COUNT(DISTINCT quizid) FROM (
199+ SELECT qz.id as quizid
200+ FROM {quiz_slots} slot
201+ JOIN {quiz} qz ON qz.id = slot.quizid
202+ JOIN {question_references} qr ON qr.itemid = slot.id
203+ JOIN {question_bank_entries} qbe2 ON qbe2.id = qr.questionbankentryid
204+ JOIN {question_versions} qv2 ON qv2.questionbankentryid = qbe2.id
205+ WHERE qv2.questionbankentryid = qbe.id
206+ AND qr.component = 'mod_quiz'
207+ AND qr.questionarea = 'slot'
208+ UNION
209+ SELECT qz.id as quizid
210+ FROM {quiz} qz
211+ JOIN {quiz_attempts} qa ON qa.quiz = qz.id
212+ JOIN {question_usages} qu ON qu.id = qa.uniqueid
213+ JOIN {question_attempts} qatt ON qatt.questionusageid = qu.id
214+ JOIN {question_versions} qv2 ON qv2.questionid = qatt.questionid
215+ JOIN {question_versions} qv3 ON qv2.questionbankentryid = qv3.questionbankentryid
216+ WHERE qa.preview = 0
217+ AND qv3.questionbankentryid = qbe.id
218+ ) as usage_combined) = 0
219+ ORDER BY q.qtype, q.id; " ;
191220
192221 try {
193222 $ questions = $ DB ->get_records_sql ($ sql );
0 commit comments