Projet

Général

Profil

new_mcd_v2.sql

Clément Leneveu, 20/06/2022 16:29

 
1
-- creation de la vue matérialisée des salles
2
-- DROP MATERIALIZED VIEW public."tr_serenade_salle";
3

    
4
CREATE MATERIALIZED VIEW public."tr_serenade_salle" AS
5
        SELECT id_salle AS id, nom, code FROM "ERP_Salle";
6

    
7
ALTER TABLE "tr_serenade_salle" OWNER TO cri;
8
GRANT SELECT ON "tr_serenade_salle" TO edt;
9
REFRESH MATERIALIZED VIEW "tr_serenade_salle";
10

    
11

    
12
-- creation de la vue matérialisée des utilisateurs
13
-- DROP MATERIALIZED VIEW public."tr_serenade_salle";
14

    
15
CREATE MATERIALIZED VIEW public."t_serenade_user" AS
16
        SELECT 
17
                id_user AS id , 
18
                CASE
19
                        WHEN prenomusuel IS NOT NULL AND length(prenomusuel::text) > 0 THEN initcap(prenomusuel::text)
20
                        ELSE initcap(prenom::text)
21
                END AS prenom,
22
                CASE
23
                        WHEN nomusuel IS NOT NULL AND length(nomusuel::text) > 0 THEN initcap(nomusuel::text)
24
                        ELSE initcap(nom::text)
25
                END AS nom,
26
                logindomaine AS pseudo,
27
                mailgemgrh AS mail
28
        FROM "ERP_User" 
29
        ORDER BY id_user ;
30

    
31
ALTER TABLE "tr_serenade_salle" OWNER TO cri;
32
GRANT SELECT ON "tr_serenade_salle" TO edt;
33
REFRESH MATERIALIZED VIEW "tr_serenade_salle";
34

    
35

    
36
-- creation de la vue matérialisée des type de séance (enseignement)
37
-- DROP MATERIALIZED VIEW public."tr_serenade_type_seance";
38

    
39
CREATE MATERIALIZED VIEW public."tr_serenade_type_seance" AS
40
        SELECT id_typeseance AS id, nom, code FROM "ERP_TypeSeance" ORDER BY id_typeseance ;
41

    
42
ALTER TABLE "tr_serenade_type_seance" OWNER TO cri;
43
GRANT SELECT ON "tr_serenade_type_seance" TO edt;
44
REFRESH MATERIALIZED VIEW "tr_serenade_type_seance";
45

    
46
        
47
-- creation de la vue matérialisée des type d'évènements
48
-- DROP MATERIALIZED VIEW public."tr_serenade_type_evenement";
49

    
50
CREATE MATERIALIZED VIEW public."tr_serenade_type_evenement" AS
51
        SELECT id_typeevenement AS id, nom, code FROM "ERP_TypeEvenement" ORDER BY id_typeevenement ;
52

    
53
ALTER TABLE "tr_serenade_type_evenement" OWNER TO cri;
54
GRANT SELECT ON "tr_serenade_type_evenement" TO edt;
55
REFRESH MATERIALIZED VIEW "tr_serenade_type_evenement";
56

    
57

    
58
-- creation de la vue matérialisée des type d'évènements
59
-- DROP MATERIALIZED VIEW public."tr_serenade_semestre";
60

    
61
CREATE MATERIALIZED VIEW public."tr_serenade_semestre" AS
62
        SELECT id_semestre AS id, nom , '' AS code FROM "ERP_Semestre" ORDER BY id_semestre ;
63

    
64
ALTER TABLE "tr_serenade_semestre" OWNER TO cri;
65
GRANT SELECT ON "tr_serenade_semestre" TO edt;
66
REFRESH MATERIALIZED VIEW "tr_serenade_semestre";
67

    
68

    
69

    
70
-- creation de la vue matérialisée des type d'évènements
71
-- DROP MATERIALIZED VIEW public."t_serenade_module";
72

    
73
CREATE MATERIALIZED VIEW public."t_serenade_module" AS
74
        SELECT id_module AS id, nom, code FROM "ERP_Module" ORDER BY id_module;
75

    
76
ALTER TABLE "t_serenade_module" OWNER TO cri;
77
GRANT SELECT ON "t_serenade_module" TO edt;
78
REFRESH MATERIALIZED VIEW "t_serenade_module";
79

    
80
-- creation de la vue matérialisée des séances
81
-- séances avec les enseignants comme utilisateurs
82
-- DROP MATERIALIZED VIEW public."t_serenade_seance";
83

    
84
CREATE MATERIALIZED VIEW public."t_serenade_seance" AS
85
        SELECT 
