-
Notifications
You must be signed in to change notification settings - Fork 9
/
Copy pathlearopsdev.session.sql
361 lines (317 loc) · 12.2 KB
/
learopsdev.session.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
-- View all tables
SELECT * from pg_catalog.pg_tables;
SELECT * from "auth_user" order by id desc;
SELECT * from "socialaccount_socialaccount" order by id desc;
SELECT * from "authtoken_token" where user_id = 470;
SELECT * from "LearningAPI_nssuser" where user_id = 470;
SELECT * from "LearningAPI_nssusercohort" where nss_user_id = 468;
SELECT * from "LearningAPI_studentteam";
SELECT * FROM "LearningAPI_cohort";
DROP FUNCTION IF EXISTS get_student_details(INT);
DROP FUNCTION IF EXISTS get_project_average_start_delay(INT);
DROP FUNCTION IF EXISTS get_cohort_student_data(INT);
SELECT * from get_cohort_student_data(29);
CREATE FUNCTION get_cohort_student_data(selected_cohort_id INT)
RETURNS TABLE (
user_id INT,
student_name TEXT,
score INT,
github_handle TEXT,
extra_data TEXT,
current_cohort TEXT,
current_cohort_id INT,
assessment_status_id INT,
assessment_url TEXT,
current_project_id INT,
current_project_index INT,
current_project_name TEXT,
current_book_id INT,
current_book_index INT,
current_book_name TEXT,
student_notes TEXT,
student_tags TEXT,
capstone_proposals TEXT,
project_duration DOUBLE PRECISION
) AS $$
BEGIN
RETURN QUERY
SELECT
nu.id::int AS user_id,
au."first_name" || ' ' || au."last_name" AS student_name,
COALESCE(lr.total_score, 0)::int AS score,
nu.github_handle::text,
social.extra_data::text,
c.name::text AS current_cohort,
c.id::int AS current_cohort_id,
COALESCE(sa.status_id::int, 0) AS assessment_status_id,
sa.url::text AS assessment_url,
sp.project_id::int AS current_project_id,
p.index::int AS current_project_index,
p.name::text AS current_project_name,
b.id::int AS current_book_id,
b.index::int AS current_book_index,
b.name::text AS current_book_name,
COALESCE(
json_agg(
json_build_object(
'note_id', sn.id,
'note', sn.note,
'created_on', sn.created_on,
'note_type_id', sn.note_type_id,
'note_label', COALESCE(snt.label, '')
)
)
)::text AS student_notes,
COALESCE(
(
SELECT json_agg(
json_build_object(
'id', st."id",
'tag', t."name"
)
)
FROM "LearningAPI_studenttag" st
LEFT JOIN "LearningAPI_tag" t ON t."id" = st."tag_id"
WHERE st."student_id" = nu.id
)
, '[]')::text AS student_tags,
COALESCE(
(
SELECT json_agg(
json_build_object(
'id', c."id",
'status', ps.status,
'current_status_id', ps.id,
'proposal_url', c."proposal_url",
'created_on', tl.date,
'course_name', cr.name
)
)
FROM "LearningAPI_capstone" c
LEFT JOIN (
SELECT DISTINCT ON (
ct.capstone_id, c.course_id
) *
FROM "LearningAPI_capstonetimeline" ct
JOIN "LearningAPI_capstone" c ON c.id = ct.capstone_id
ORDER BY
c.course_id,
ct.capstone_id,
date desc
) tl ON tl.capstone_id = c.id
LEFT JOIN "LearningAPI_proposalstatus" ps ON ps."id" = tl.status_id
LEFT JOIN "LearningAPI_course" cr ON c.course_id = cr.id
WHERE c."student_id" = nu.id
), '[]'
)::text AS capstone_proposals,
CASE
WHEN sa.id IS NOT NULL AND sa.assessment_id = la.id THEN
(
EXTRACT(YEAR FROM AGE(NOW(), sa.date_created)) * 365 +
EXTRACT(MONTH FROM AGE(NOW(), sa.date_created)) * 30 +
EXTRACT(DAY FROM AGE(NOW(), sa.date_created))
)::double precision
ELSE
(
EXTRACT(YEAR FROM AGE(NOW(), sp.date_created)) * 365 +
EXTRACT(MONTH FROM AGE(NOW(), sp.date_created)) * 30 +
EXTRACT(DAY FROM AGE(NOW(), sp.date_created))
)::double precision
END AS project_duration
FROM "LearningAPI_nssuser" nu
JOIN "auth_user" au ON au."id" = nu."user_id"
LEFT JOIN "LearningAPI_nssusercohort" nc ON nc."nss_user_id" = nu."id"
LEFT JOIN "LearningAPI_cohort" c ON c."id" = nc."cohort_id"
LEFT JOIN "LearningAPI_studentnote" sn ON sn."student_id" = nu."id"
LEFT JOIN "LearningAPI_studentnotetype" snt ON sn."note_type_id" = snt."id"
LEFT JOIN "LearningAPI_studenttag" stg ON stg."student_id" = nu."id"
LEFT JOIN "LearningAPI_tag" tag ON stg.tag_id = tag.id
LEFT JOIN "socialaccount_socialaccount" social ON social.user_id = nu.user_id
LEFT JOIN "LearningAPI_capstone" sc ON sc.student_id = nu."id"
LEFT JOIN "LearningAPI_studentproject" sp
ON sp."student_id" = nu."id"
AND sp.id = (
SELECT id
FROM "LearningAPI_studentproject"
WHERE "student_id" = nu."id"
ORDER BY id DESC
LIMIT 1
)
LEFT JOIN "LearningAPI_project" p ON p."id" = sp."project_id"
LEFT JOIN "LearningAPI_book" b ON b."id" = p."book_id"
LEFT JOIN "LearningAPI_assessment" la
ON b.id = la.book_id
LEFT JOIN "LearningAPI_studentassessment" sa
ON sa."student_id" = nu."id"
AND sa."assessment_id" = la."id"
AND sa."date_created" = (
SELECT MAX("date_created")
FROM "LearningAPI_studentassessment"
WHERE "student_id" = nu."id"
AND "assessment_id" = la."id"
)
AND sa.assessment_id = la.id
LEFT JOIN (
SELECT lr."student_id", SUM(lw."weight") AS total_score
FROM "LearningAPI_learningrecord" lr
JOIN "LearningAPI_learningweight" lw ON lw."id" = lr."weight_id"
WHERE lr."achieved" = true
GROUP BY lr."student_id"
) lr ON lr."student_id" = nu."id"
WHERE nc."cohort_id" = selected_cohort_id
AND au.is_active = TRUE
AND au.is_staff = FALSE
GROUP BY nu.id, nu.github_handle, social.extra_data, sa.url,
student_name, current_cohort, current_cohort_id, assessment_status_id,
current_project_id, current_project_index, current_project_name,
project_duration, current_book_id, current_book_index, current_book_name,
score
ORDER BY b.index ASC,
p.index ASC;
END;
$$ LANGUAGE plpgsql;
SELECT
nu.id::int AS user_id,
au."first_name" || ' ' || au."last_name" AS student_name,
COALESCE(lr.total_score, 0)::int AS score,
nu.github_handle::text,
social.extra_data::text,
c.name::text AS current_cohort,
c.id::int AS current_cohort_id,
COALESCE(sa.status_id::int, 0) AS assessment_status_id,
sa.url::text AS assessment_url,
sp.project_id::int AS current_project_id,
p.index::int AS current_project_index,
p.name::text AS current_project_name,
b.id::int AS current_book_id,
b.index::int AS current_book_index,
b.name::text AS current_book_name,
COALESCE(
json_agg(
json_build_object(
'note_id', sn.id,
'note', sn.note,
'created_on', sn.created_on,
'note_type_id', sn.note_type_id,
'note_label', COALESCE(snt.label, '')
)
)
)::text AS student_notes,
COALESCE(
(
SELECT json_agg(
json_build_object(
'id', st."id",
'tag', t."name"
)
)
FROM "LearningAPI_studenttag" st
LEFT JOIN "LearningAPI_tag" t ON t."id" = st."tag_id"
WHERE st."student_id" = nu.id
)
, '[]')::text AS student_tags,
COALESCE(
(
SELECT json_agg(
json_build_object(
'id', c."id",
'status', ps.status,
'current_status_id', ps.id,
'proposal_url', c."proposal_url",
'created_on', tl.date,
'course_name', cr.name
)
)
FROM "LearningAPI_capstone" c
LEFT JOIN (
SELECT DISTINCT ON (
ct.capstone_id, c.course_id
) *
FROM "LearningAPI_capstonetimeline" ct
JOIN "LearningAPI_capstone" c ON c.id = ct.capstone_id
ORDER BY
c.course_id,
ct.capstone_id,
date desc
) tl ON tl.capstone_id = c.id
LEFT JOIN "LearningAPI_proposalstatus" ps ON ps."id" = tl.status_id
LEFT JOIN "LearningAPI_course" cr ON c.course_id = cr.id
WHERE c."student_id" = nu.id
), '[]'
)::text AS capstone_proposals,
CASE
WHEN sa.id IS NOT NULL AND sa.assessment_id = la.id THEN
EXTRACT(YEAR FROM AGE(NOW(), sa.date_created)) * 365 +
EXTRACT(MONTH FROM AGE(NOW(), sa.date_created)) * 30 +
EXTRACT(DAY FROM AGE(NOW(), sa.date_created))::double precision
ELSE
EXTRACT(YEAR FROM AGE(NOW(), sp.date_created)) * 365 +
EXTRACT(MONTH FROM AGE(NOW(), sp.date_created)) * 30 +
EXTRACT(DAY FROM AGE(NOW(), sp.date_created))::double precision
END AS project_duration
FROM "LearningAPI_nssuser" nu
JOIN "auth_user" au ON au."id" = nu."user_id"
LEFT JOIN "LearningAPI_nssusercohort" nc ON nc."nss_user_id" = nu."id"
LEFT JOIN "LearningAPI_cohort" c ON c."id" = nc."cohort_id"
LEFT JOIN "LearningAPI_studentnote" sn ON sn."student_id" = nu."id"
LEFT JOIN "LearningAPI_studentnotetype" snt ON sn."note_type_id" = snt."id"
LEFT JOIN "LearningAPI_studenttag" stg ON stg."student_id" = nu."id"
LEFT JOIN "LearningAPI_tag" tag ON stg.tag_id = tag.id
LEFT JOIN "socialaccount_socialaccount" social ON social.user_id = nu.user_id
LEFT JOIN "LearningAPI_capstone" sc ON sc.student_id = nu."id"
LEFT JOIN "LearningAPI_studentproject" sp
ON sp."student_id" = nu."id"
AND sp.id = (
SELECT id
FROM "LearningAPI_studentproject"
WHERE "student_id" = nu."id"
ORDER BY id DESC
LIMIT 1
)
LEFT JOIN "LearningAPI_project" p ON p."id" = sp."project_id"
LEFT JOIN "LearningAPI_book" b ON b."id" = p."book_id"
LEFT JOIN "LearningAPI_assessment" la
ON b.id = la.book_id
LEFT JOIN "LearningAPI_studentassessment" sa
ON sa."student_id" = nu."id"
AND sa."assessment_id" = la."id"
AND sa."date_created" = (
SELECT MAX("date_created")
FROM "LearningAPI_studentassessment"
WHERE "student_id" = nu."id"
AND "assessment_id" = la."id"
)
AND sa.assessment_id = la.id
LEFT JOIN (
SELECT lr."student_id", SUM(lw."weight") AS total_score
FROM "LearningAPI_learningrecord" lr
JOIN "LearningAPI_learningweight" lw ON lw."id" = lr."weight_id"
WHERE lr."achieved" = true
GROUP BY lr."student_id"
) lr ON lr."student_id" = nu."id"
WHERE nc."cohort_id" = 29
AND au.is_active = TRUE
AND au.is_staff = FALSE
GROUP BY nu.id, nu.github_handle, social.extra_data, sa.url,
student_name, current_cohort, current_cohort_id, assessment_status_id,
current_project_id, current_project_index, current_project_name,
project_duration, current_book_id, current_book_index, current_book_name,
score
ORDER BY b.index ASC,
p.index ASC;
SELECT *
FROM "LearningAPI_learningrecordentry" lr
order by id desc;
SELECT
sum(lw.weight) as score,
au."first_name" || ' ' || au."last_name" AS student_name
from "LearningAPI_learningrecord" lr
join "LearningAPI_learningweight" lw on lr.weight_id = lw.id
join "LearningAPI_nssuser" nu on nu.id = lr.student_id
join "auth_user" au on au.id = nu.user_id
join "LearningAPI_nssusercohort" uc on uc.nss_user_id = nu.id
join "LearningAPI_cohort" c on uc.cohort_id = c.id
where c.id = 29
group by student_name
;
SELECT * from "LearningAPI_studentnote" order by id desc;