86
                row_number() OVER () AS id,
87
                tab.utilisateur_id,
88
                tab.module_id,
89
                tab.semestre_id,
90
                tab.salle_id,
91
                tab.debut,
92
                tab.fin,
93
                tab.type_id,
94
                tab.number_type,
95
                tab.groupe_td,
96
                tab.enseignant
97
        FROM ( 
98
                SELECT DISTINCT 
99
                        seance.id_seance AS "id",
100
                        CASE
101
                                WHEN usrprof.id_user IS NULL THEN 0::bigint
102
                                ELSE usrprof.id_user
103
                        END AS "utilisateur_id",
104
                        salle.id_salle::text AS "salle_id",
105
                        mo.id_module AS "module_id",
106
                        es.id_semestre AS "semestre_id",
107
                        ((seance.dateseance || ' '::text) || seance.heuredeb::text) || ':00'::text AS "debut",
108
                        ((seance.dateseance || ' '::text) || seance.heurefin::text) || ':00'::text AS "fin",
109
                        CASE
110
                                WHEN usrprof.nomusuel IS NOT NULL AND length(usrprof.nomusuel::text) > 0 THEN usrprof.nomusuel::text
111
                                ELSE usrprof.nom::text || ' '::text
112
                        END ||
113
                        CASE
114
                                WHEN usrprof.prenomusuel IS NOT NULL AND length(usrprof.prenomusuel::text) > 0 THEN initcap(usrprof.prenomusuel::text)
115
                                ELSE initcap(usrprof.prenom::text)
116
                        END AS "enseignant",
117
                        typseance.id_typeseance AS "type_id",
118
                        0 AS number_type,
119
                        STRING_AGG (gpe_td.nom, '|') AS "groupe_td"
120
                   FROM "ERP_Seance" seance
121
                         LEFT JOIN "ERP_GroupeSeanceReelle" seance_relle ON seance.id_seance = seance_relle.id_seance
122
                         LEFT JOIN "ERP_InscriptionInstanceModule" iim ON seance_relle.id_instancemodule = iim.id_instancemodule
123
                         LEFT JOIN "ERP_InstanceModule" imo ON seance_relle.id_instancemodule = imo.id_instancemodule
124
                         LEFT JOIN "ERP_Module" mo ON imo.id_module = mo.id_module
125
                         LEFT JOIN "ERP_Semestre" es ON imo.id_semestre = es.id_semestre
126
                         LEFT JOIN "ERP_Etudiant" etu ON iim.id_etudiant = etu.id_etudiant
127
                         LEFT JOIN "ERP_User" usr ON usr.id_user = etu.id_user
128
                         LEFT JOIN "ERP_ProfAnime" profanim ON profanim.id_seance = seance.id_seance
129
                         LEFT JOIN "ERP_Professeur" prof ON prof.id_prof = profanim.id_prof
130
                         LEFT JOIN "ERP_User" usrprof ON prof.id_user = usrprof.id_user
131
                         LEFT JOIN "ERP_SalleSeance" salseance ON seance.id_seance = salseance.id_seance
132
                         LEFT JOIN "ERP_Salle" salle ON salseance.id_salle = salle.id_salle
133
                         LEFT JOIN "ERP_TypeSeance" typseance ON seance.id_typeseance = typseance.id_typeseance
134
                         LEFT JOIN "ERP_InstanceGroupeTDModule" igpe_td_mo ON imo.id_instancemodule = igpe_td_mo.id_instancemodule AND iim.id_instancegroupetd = igpe_td_mo.id_instancegroupetd
135
                         LEFT JOIN "ERP_InstanceGroupeTD" igpe_td ON igpe_td_mo.id_instancegroupetd = igpe_td.id_instancegroupetd
136
                         LEFT JOIN "ERP_GroupeTd" gpe_td ON igpe_td.id_groupetd = gpe_td.id_groupetd
137
                  WHERE seance.dateseance <= (now() + '6 mons'::interval) AND seance.dateseance >= (now() - '6 mons'::interval)
138
                  GROUP BY seance.id_seance, usrprof.id_user, salle.id_salle, mo.id_module, es.id_semestre, seance.dateseance, seance.heuredeb, seance.heurefin, usrprof.nomusuel, usrprof.nom, usrprof.prenomusuel, usrprof.prenom, typseance.id_typeseance 
139
                --;
140
                UNION ALL
141
                -- séances avec les étudiants comme utilisateurs
142
                SELECT DISTINCT 
143
                        seance.id_seance AS "id",
144
                        CASE
145
                                WHEN usr.id_user IS NULL THEN 0::bigint
146
                                ELSE usr.id_user
147
                        END AS "utilisateur_id",
148
                        salle.id_salle::text AS "salle_id",
149
                        mo.id_module AS "module_id",
150
                        es.id_semestre AS "semestre_id",
151
                        ((seance.dateseance || ' '::text) || seance.heuredeb::text) || ':00'::text AS "debut",
152
                        ((seance.dateseance || ' '::text) || seance.heurefin::text) || ':00'::text AS "fin",
153
                        STRING_AGG (CASE
154
                                WHEN usrprof.nomusuel IS NOT NULL AND length(usrprof.nomusuel::text) > 0 THEN initcap(usrprof.nomusuel::text)
155
                                ELSE initcap(usrprof.nom::text) || ' '::text
156
                        END ||
157
                        CASE
158
                                WHEN usrprof.prenomusuel IS NOT NULL AND length(usrprof.prenomusuel::text) > 0 THEN initcap(usrprof.prenomusuel::text)
159
                                ELSE initcap(usrprof.prenom::text)
160
                        END, '|') AS "enseignant",
161
                        typseance.id_typeseance AS "type_id",
162
                        0 AS number_type,
163
                        gpe_td.nom AS "groupe_td"
164
                FROM "ERP_Seance" seance
165
                        LEFT JOIN "ERP_GroupeSeanceReelle" seance_relle ON seance.id_seance = seance_relle.id_seance
166
                        LEFT JOIN "ERP_InscriptionInstanceModule" iim ON seance_relle.id_instancemodule = iim.id_instancemodule
167
                        LEFT JOIN "ERP_InstanceModule" imo ON iim.id_instancemodule = imo.id_instancemodule
168
                        LEFT JOIN "ERP_Semestre" es ON imo.id_semestre = es.id_semestre
169
                        LEFT JOIN "ERP_Module" mo ON imo.id_module = mo.id_module
170
                        LEFT JOIN "ERP_Etudiant" etu ON iim.id_etudiant = etu.id_etudiant
171
                        LEFT JOIN "ERP_User" usr ON usr.id_user = etu.id_user
172
                        LEFT JOIN "ERP_ProfAnime" profanim ON profanim.id_seance = seance.id_seance
173
                        LEFT JOIN "ERP_Professeur" prof ON prof.id_prof = profanim.id_prof
174
                        LEFT JOIN "ERP_User" usrprof ON prof.id_user = usrprof.id_user
175
                        LEFT JOIN "ERP_SalleSeance" salseance ON seance.id_seance = salseance.id_seance
176
                        LEFT JOIN "ERP_Salle" salle ON salseance.id_salle = salle.id_salle
177
                        LEFT JOIN "ERP_TypeSeance" typseance ON seance.id_typeseance = typseance.id_typeseance
178
                        LEFT JOIN "ERP_InstanceGroupeTDModule" igpe_td_mo ON imo.id_instancemodule = igpe_td_mo.id_instancemodule AND iim.id_instancegroupetd = igpe_td_mo.id_instancegroupetd
179
                        LEFT JOIN "ERP_InstanceGroupeTD" igpe_td ON igpe_td_mo.id_instancegroupetd = igpe_td.id_instancegroupetd
180
                        LEFT JOIN "ERP_GroupeTd" gpe_td ON igpe_td.id_groupetd = gpe_td.id_groupetd
181
                WHERE igpe_td.id_instancegroupetd = seance_relle.id_instancegroupetd AND seance.dateseance <= (now() + '6 mons'::interval) AND seance.dateseance >= (now() - '6 mons'::interval)
182
                GROUP BY seance.id_seance, usr.id_user, salle.id_salle, mo.id_module, es.id_semestre, seance.dateseance, seance.heuredeb, seance.heurefin, typseance.id_typeseance, gpe_td.nom 
183
                --;
184
                UNION ALL
185
                -- séances avec les étudiants comme utilisateurs
186
                -- table des modules bizarres
187
                SELECT DISTINCT 
188
                        seance.id_seance AS "id",
189
                        CASE
190
                                WHEN usr.id_user IS NULL THEN 0::bigint
191
                                ELSE usr.id_user
192
                        END AS "utilisateur_id",
193
                        salle.id_salle::text AS "salle_id",
194
                        mo.id_module AS "module_id",
195
                        es.id_semestre AS "semestre_id",
196
                        ((seance.dateseance || ' '::text) || seance.heuredeb::text) || ':00'::text AS "debut",
197
                        ((seance.dateseance || ' '::text) || seance.heurefin::text) || ':00'::text AS "fin",
198
                        STRING_AGG (CASE
199
                                WHEN usrprof.nomusuel IS NOT NULL AND length(usrprof.nomusuel::text) > 0 THEN initcap(usrprof.nomusuel::text)
200
                                ELSE initcap(usrprof.nom::text) || ' '::text
201
                        END ||
202
                        CASE
203
                                WHEN usrprof.prenomusuel IS NOT NULL AND length(usrprof.prenomusuel::text) > 0 THEN initcap(usrprof.prenomusuel::text)
204
                                ELSE initcap(usrprof.prenom::text)
205
                        END, '|') AS "enseignant",
206
                        typseance.id_typeseance AS "type_id",
207
                        0 AS number_type,
208
                        gpe_td.nom AS "groupe_td"
209
                FROM "ERP_Seance" seance
210
                        LEFT JOIN "ERP_GroupeSeanceReelle" seance_relle ON seance.id_seance = seance_relle.id_seance
211
                        LEFT JOIN "ERP_InscriptionInstanceModule" iim ON seance_relle.id_instancemodule = iim.id_instancemodule
212
                        JOIN "ERP_GPCOM_IIM" gp_comp ON iim.id_inscriptioninstancemodule = gp_comp.id_inscriptioninstancemodule
213
                        LEFT JOIN "ERP_InstanceModule" imo ON iim.id_instancemodule = imo.id_instancemodule
214
                        LEFT JOIN "ERP_Semestre" es ON imo.id_semestre = es.id_semestre
215
                        LEFT JOIN "ERP_Module" mo ON imo.id_module = mo.id_module
216
                        LEFT JOIN "ERP_Etudiant" etu ON iim.id_etudiant = etu.id_etudiant
217
                        LEFT JOIN "ERP_User" usr ON usr.id_user = etu.id_user
218
                        LEFT JOIN "ERP_ProfAnime" profanim ON profanim.id_seance = seance.id_seance
219
                        LEFT JOIN "ERP_Professeur" prof ON prof.id_prof = profanim.id_prof
220
                        LEFT JOIN "ERP_User" usrprof ON prof.id_user = usrprof.id_user
221
                        LEFT JOIN "ERP_SalleSeance" salseance ON seance.id_seance = salseance.id_seance
222
                        LEFT JOIN "ERP_Salle" salle ON salseance.id_salle = salle.id_salle
223
                        LEFT JOIN "ERP_TypeSeance" typseance ON seance.id_typeseance = typseance.id_typeseance
224
                        LEFT JOIN "ERP_InstanceGroupeTDModule" igpe_td_mo ON imo.id_instancemodule = igpe_td_mo.id_instancemodule AND gp_comp.id_instancegroupetd = igpe_td_mo.id_instancegroupetd
225
                        LEFT JOIN "ERP_InstanceGroupeTD" igpe_td ON igpe_td_mo.id_instancegroupetd = igpe_td.id_instancegroupetd
226
                        LEFT JOIN "ERP_GroupeTd" gpe_td ON igpe_td.id_groupetd = gpe_td.id_groupetd
227
                WHERE igpe_td.id_instancegroupetd = seance_relle.id_instancegroupetd AND seance.dateseance <= (now() + '6 mons'::interval) AND seance.dateseance >= (now() - '6 mons'::interval)
228
                GROUP BY seance.id_seance, usr.id_user, salle.id_salle, mo.id_module, es.id_semestre, seance.dateseance, seance.heuredeb, seance.heurefin, typseance.id_typeseance, gpe_td.nom
229
                --;
230
                UNION ALL
231
                -- seance de type evaluations
232
                SELECT DISTINCT 
233
                        seance.id_seanceevaluation AS "id",
234
                        CASE
235
                                WHEN usr.id_user IS NULL THEN 0::bigint
236
                                ELSE usr.id_user
237
                        END AS "utilisateur_id",
238
                        salle.id_salle::text AS "salle_id",
239
                        mo.id_module AS "module_id",
240
                        es.id_semestre AS "semestre_id",
241
                        ((seance.dateseance || ' '::text) || seance.heuredeb::text) || ':00'::text AS "debut",
242
                        ((seance.dateseance || ' '::text) || seance.heurefin::text) || ':00'::text AS "fin",
243
                        ''::text AS "enseignant",
244
                        typseance.id_typeseance AS "type_id",
245
                        0 AS number_type,
246
                        gpe_td.nom AS "groupe_td"
247
                FROM "ERP_SeanceEvaluation" seance
248
                        LEFT JOIN "ERP_SalleSeanceEvaluation" evasalle ON evasalle.id_seanceevaluation = seance.id_seanceevaluation
249
                        LEFT JOIN "ERP_Salle" salle ON salle.id_salle = evasalle.id_salle
250
                        LEFT JOIN "ERP_GroupeSeanceEvaluationReelle" s_grpe_eval_re ON seance.id_seanceevaluation = s_grpe_eval_re.id_seanceevaluation
251
                        LEFT JOIN "ERP_InstanceModule" imo ON imo.id_instancemodule = s_grpe_eval_re.id_instancemodule
252
                        LEFT JOIN "ERP_Semestre" es ON imo.id_semestre = es.id_semestre
253
                        LEFT JOIN "ERP_Module" mo ON imo.id_module = mo.id_module
254
                        LEFT JOIN "ERP_InscriptionInstanceModule" iim ON imo.id_instancemodule = iim.id_instancemodule
255
                        LEFT JOIN "ERP_Etudiant" etu ON iim.id_etudiant = etu.id_etudiant
256
                        LEFT JOIN "ERP_User" usr ON usr.id_user = etu.id_user
257
                        LEFT JOIN "ERP_TypeSeance" typseance ON seance.id_typeseance = typseance.id_typeseance
258
                        LEFT JOIN "ERP_InstanceGroupeTDModule" igpe_td_mo ON imo.id_instancemodule = igpe_td_mo.id_instancemodule AND iim.id_instancegroupetd = igpe_td_mo.id_instancegroupetd
259
                        LEFT JOIN "ERP_InstanceGroupeTD" igpe_td ON igpe_td_mo.id_instancegroupetd = igpe_td.id_instancegroupetd
260
                        LEFT JOIN "ERP_GroupeTd" gpe_td ON igpe_td.id_groupetd = gpe_td.id_groupetd
261
                WHERE s_grpe_eval_re.id_instancegroupetd = iim.id_instancegroupetd AND seance.dateseance <= (now() + '6 mons'::interval) AND seance.dateseance >= (now() - '6 mons'::interval)
262
                --;
263
                UNION ALL
264
                -- séance de type evenements
265
                SELECT DISTINCT
266
                        evtsalle.id_evenement AS "id",
267
                        CASE
268
                                WHEN usr_inv.id_user IS NOT NULL THEN usr_inv.id_user
269
                                ELSE 0::bigint
270
                        END AS "utilisateur_id",
271
                        STRING_AGG (salle.id_salle::text, '|') AS "salle_id",
272
                        0 AS "module_id",
273
                        0 AS "semestre_id",
274
                        ((evt.datedebutevenement || ' '::text) || evt.heuredebut::text) || ':00'::text AS "debut",
275
                        ((evt.datefinevenement || ' '::text) || evt.heurefin::text) || ':00'::text AS "fin",
276
                        ''::text AS "enseignant",
277
                        1 AS number_type,
278
                        evttype.id_typeevenement AS "type_id",
279
                        ''::text AS "groupe_td"
280
                FROM "ERP_Evenement" evt
281
                        LEFT JOIN "ERP_SalleEvenement" evtsalle ON evtsalle.id_evenement = evt.id_evenement
282
                        LEFT JOIN "ERP_TypeEvenement" evttype ON evttype.id_typeevenement = evt.id_typeevenement
283
                        LEFT JOIN "ERP_Salle" salle ON evtsalle.id_salle = salle.id_salle
284
                        LEFT JOIN "ERP_InviteEvenement" inv ON inv.id_evenement = evt.id_evenement
285
                        LEFT JOIN "ERP_User" usr_inv ON inv.id_user = usr_inv.id_user
286
                WHERE evt.datedebutevenement <= (now() + '6 mons'::interval) AND evt.datedebutevenement >= (now() - '6 mons'::interval)
287
                GROUP BY evtsalle.id_evenement, usr_inv.id_user, evt.datedebutevenement, evt.heuredebut, evt.datefinevenement, evt.heurefin, evttype.id_typeevenement
288
        ) AS tab;
289

    
290
ALTER TABLE "t_serenade_seance" OWNER TO cri;
291
GRANT SELECT ON "t_serenade_seance" TO edt;
292
REFRESH MATERIALIZED VIEW "t_serenade_seance";