body.sql 91.4 KB
Newer Older
Laurent Lécluse's avatar
Laurent Lécluse committed
1
CREATE OR REPLACE PACKAGE BODY "UNICAEN_TBL" AS
2
3
4
  TYPE t_dems_values IS TABLE OF BOOLEAN INDEX BY VARCHAR2(80);
  TYPE t_dems_params IS TABLE OF t_dems_values INDEX BY VARCHAR2(30);
  TYPE t_dems IS TABLE OF t_dems_params INDEX BY VARCHAR2(30);
Laurent Lécluse's avatar
Laurent Lécluse committed
5

6
  dems t_dems;
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
  FUNCTION MAKE_WHERE(param VARCHAR2 DEFAULT NULL, value VARCHAR2 DEFAULT NULL,
                      alias VARCHAR2 DEFAULT NULL) RETURN VARCHAR2 IS
    res VARCHAR2(120) DEFAULT '';
  BEGIN
    IF param IS NULL THEN
      RETURN '1=1';
    END IF;
    IF alias IS NOT NULL THEN
      res := alias || '.';
    END IF;
    IF value IS NULL THEN
      RETURN res || param || ' IS NULL';
    END IF;
   RETURN res || param || ' = q''[' || value || ']''';
  END;



  FUNCTION QUERY_APPLY_PARAM(sqlQuery VARCHAR2, param VARCHAR2, value VARCHAR2) RETURN CLOB IS
    pos       NUMERIC;
    paramLen  NUMERIC;
    paramComm VARCHAR2(200);
    debComm   NUMERIC;
    endComm   NUMERIC;
    debReal   NUMERIC;
    realParam VARCHAR2(80);
    realValue VARCHAR2(120);
    q         CLOB;
  BEGIN
    q := sqlQuery;
    IF param IS NULL THEN
      RETURN q;
    END IF;

    paramlen := length(param);
    IF value IS NULL THEN
      realValue := ' IS NULL';
    ELSE
      BEGIN
        realValue := TO_NUMBER(value);
      EXCEPTION
        WHEN VALUE_ERROR THEN
          realValue := 'q''[' || value || ']''';
      END;
     realValue := '=' || realValue;
    END IF;

    LOOP
      pos := instr(q, '/*@' || param, 1, 1);
      EXIT WHEN pos = 0;
     debComm := pos - 1;
      endComm := instr(q, '*/', pos, 1);
      paramComm := substr(q, debComm, endComm - debComm);
     debReal := instr(paramComm, '=', 1, 1);
     realParam := trim(substr(paramComm, debReal + 1));
     --realParam := 'AND ' || substr(q,pos + paramLen + 4,endComm-pos - paramLen - 4);
      realParam := 'AND ' || realParam || realValue;
     q := substr(q, 1, debComm) || realParam || substr(q, endComm + 2);
    END LOOP;

    RETURN q;
  END;



  PROCEDURE CALCULER(TBL_NAME VARCHAR2) IS
  BEGIN
    ANNULER_DEMANDES(TBL_NAME);
    CALCULER(TBL_NAME, null, null);
  END;
Laurent Lécluse's avatar
Laurent Lécluse committed
80
81


82

83
84
85
86
  PROCEDURE CALCULER(TBL_NAME VARCHAR2, param VARCHAR2, value VARCHAR2) IS
    calcul_proc varchar2(30);
  BEGIN
    IF NOT UNICAEN_TBL.ACTIV_CALCULS THEN RETURN; END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
87

88
    SELECT custom_calcul_proc INTO calcul_proc FROM tbl WHERE tbl_name = CALCULER.TBL_NAME;
89

90
91
92
93
94
95
96
97
98
99
100
    UNICAEN_TBL.CALCUL_PROC_PARAM := PARAM;
    UNICAEN_TBL.CALCUL_PROC_VALUE := VALUE;
    IF calcul_proc IS NOT NULL THEN
      EXECUTE IMMEDIATE
              'BEGIN ' || calcul_proc || '(UNICAEN_TBL.CALCUL_PROC_PARAM,UNICAEN_TBL.CALCUL_PROC_VALUE); END;';
    ELSE
      EXECUTE IMMEDIATE
              'BEGIN UNICAEN_TBL.C_' || TBL_NAME ||
              '(UNICAEN_TBL.CALCUL_PROC_PARAM,UNICAEN_TBL.CALCUL_PROC_VALUE); END;';
    END IF;
  END;
101
102


103

104
105
106
107
  PROCEDURE DEMANDE_CALCUL(TBL_NAME VARCHAR2, param VARCHAR2, value VARCHAR2) IS
  BEGIN
    dems(TBL_NAME)(param)(value) := TRUE;
  END;
108
109
110



111
112
113
114
  PROCEDURE ANNULER_DEMANDES IS
  BEGIN
    dems.delete;
  END;
115
116


117

118
119
  PROCEDURE ANNULER_DEMANDES(TBL_NAME VARCHAR2) IS
  BEGIN
120
121
122
    IF dems.exists(tbl_name) THEN
      dems(tbl_name).delete;
    END IF;
123
  END;
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


  FUNCTION HAS_DEMANDES RETURN BOOLEAN IS
  BEGIN
    RETURN dems.count > 0;
  END;



  PROCEDURE CALCULER_DEMANDES IS
    d t_dems;
    tbl_name VARCHAR2(30);
    param VARCHAR2(30);
    value VARCHAR2(80);
  BEGIN
    d := dems;
    dems.delete;

    tbl_name := d.FIRST;
    LOOP EXIT WHEN tbl_name IS NULL;
      param := d(tbl_name).FIRST;
      LOOP EXIT WHEN param IS NULL;
        value := d(tbl_name)(param).FIRST;
        LOOP EXIT WHEN value IS NULL;
          calculer(tbl_name, param, value);
          value := d(tbl_name)(param).NEXT(value);
151
        END LOOP;
152
153
154
155
156
157
158
159
160
        param := d(tbl_name).NEXT(param);
      END LOOP;
      tbl_name := d.NEXT(tbl_name);
    END LOOP;

    IF HAS_DEMANDES THEN -- pour les boucles !!
      CALCULER_DEMANDES;
    END IF;
  END;
161
162
163



164
  -- AUTOMATIC GENERATION --
Laurent Lécluse's avatar
Laurent Lécluse committed
165

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
166
167
168
169
170
171
172
173
  PROCEDURE C_AGREMENT(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_AGREMENT%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'WITH i_s AS (
Laurent Lécluse's avatar
Laurent Lécluse committed
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
          SELECT
            fr.intervenant_id,
            ep.structure_id structure_id
          FROM
            formule_resultat fr
            JOIN type_volume_horaire  tvh ON tvh.code = ''PREVU'' AND tvh.id = fr.type_volume_horaire_id
            JOIN etat_volume_horaire  evh ON evh.code = ''valide'' AND evh.id = fr.etat_volume_horaire_id

            JOIN formule_resultat_service frs ON frs.formule_resultat_id = fr.id
            JOIN service s ON s.id = frs.service_id
            JOIN element_pedagogique ep ON ep.id = s.element_pedagogique_id
          WHERE
            frs.total > 0
            /*@INTERVENANT_ID=fr.intervenant_id*/
        ),
        avi AS (
            SELECT
                i.code                intervenant_code,
                i.annee_id            annee_id,
                a.type_agrement_id    type_agrement_id,
                a.id                  agrement_id,
                a.structure_id        structure_id
            FROM intervenant i
            	JOIN agrement a ON a.intervenant_id = i.id
            WHERE
            	a.histo_destruction IS NULL
        )
        SELECT DISTINCT "ANNEE_ID","ANNEE_AGREMENT","TYPE_AGREMENT_ID","INTERVENANT_ID","CODE_INTERVENANT","STRUCTURE_ID","OBLIGATOIRE","AGREMENT_ID","DUREE_VIE" FROM (
            SELECT
              i.annee_id                     annee_id,
              CASE
                WHEN COALESCE (avi.agrement_id,0) = 0
                THEN NULL
                ELSE NVL(avi.annee_id, i.annee_id) END   annee_agrement,
              tas.type_agrement_id                       type_agrement_id,
              i.id                                       intervenant_id,
              i.code                                     code_intervenant,
              null                                       structure_id,
              tas.obligatoire                            obligatoire,
              avi.agrement_id			                 agrement_id,
              tas.duree_vie                              duree_vie,
              RANK() OVER(
                PARTITION BY i.code,i.annee_id ORDER BY
                CASE
                WHEN COALESCE (avi.agrement_id,0) = 0
                THEN NULL
                ELSE NVL(avi.annee_id, i.annee_id) END DESC
              ) rank
            FROM
              type_agrement                  ta
              JOIN type_agrement_statut      tas ON tas.type_agrement_id = ta.id
                                                AND tas.histo_destruction IS NULL

              JOIN intervenant                 i ON i.histo_destruction IS NULL
                                                AND i.statut_id = tas.statut_intervenant_id

              JOIN                           i_s ON i_s.intervenant_id = i.id

              LEFT JOIN                      avi ON i.code = avi.intervenant_code
              							                		AND avi.type_agrement_id = tas.type_agrement_id
                                                AND i.annee_id < avi.annee_id + tas.duree_vie
                                                AND i.annee_id >= avi.annee_id


            WHERE
              ta.code = ''CONSEIL_ACADEMIQUE''
              /*@INTERVENANT_ID=i.id*/
              /*@ANNEE_ID=i.annee_id*/
          )
        WHERE
          rank = 1

        UNION ALL
        SELECT DISTINCT "ANNEE_ID","ANNEE_AGREMENT","TYPE_AGREMENT_ID","INTERVENANT_ID","CODE_INTERVENANT","STRUCTURE_ID","OBLIGATOIRE","AGREMENT_ID","DUREE_VIE" FROM (
            SELECT
              i.annee_id                                  annee_id,
              CASE
                WHEN COALESCE (avi.agrement_id,0) = 0
                THEN NULL
                ELSE NVL(avi.annee_id, i.annee_id) END    annee_agrement,
              tas.type_agrement_id                        type_agrement_id,
              i.id                                        intervenant_id,
              i.code                                      code_intervenant,
              i_s.structure_id							  structure_id,
              tas.obligatoire                             obligatoire,
              avi.agrement_id 			                  agrement_id,
              tas.duree_vie                               duree_vie,
              RANK() OVER(
                PARTITION BY i.code,i.annee_id,i_s.structure_id ORDER BY
                CASE
                WHEN COALESCE (avi.agrement_id,0) = 0
                THEN NULL
                ELSE NVL(avi.annee_id, i.annee_id) END DESC
              ) rank
            FROM
              type_agrement                   ta
              JOIN type_agrement_statut      tas ON tas.type_agrement_id = ta.id
                                                AND tas.histo_destruction IS NULL

              JOIN intervenant                 i ON i.histo_destruction IS NULL
                                                AND i.statut_id = tas.statut_intervenant_id

              JOIN                           i_s ON i_s.intervenant_id = i.id

              LEFT JOIN                      avi ON i.code = avi.intervenant_code
                							                	AND avi.type_agrement_id = tas.type_agrement_id
        										                    AND COALESCE(avi.structure_id,0) = COALESCE(i_s.structure_id,0)
                                                AND i.annee_id < avi.annee_id + tas.duree_vie
                                                AND i.annee_id >= avi.annee_id


            WHERE
              ta.code = ''CONSEIL_RESTREINT''
              /*@INTERVENANT_ID=i.id*/
              /*@ANNEE_ID=i.annee_id*/
          )
        WHERE
          rank = 1';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
293
294
295
296
297
298
299
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
300

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
301
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
302
303
304
    SELECT
      CASE WHEN
            t.ANNEE_ID                     = v.ANNEE_ID
305
        AND COALESCE(t.ANNEE_AGREMENT,0)   = COALESCE(v.ANNEE_AGREMENT,0)
Laurent Lécluse's avatar
Laurent Lécluse committed
306
307
        AND t.TYPE_AGREMENT_ID             = v.TYPE_AGREMENT_ID
        AND t.INTERVENANT_ID               = v.INTERVENANT_ID
308
        AND t.CODE_INTERVENANT             = v.CODE_INTERVENANT
Laurent Lécluse's avatar
Laurent Lécluse committed
309
310
311
312
313
314
        AND COALESCE(t.STRUCTURE_ID,0)     = COALESCE(v.STRUCTURE_ID,0)
        AND t.OBLIGATOIRE                  = v.OBLIGATOIRE
        AND COALESCE(t.AGREMENT_ID,0)      = COALESCE(v.AGREMENT_ID,0)
        AND t.DUREE_VIE                    = v.DUREE_VIE
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
315
      v.ANNEE_AGREMENT,
Laurent Lécluse's avatar
Laurent Lécluse committed
316
317
      v.TYPE_AGREMENT_ID,
      v.INTERVENANT_ID,
318
      v.CODE_INTERVENANT,
Laurent Lécluse's avatar
Laurent Lécluse committed
319
320
321
322
323
      v.STRUCTURE_ID,
      v.OBLIGATOIRE,
      v.AGREMENT_ID,
      v.DUREE_VIE
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
324
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
325
      FULL JOIN TBL_AGREMENT t ON
326
327
            COALESCE(t.ANNEE_AGREMENT,0)   = COALESCE(v.ANNEE_AGREMENT,0)
        AND t.TYPE_AGREMENT_ID             = v.TYPE_AGREMENT_ID
Laurent Lécluse's avatar
Laurent Lécluse committed
328
329
330
        AND t.INTERVENANT_ID               = v.INTERVENANT_ID
        AND COALESCE(t.STRUCTURE_ID,0)     = COALESCE(v.STRUCTURE_ID,0)
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
331
332
333
334
335
336
337
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_AGREMENT_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_AGREMENT values d;
      ELSIF
338
339
            d.ANNEE_AGREMENT IS NULL
        AND d.TYPE_AGREMENT_ID IS NULL
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
        AND d.INTERVENANT_ID IS NULL
        AND d.STRUCTURE_ID IS NULL
      THEN
        DELETE FROM TBL_AGREMENT WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_AGREMENT SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_CHARGENS(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_CHARGENS%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'WITH t AS (
Laurent Lécluse's avatar
Laurent Lécluse committed
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
        SELECT
          n.annee_id                        annee_id,
          n.noeud_id                        noeud_id,
          sn.scenario_id                    scenario_id,
          sne.type_heures_id                type_heures_id,
          ti.id                             type_intervention_id,

          n.element_pedagogique_id          element_pedagogique_id,
          n.element_pedagogique_etape_id    etape_id,
          sne.etape_id                      etape_ens_id,
          n.structure_id                    structure_id,
          n.groupe_type_formation_id        groupe_type_formation_id,

          vhe.heures                        heures,
          vhe.heures * ti.taux_hetd_service hetd,

          GREATEST(COALESCE(sns.ouverture, 1),1)                                           ouverture,
          GREATEST(COALESCE(sns.dedoublement, snsetp.dedoublement, csdd.dedoublement,1),1) dedoublement,
          COALESCE(sns.assiduite,1)                                                        assiduite,
          sne.effectif*COALESCE(sns.assiduite,1)                                           effectif,

          SUM(sne.effectif*COALESCE(sns.assiduite,1)) OVER (PARTITION BY n.noeud_id, sn.scenario_id, ti.id) t_effectif

        FROM
                    scenario_noeud_effectif    sne
               JOIN etape                        e ON e.id = sne.etape_id
                                                  AND e.histo_destruction IS NULL

               JOIN scenario_noeud              sn ON sn.id = sne.scenario_noeud_id
                                                  AND sn.histo_destruction IS NULL
392
393
                                                  /*@NOEUD_ID=sn.noeud_id*/
                                                  /*@SCENARIO_ID=sn.scenario_id*/
Laurent Lécluse's avatar
Laurent Lécluse committed
394
395

               JOIN tbl_noeud                       n ON n.noeud_id = sn.noeud_id
396
397
398
                                                  /*@ANNEE_ID=n.annee_id*/
                                                  /*@ELEMENT_PEDAGOGIQUE_ID=n.element_pedagogique_id*/
                                                  /*@ETAPE_ID=n.element_pedagogique_etape_id*/
Laurent Lécluse's avatar
Laurent Lécluse committed
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422

               JOIN volume_horaire_ens         vhe ON vhe.element_pedagogique_id = n.element_pedagogique_id
                                                  AND vhe.histo_destruction IS NULL
                                                  AND vhe.heures > 0

               JOIN type_intervention           ti ON ti.id = vhe.type_intervention_id

          LEFT JOIN tbl_noeud                 netp ON netp.etape_id = e.id

          LEFT JOIN scenario_noeud           snetp ON snetp.scenario_id = sn.scenario_id
                                                  AND snetp.noeud_id = netp.noeud_id
                                                  AND snetp.histo_destruction IS NULL

          LEFT JOIN scenario_noeud_seuil    snsetp ON snsetp.scenario_noeud_id = snetp.id
                                                  AND snsetp.type_intervention_id = ti.id

          LEFT JOIN tbl_chargens_seuils_def   csdd ON csdd.annee_id = n.annee_id
                                                  AND csdd.scenario_id = sn.scenario_id
                                                  AND csdd.type_intervention_id = ti.id
                                                  AND csdd.groupe_type_formation_id = n.groupe_type_formation_id
                                                  AND csdd.structure_id = n.structure_id

          LEFT JOIN scenario_noeud_seuil       sns ON sns.scenario_noeud_id = sn.id
                                                  AND sns.type_intervention_id = ti.id
423
424
425
        WHERE
          1=1
          /*@ETAPE_ENS_ID=sne.etape_id*/
Laurent Lécluse's avatar
Laurent Lécluse committed
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
        )
        SELECT
          annee_id,
          noeud_id,
          scenario_id,
          type_heures_id,
          type_intervention_id,

          element_pedagogique_id,
          etape_id,
          etape_ens_id,
          structure_id,
          groupe_type_formation_id,

          ouverture,
          dedoublement,
          assiduite,
          effectif,
          heures heures_ens,
          --t_effectif,

          CASE WHEN t_effectif < ouverture THEN 0 ELSE
            CEIL( t_effectif / dedoublement ) * effectif / t_effectif
          END groupes,

          CASE WHEN t_effectif < ouverture THEN 0 ELSE
            CEIL( t_effectif / dedoublement ) * heures * effectif / t_effectif
          END heures,

          CASE WHEN t_effectif < ouverture THEN 0 ELSE
            CEIL( t_effectif / dedoublement ) * hetd * effectif / t_effectif
          END  hetd

        FROM
          t';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
462
463
464
465
466
467
468
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
469

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
470
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
    SELECT
      CASE WHEN
            t.ANNEE_ID                             = v.ANNEE_ID
        AND t.NOEUD_ID                             = v.NOEUD_ID
        AND t.SCENARIO_ID                          = v.SCENARIO_ID
        AND t.TYPE_HEURES_ID                       = v.TYPE_HEURES_ID
        AND t.TYPE_INTERVENTION_ID                 = v.TYPE_INTERVENTION_ID
        AND t.ELEMENT_PEDAGOGIQUE_ID               = v.ELEMENT_PEDAGOGIQUE_ID
        AND t.ETAPE_ID                             = v.ETAPE_ID
        AND t.ETAPE_ENS_ID                         = v.ETAPE_ENS_ID
        AND t.STRUCTURE_ID                         = v.STRUCTURE_ID
        AND t.GROUPE_TYPE_FORMATION_ID             = v.GROUPE_TYPE_FORMATION_ID
        AND t.OUVERTURE                            = v.OUVERTURE
        AND t.DEDOUBLEMENT                         = v.DEDOUBLEMENT
        AND t.ASSIDUITE                            = v.ASSIDUITE
        AND t.EFFECTIF                             = v.EFFECTIF
        AND t.HEURES_ENS                           = v.HEURES_ENS
        AND t.GROUPES                              = v.GROUPES
        AND t.HEURES                               = v.HEURES
        AND t.HETD                                 = v.HETD
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
      v.NOEUD_ID,
      v.SCENARIO_ID,
      v.TYPE_HEURES_ID,
      v.TYPE_INTERVENTION_ID,
      v.ELEMENT_PEDAGOGIQUE_ID,
      v.ETAPE_ID,
      v.ETAPE_ENS_ID,
      v.STRUCTURE_ID,
      v.GROUPE_TYPE_FORMATION_ID,
      v.OUVERTURE,
      v.DEDOUBLEMENT,
      v.ASSIDUITE,
      v.EFFECTIF,
      v.HEURES_ENS,
      v.GROUPES,
      v.HEURES,
      v.HETD
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
511
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
512
513
514
515
516
517
518
519
520
521
522
523
      FULL JOIN TBL_CHARGENS t ON
            t.ANNEE_ID                             = v.ANNEE_ID
        AND t.NOEUD_ID                             = v.NOEUD_ID
        AND t.SCENARIO_ID                          = v.SCENARIO_ID
        AND t.TYPE_HEURES_ID                       = v.TYPE_HEURES_ID
        AND t.TYPE_INTERVENTION_ID                 = v.TYPE_INTERVENTION_ID
        AND t.ELEMENT_PEDAGOGIQUE_ID               = v.ELEMENT_PEDAGOGIQUE_ID
        AND t.ETAPE_ID                             = v.ETAPE_ID
        AND t.ETAPE_ENS_ID                         = v.ETAPE_ENS_ID
        AND t.STRUCTURE_ID                         = v.STRUCTURE_ID
        AND t.GROUPE_TYPE_FORMATION_ID             = v.GROUPE_TYPE_FORMATION_ID
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_CHARGENS_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_CHARGENS values d;
      ELSIF
            d.ANNEE_ID IS NULL
        AND d.NOEUD_ID IS NULL
        AND d.SCENARIO_ID IS NULL
        AND d.TYPE_HEURES_ID IS NULL
        AND d.TYPE_INTERVENTION_ID IS NULL
        AND d.ELEMENT_PEDAGOGIQUE_ID IS NULL
        AND d.ETAPE_ID IS NULL
        AND d.ETAPE_ENS_ID IS NULL
        AND d.STRUCTURE_ID IS NULL
        AND d.GROUPE_TYPE_FORMATION_ID IS NULL
      THEN
        DELETE FROM TBL_CHARGENS WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_CHARGENS SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_CHARGENS_SEUILS_DEF(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_CHARGENS_SEUILS_DEF%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'SELECT
Laurent Lécluse's avatar
Laurent Lécluse committed
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
          sta.annee_id,
          sta.scenario_id,
          s.structure_id,
          gtf.groupe_type_formation_id,
          sta.type_intervention_id,
          COALESCE(sc1.dedoublement, sc2.dedoublement, sc3.dedoublement, sc4.dedoublement) dedoublement
        FROM
          (SELECT DISTINCT scenario_id, type_intervention_id, annee_id FROM seuil_charge WHERE histo_destruction IS NULL) sta
          JOIN (SELECT DISTINCT structure_id FROM noeud WHERE structure_id IS NOT NULL) s ON 1=1
          JOIN (SELECT id groupe_type_formation_id FROM groupe_type_formation) gtf ON 1=1

          LEFT JOIN seuil_charge sc1 ON
            sc1.histo_destruction            IS NULL
            AND sc1.annee_id                 = sta.annee_id
            AND sc1.scenario_id              = sta.scenario_id
            AND sc1.type_intervention_id     = sta.type_intervention_id
            AND sc1.structure_id             = s.structure_id
            AND sc1.groupe_type_formation_id = gtf.groupe_type_formation_id

          LEFT JOIN seuil_charge sc2 ON
            sc2.histo_destruction            IS NULL
            AND sc2.annee_id                 = sta.annee_id
            AND sc2.scenario_id              = sta.scenario_id
            AND sc2.type_intervention_id     = sta.type_intervention_id
            AND sc2.structure_id             = s.structure_id
            AND sc2.groupe_type_formation_id IS NULL

          LEFT JOIN seuil_charge sc3 ON
            sc3.histo_destruction            IS NULL
            AND sc3.annee_id                 = sta.annee_id
            AND sc3.scenario_id              = sta.scenario_id
            AND sc3.type_intervention_id     = sta.type_intervention_id
            AND sc3.structure_id             IS NULL
            AND sc3.groupe_type_formation_id = gtf.groupe_type_formation_id

          LEFT JOIN seuil_charge sc4 ON
            sc4.histo_destruction            IS NULL
            AND sc4.annee_id                 = sta.annee_id
            AND sc4.scenario_id              = sta.scenario_id
            AND sc4.type_intervention_id     = sta.type_intervention_id
            AND sc4.structure_id             IS NULL
            AND sc4.groupe_type_formation_id IS NULL
        WHERE
          COALESCE(sc1.dedoublement, sc2.dedoublement, sc3.dedoublement, sc4.dedoublement, 1) <> 1';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
606
607
608
609
610
611
612
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
613

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
614
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
    SELECT
      CASE WHEN
            t.ANNEE_ID                             = v.ANNEE_ID
        AND t.SCENARIO_ID                          = v.SCENARIO_ID
        AND t.STRUCTURE_ID                         = v.STRUCTURE_ID
        AND t.GROUPE_TYPE_FORMATION_ID             = v.GROUPE_TYPE_FORMATION_ID
        AND t.TYPE_INTERVENTION_ID                 = v.TYPE_INTERVENTION_ID
        AND t.DEDOUBLEMENT                         = v.DEDOUBLEMENT
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
      v.SCENARIO_ID,
      v.STRUCTURE_ID,
      v.GROUPE_TYPE_FORMATION_ID,
      v.TYPE_INTERVENTION_ID,
      v.DEDOUBLEMENT
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
631
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
632
633
634
635
636
637
638
      FULL JOIN TBL_CHARGENS_SEUILS_DEF t ON
            t.ANNEE_ID                             = v.ANNEE_ID
        AND t.SCENARIO_ID                          = v.SCENARIO_ID
        AND t.STRUCTURE_ID                         = v.STRUCTURE_ID
        AND t.GROUPE_TYPE_FORMATION_ID             = v.GROUPE_TYPE_FORMATION_ID
        AND t.TYPE_INTERVENTION_ID                 = v.TYPE_INTERVENTION_ID
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_CHARGENS_SEUILS_DEF_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_CHARGENS_SEUILS_DEF values d;
      ELSIF
            d.ANNEE_ID IS NULL
        AND d.SCENARIO_ID IS NULL
        AND d.STRUCTURE_ID IS NULL
        AND d.GROUPE_TYPE_FORMATION_ID IS NULL
        AND d.TYPE_INTERVENTION_ID IS NULL
      THEN
        DELETE FROM TBL_CHARGENS_SEUILS_DEF WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_CHARGENS_SEUILS_DEF SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_CLOTURE_REALISE(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_CLOTURE_REALISE%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'WITH t AS (
Laurent Lécluse's avatar
Laurent Lécluse committed
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
          SELECT
            i.annee_id              annee_id,
            i.id                    intervenant_id,
            si.peut_cloturer_saisie peut_cloturer_saisie,
            CASE WHEN v.id IS NULL THEN 0 ELSE 1 END cloture
          FROM
                      intervenant         i
                 JOIN statut_intervenant si ON si.id = i.statut_id
                 JOIN type_validation    tv ON tv.code = ''CLOTURE_REALISE''

            LEFT JOIN validation          v ON v.intervenant_id = i.id
                                           AND v.type_validation_id = tv.id
                                           AND v.histo_destruction IS NULL

          WHERE
            i.histo_destruction IS NULL
            /*@INTERVENANT_ID=i.id*/
            /*@ANNEE_ID=i.annee_id*/
        )
        SELECT
          annee_id,
          intervenant_id,
          peut_cloturer_saisie,
          CASE WHEN sum(cloture) = 0 THEN 0 ELSE 1 END cloture
        FROM
          t
        GROUP BY
          annee_id,
          intervenant_id,
          peut_cloturer_saisie';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
702
703
704
705
706
707
708
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
709

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
710
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
711
712
713
714
715
716
717
718
719
720
721
722
    SELECT
      CASE WHEN
            t.ANNEE_ID                         = v.ANNEE_ID
        AND t.INTERVENANT_ID                   = v.INTERVENANT_ID
        AND t.PEUT_CLOTURER_SAISIE             = v.PEUT_CLOTURER_SAISIE
        AND t.CLOTURE                          = v.CLOTURE
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
      v.INTERVENANT_ID,
      v.PEUT_CLOTURER_SAISIE,
      v.CLOTURE
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
723
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
724
725
726
      FULL JOIN TBL_CLOTURE_REALISE t ON
            t.INTERVENANT_ID                   = v.INTERVENANT_ID
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_CLOTURE_REALISE_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_CLOTURE_REALISE values d;
      ELSIF
            d.INTERVENANT_ID IS NULL
      THEN
        DELETE FROM TBL_CLOTURE_REALISE WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_CLOTURE_REALISE SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_CONTRAT(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_CONTRAT%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'WITH t AS (
Laurent Lécluse's avatar
Laurent Lécluse committed
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
          SELECT
            i.annee_id                                                                annee_id,
            i.id                                                                      intervenant_id,
            si.peut_avoir_contrat                                                     peut_avoir_contrat,
            NVL(ep.structure_id, i.structure_id)                                      structure_id,
            CASE WHEN evh.code IN (''contrat-edite'',''contrat-signe'') THEN 1 ELSE 0 END edite,
            CASE WHEN evh.code IN (''contrat-signe'')                 THEN 1 ELSE 0 END signe
          FROM
                      intervenant                 i

                 JOIN statut_intervenant         si ON si.id = i.statut_id

                 JOIN service                     s ON s.intervenant_id = i.id
                                                   AND s.histo_destruction IS NULL

                 JOIN type_volume_horaire       tvh ON tvh.code = ''PREVU''

                 JOIN volume_horaire             vh ON vh.service_id = s.id
                                                   AND vh.histo_destruction IS NULL
                                                   AND vh.heures <> 0
                                                   AND vh.type_volume_horaire_id = tvh.id
                                                   AND vh.motif_non_paiement_id IS NULL

                 JOIN v_volume_horaire_etat     vhe ON vhe.volume_horaire_id = vh.id

                 JOIN etat_volume_horaire       evh ON evh.id = vhe.etat_volume_horaire_id
                                                   AND evh.code IN (''valide'', ''contrat-edite'', ''contrat-signe'')

                 JOIN element_pedagogique        ep ON ep.id = s.element_pedagogique_id

          WHERE
            i.histo_destruction IS NULL
            /*@INTERVENANT_ID=i.id*/
            /*@ANNEE_ID=i.annee_id*/
            AND NOT (si.peut_avoir_contrat = 0 AND evh.code = ''valide'')
        )
        SELECT
          annee_id,
          intervenant_id,
          peut_avoir_contrat,
          structure_id,
          count(*) as nbvh,
          sum(edite) as edite,
          sum(signe) as signe
        FROM
          t
        GROUP BY
          annee_id,
          intervenant_id,
          peut_avoir_contrat,
          structure_id';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
807
808
809
810
811
812
813
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
814

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
815
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
    SELECT
      CASE WHEN
            t.ANNEE_ID                       = v.ANNEE_ID
        AND t.INTERVENANT_ID                 = v.INTERVENANT_ID
        AND t.PEUT_AVOIR_CONTRAT             = v.PEUT_AVOIR_CONTRAT
        AND COALESCE(t.STRUCTURE_ID,0)       = COALESCE(v.STRUCTURE_ID,0)
        AND t.NBVH                           = v.NBVH
        AND t.EDITE                          = v.EDITE
        AND t.SIGNE                          = v.SIGNE
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
      v.INTERVENANT_ID,
      v.PEUT_AVOIR_CONTRAT,
      v.STRUCTURE_ID,
      v.NBVH,
      v.EDITE,
      v.SIGNE
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
834
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
835
836
837
838
      FULL JOIN TBL_CONTRAT t ON
            t.INTERVENANT_ID                 = v.INTERVENANT_ID
        AND COALESCE(t.STRUCTURE_ID,0)       = COALESCE(v.STRUCTURE_ID,0)
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_CONTRAT_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_CONTRAT values d;
      ELSIF
            d.INTERVENANT_ID IS NULL
        AND d.STRUCTURE_ID IS NULL
      THEN
        DELETE FROM TBL_CONTRAT WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_CONTRAT SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_DMEP_LIQUIDATION(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_DMEP_LIQUIDATION%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'SELECT
Laurent Lécluse's avatar
Laurent Lécluse committed
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
          annee_id,
          type_ressource_id,
          structure_id,
          SUM(heures) heures
        FROM
        (
          SELECT
            i.annee_id,
            cc.type_ressource_id,
            COALESCE( ep.structure_id, i.structure_id ) structure_id,
            mep.heures
          FROM
                      mise_en_paiement         mep
                 JOIN centre_cout               cc ON cc.id = mep.centre_cout_id
                 JOIN formule_resultat_service frs ON frs.id = mep.formule_res_service_id
                 JOIN service                    s ON s.id = frs.service_id
                 JOIN intervenant                i ON i.id = s.intervenant_id
            LEFT JOIN element_pedagogique       ep ON ep.id = s.element_pedagogique_id
          WHERE
            mep.histo_destruction IS NULL
            /*@INTERVENANT_ID=i.id*/
            /*@ANNEE_ID=i.annee_id*/

          UNION ALL

          SELECT
            i.annee_id,
            cc.type_ressource_id,
            sr.structure_id structure_id,
            heures
          FROM
                      mise_en_paiement              mep
                 JOIN centre_cout                    cc ON cc.id = mep.centre_cout_id
                 JOIN formule_resultat_service_ref frsr ON frsr.id = mep.formule_res_service_ref_id
                 JOIN service_referentiel            sr ON sr.id = frsr.service_referentiel_id
                 JOIN intervenant                     i ON i.id = sr.intervenant_id

          WHERE
            mep.histo_destruction IS NULL
            /*@INTERVENANT_ID=i.id*/
            /*@ANNEE_ID=i.annee_id*/

        ) t1
        GROUP BY
          annee_id, type_ressource_id, structure_id';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
914
915
916
917
918
919
920
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
921

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
922
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
923
924
925
926
927
928
929
930
931
932
933
934
    SELECT
      CASE WHEN
            t.ANNEE_ID                      = v.ANNEE_ID
        AND t.TYPE_RESSOURCE_ID             = v.TYPE_RESSOURCE_ID
        AND t.STRUCTURE_ID                  = v.STRUCTURE_ID
        AND t.HEURES                        = v.HEURES
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
      v.TYPE_RESSOURCE_ID,
      v.STRUCTURE_ID,
      v.HEURES
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
935
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
936
937
938
939
940
      FULL JOIN TBL_DMEP_LIQUIDATION t ON
            t.ANNEE_ID                      = v.ANNEE_ID
        AND t.TYPE_RESSOURCE_ID             = v.TYPE_RESSOURCE_ID
        AND t.STRUCTURE_ID                  = v.STRUCTURE_ID
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_DMEP_LIQUIDATION_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_DMEP_LIQUIDATION values d;
      ELSIF
            d.ANNEE_ID IS NULL
        AND d.TYPE_RESSOURCE_ID IS NULL
        AND d.STRUCTURE_ID IS NULL
      THEN
        DELETE FROM TBL_DMEP_LIQUIDATION WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_DMEP_LIQUIDATION SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_DOSSIER(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_DOSSIER%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
    viewQuery := 'SELECT
          i.annee_id,
          i.id intervenant_id,
          si.peut_saisir_dossier,
          d.id dossier_id,
          v.id validation_id,
          /*Complétude statut*/
          CASE WHEN si.code = ''AUTRES'' THEN 0
          ELSE 1 END completude_statut,
          /*Complétude identité*/
          CASE WHEN
            (
              d.civilite_id IS NOT NULL
              AND d.nom_usuel IS NOT NULL
              AND d.prenom IS NOT NULL
            ) THEN 1 ELSE 0 END completude_identite,
           /*Complétude identité complémentaire*/
          CASE WHEN si.dossier_identite_comp = 0 THEN 1
          ELSE
          	  	CASE WHEN
          	  	(
          	  	   d.date_naissance IS NOT NULL
        		   AND NOT (OSE_DIVERS.str_reduce(pn.LIBELLE) = ''france'' AND d.departement_naissance_id IS NULL)
                   AND d.pays_naissance_id IS NOT NULL
                   AND d.pays_nationalite_id IS NOT NULL
                   AND d.commune_naissance IS NOT NULL
          	  	) THEN 1 ELSE 0 END
           END completude_identite_comp,
           /*Complétude contact*/
           CASE WHEN si.dossier_contact = 0 THEN 1
           ELSE
           (
                CASE WHEN
                (
                  (CASE WHEN si.dossier_email_perso = 1 THEN
                     CASE WHEN d.email_perso IS NOT NULL THEN 1 ELSE 0 END
1006
                   ELSE
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1007
1008
1009
1010
1011
                     CASE WHEN d.email_pro IS NOT NULL OR d.email_perso IS NOT NULL THEN 1 ELSE 0 END
                   END) = 1
                   AND
                  (CASE WHEN si.dossier_tel_perso = 1 THEN
              	     CASE WHEN d.tel_perso IS NOT NULL AND d.tel_pro IS NOT NULL THEN 1 ELSE 0 END
1012
                   ELSE
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
              	     CASE WHEN d.tel_pro IS NOT NULL OR d.tel_perso IS NOT NULL THEN 1 ELSE 0 END
                   END) = 1
                ) THEN 1 ELSE 0 END
           ) END completude_contact,
           /*Complétude adresse*/
           CASE WHEN si.dossier_adresse = 0 THEN 1
           ELSE
           (
            	CASE WHEN
        	    (
        	       d.adresse_precisions IS NOT NULL
        	       OR d.adresse_lieu_dit IS NOT NULL
        	       OR (d.adresse_voie IS NOT NULL AND d.adresse_numero IS NOT NULL)
        	    ) AND
        	    (
        		   d.adresse_commune IS NOT NULL
        	       AND d.adresse_code_postal IS NOT NULL
        	    ) THEN 1 ELSE 0 END
            ) END completude_adresse,
             /*Complétude INSEE*/
             CASE WHEN si.dossier_insee = 0 THEN 1
             ELSE
             (
             	CASE WHEN
             	(
             	d.numero_insee IS NOT NULL OR COALESCE(d.numero_insee_provisoire,0) = 1
             	) THEN 1 ELSE 0 END
             ) END completude_insee,
             /*Complétude IBAN*/
             CASE WHEN si.dossier_iban = 0 THEN 1
             ELSE
             (
             	CASE WHEN
             	(
             		(d.iban IS NOT NULL
            		AND d.bic IS NOT NULL)
            		OR COALESCE(d.rib_hors_sepa,0) = 1
             	) THEN 1 ELSE 0 END
             ) END completude_iban,
             /*Complétude employeur*/
             CASE WHEN si.dossier_employeur = 0 THEN 1
             ELSE
             (
             	CASE WHEN
             	(
             		d.employeur_id IS NOT NULL
             	) THEN 1 ELSE 0 END
             ) END completude_employeur,
             /*Complétude champs autres*/
             CASE WHEN
             (
               NOT (d.autre_1 IS NULL AND COALESCE(dca1.obligatoire,0) = 1)
               AND NOT (d.autre_2 IS NULL AND COALESCE(dca2.obligatoire,0) = 1)
               AND NOT (d.autre_3 IS NULL AND COALESCE(dca3.obligatoire,0) = 1)
               AND NOT (d.autre_4 IS NULL AND COALESCE(dca4.obligatoire,0) = 1)
               AND NOT (d.autre_5 IS NULL AND COALESCE(dca5.obligatoire,0) = 1)
             ) THEN 1 ELSE 0 END completude_autres

        FROM
                    intervenant         i
               JOIN statut_intervenant si ON si.id = i.statut_id
          LEFT JOIN intervenant_dossier d ON d.intervenant_id = i.id
                                         AND d.histo_destruction IS NULL
          LEFT JOIN pays               pn ON pn.id = d.pays_naissance_id

               JOIN type_validation tv ON tv.code = ''DONNEES_PERSO_PAR_COMP''
          LEFT JOIN validation       v ON v.intervenant_id = i.id
                                      AND v.type_validation_id = tv.id
                                      AND v.histo_destruction IS NULL
          /*Champs autre 1*/
          LEFT JOIN dossier_champ_autre_par_statut dcas1 ON dcas1.dossier_champ_autre_id = 1 AND dcas1.statut_id = si.id
          LEFT JOIN dossier_champ_autre dca1 ON dca1.id = 1 AND dcas1.dossier_champ_autre_id = dca1.id
         /*Champs autre 2*/
          LEFT JOIN dossier_champ_autre_par_statut dcas2 ON dcas2.dossier_champ_autre_id = 2 AND dcas2.statut_id = si.id
          LEFT JOIN dossier_champ_autre dca2 ON dca2.id = 2 AND dcas2.dossier_champ_autre_id = dca2.id
         /*Champs autre 3*/
          LEFT JOIN dossier_champ_autre_par_statut dcas3 ON dcas3.dossier_champ_autre_id = 3 AND dcas3.statut_id = si.id
          LEFT JOIN dossier_champ_autre dca3 ON dca3.id = 3 AND dcas3.dossier_champ_autre_id = dca3.id
         /*Champs autre 4*/
          LEFT JOIN dossier_champ_autre_par_statut dcas4 ON dcas4.dossier_champ_autre_id = 4 AND dcas4.statut_id = si.id
          LEFT JOIN dossier_champ_autre dca4 ON dca4.id = 4 AND dcas4.dossier_champ_autre_id = dca4.id
         /*Champs autre 5*/
          LEFT JOIN dossier_champ_autre_par_statut dcas5 ON dcas5.dossier_champ_autre_id = 5 AND dcas5.statut_id = si.id
          LEFT JOIN dossier_champ_autre dca5 ON dca5.id = 5 AND dcas5.dossier_champ_autre_id = dca5.id
        WHERE
          i.histo_destruction IS NULL
           /*@INTERVENANT_ID=i.id*/
          /*@ANNEE_ID=i.annee_id*/';
Laurent Lécluse's avatar
Laurent Lécluse committed
1101

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1102
1103
1104
1105
1106
1107
1108
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
1109

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1110
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
1111
1112
    SELECT
      CASE WHEN
1113
1114
1115
            t.ANNEE_ID                             = v.ANNEE_ID
        AND t.INTERVENANT_ID                       = v.INTERVENANT_ID
        AND t.PEUT_SAISIR_DOSSIER                  = v.PEUT_SAISIR_DOSSIER
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1116
        AND COALESCE(t.DOSSIER_ID,0)               = COALESCE(v.DOSSIER_ID,0)
1117
        AND COALESCE(t.VALIDATION_ID,0)            = COALESCE(v.VALIDATION_ID,0)
1118
        AND COALESCE(t.COMPLETUDE_STATUT,0)        = COALESCE(v.COMPLETUDE_STATUT,0)
1119
1120
1121
1122
1123
1124
1125
1126
        AND COALESCE(t.COMPLETUDE_IDENTITE,0)      = COALESCE(v.COMPLETUDE_IDENTITE,0)
        AND COALESCE(t.COMPLETUDE_IDENTITE_COMP,0) = COALESCE(v.COMPLETUDE_IDENTITE_COMP,0)
        AND COALESCE(t.COMPLETUDE_CONTACT,0)       = COALESCE(v.COMPLETUDE_CONTACT,0)
        AND COALESCE(t.COMPLETUDE_ADRESSE,0)       = COALESCE(v.COMPLETUDE_ADRESSE,0)
        AND COALESCE(t.COMPLETUDE_INSEE,0)         = COALESCE(v.COMPLETUDE_INSEE,0)
        AND COALESCE(t.COMPLETUDE_IBAN,0)          = COALESCE(v.COMPLETUDE_IBAN,0)
        AND COALESCE(t.COMPLETUDE_EMPLOYEUR,0)     = COALESCE(v.COMPLETUDE_EMPLOYEUR,0)
        AND COALESCE(t.COMPLETUDE_AUTRES,0)        = COALESCE(v.COMPLETUDE_AUTRES,0)
Laurent Lécluse's avatar
Laurent Lécluse committed
1127
      THEN -1 ELSE t.ID END ID,
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1128
      v.ANNEE_ID,
Laurent Lécluse's avatar
Laurent Lécluse committed
1129
1130
      v.INTERVENANT_ID,
      v.PEUT_SAISIR_DOSSIER,
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1131
      v.DOSSIER_ID,
1132
      v.VALIDATION_ID,
1133
      v.COMPLETUDE_STATUT,
1134
1135
1136
1137
1138
1139
1140
      v.COMPLETUDE_IDENTITE,
      v.COMPLETUDE_IDENTITE_COMP,
      v.COMPLETUDE_CONTACT,
      v.COMPLETUDE_ADRESSE,
      v.COMPLETUDE_INSEE,
      v.COMPLETUDE_IBAN,
      v.COMPLETUDE_EMPLOYEUR,
1141
      v.COMPLETUDE_AUTRES
Laurent Lécluse's avatar
Laurent Lécluse committed
1142
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1143
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
1144
      FULL JOIN TBL_DOSSIER t ON
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1145
            t.INTERVENANT_ID                       = v.INTERVENANT_ID
Laurent Lécluse's avatar
Laurent Lécluse committed
1146
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_DOSSIER_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_DOSSIER values d;
      ELSIF
            d.INTERVENANT_ID IS NULL
      THEN
        DELETE FROM TBL_DOSSIER WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_DOSSIER SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_PAIEMENT(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_PAIEMENT%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'SELECT
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
          annee_id,
          service_id,
          service_referentiel_id,
          formule_res_service_id,
          formule_res_service_ref_id,
          intervenant_id,
          structure_id,
          mise_en_paiement_id,
          periode_paiement_id,
          domaine_fonctionnel_id,
          heures_a_payer,
          heures_a_payer_pond,
          heures_demandees,
          heures_payees,
          ROUND(pourc_exercice_aa,2)            pourc_exercice_aa,
          1 - ROUND(pourc_exercice_aa,2)        pourc_exercice_ac,
          ROUND(heures_aa,2)                    heures_aa,
          heures_demandees - ROUND(heures_aa,2) heures_ac
        FROM
        (
        SELECT
Laurent Lécluse's avatar
Laurent Lécluse committed
1196
1197
          i.annee_id                                  annee_id,
          frs.service_id                              service_id,
1198
          NULL                                        service_referentiel_id,
Laurent Lécluse's avatar
Laurent Lécluse committed
1199
          frs.id                                      formule_res_service_id,
1200
          NULL                                        formule_res_service_ref_id,
Laurent Lécluse's avatar
Laurent Lécluse committed
1201
1202
1203
1204
          i.id                                        intervenant_id,
          COALESCE( ep.structure_id, i.structure_id ) structure_id,
          mep.id                                      mise_en_paiement_id,
          mep.periode_paiement_id                     periode_paiement_id,
1205
          COALESCE(mep.domaine_fonctionnel_id, e.domaine_fonctionnel_id, to_number(p.valeur)) domaine_fonctionnel_id,
Laurent Lécluse's avatar
Laurent Lécluse committed
1206
          frs.heures_compl_fi + frs.heures_compl_fc + frs.heures_compl_fa + frs.heures_compl_fc_majorees heures_a_payer,
1207
1208
          COUNT(*) OVER(PARTITION BY frs.id)          heures_a_payer_pond,
          COALESCE(mep.heures,0)                      heures_demandees,
1209
          CASE WHEN mep.periode_paiement_id IS NULL THEN 0 ELSE mep.heures END heures_payees,
Laurent Lécluse's avatar
Laurent Lécluse committed
1210
          pea.pourc_exercice_aa                       pourc_exercice_aa,
1211
1212
1213
          SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id)  total_heures,
          SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id) * pea.pourc_exercice_aa  total_heures_aa,
          SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id ORDER BY mep.id) cumul_heures,
1214
          CASE WHEN p2.valeur = ''prorata'' THEN COALESCE(mep.heures,0) * pea.pourc_exercice_aa ELSE ose_divers.CALC_HEURES_AA(
1215
1216
1217
1218
1219
            COALESCE(mep.heures,0), -- heures
            pea.pourc_exercice_aa, -- pourc_exercice_aa
            SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id), -- total_heures
            SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id ORDER BY mep.id) -- cumul_heures
          ) END heures_aa
Laurent Lécluse's avatar
Laurent Lécluse committed
1220
1221
1222
1223
        FROM
                    formule_resultat_service        frs
               JOIN type_volume_horaire             tvh ON tvh.code = ''REALISE''
               JOIN etat_volume_horaire             evh ON evh.code = ''valide''
1224
               JOIN parametre                         p ON p.nom = ''domaine_fonctionnel_ens_ext''
1225
               JOIN parametre                        p2 ON p2.nom = ''regle_repartition_annee_civile''
Laurent Lécluse's avatar
Laurent Lécluse committed
1226
1227
1228
1229
1230
1231
               JOIN formule_resultat                 fr ON fr.id = frs.formule_resultat_id
                                                       AND fr.type_volume_horaire_id = tvh.id
                                                       AND fr.etat_volume_horaire_id = evh.id

               JOIN intervenant                       i ON i.id = fr.intervenant_id /*@INTERVENANT_ID=i.id*/ /*@ANNEE_ID=a.annee_id*/
               JOIN service                           s ON s.id = frs.service_id
Laurent Lécluse's avatar
Laurent Lécluse committed
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
               JOIN (
                 SELECT
                   frvh.formule_resultat_id,
                   vh.service_id,
                   CASE WHEN SUM(vh.heures) > 0 THEN
                     SUM(ose_divers.CALC_POURC_AA(vh.periode_id, vh.horaire_debut, vh.horaire_fin, i.annee_id) * vh.heures) / SUM(vh.heures)
                   ELSE
                     SUM(ose_divers.CALC_POURC_AA(vh.periode_id, vh.horaire_debut, vh.horaire_fin, i.annee_id))
                   END pourc_exercice_aa
                 FROM
                   volume_horaire             vh
                   JOIN service                s ON s.id = vh.service_id
                   JOIN intervenant            i ON i.id = s.intervenant_id /*@INTERVENANT_ID=i.id*/ /*@ANNEE_ID=a.annee_id*/
                   JOIN formule_resultat_vh frvh ON frvh.volume_horaire_id = vh.id
                 GROUP BY
                   frvh.formule_resultat_id,
                   vh.service_id
                 )                                  pea ON pea.formule_resultat_id = fr.id AND pea.service_id = s.id
Laurent Lécluse's avatar
Laurent Lécluse committed
1250
          LEFT JOIN element_pedagogique              ep ON ep.id = s.element_pedagogique_id
1251
          LEFT JOIN etape                             e ON e.id = ep.etape_id
Laurent Lécluse's avatar
Laurent Lécluse committed
1252
1253
1254
1255
1256
1257
1258
          LEFT JOIN mise_en_paiement                mep ON mep.formule_res_service_id = frs.id
                                                       AND mep.histo_destruction IS NULL

        UNION ALL

        SELECT
          i.annee_id                                  annee_id,
1259
          NULL                                        service_id,
Laurent Lécluse's avatar
Laurent Lécluse committed
1260
          frs.service_referentiel_id                  service_referentiel_id,
1261
          NULL                                        formule_res_service_id,
Laurent Lécluse's avatar
Laurent Lécluse committed
1262
1263
          frs.id                                      formule_res_service_ref_id,
          i.id                                        intervenant_id,
1264
          sr.structure_id                             structure_id,
Laurent Lécluse's avatar
Laurent Lécluse committed
1265
1266
          mep.id                                      mise_en_paiement_id,
          mep.periode_paiement_id                     periode_paiement_id,
1267
          COALESCE(mep.domaine_fonctionnel_id, fncr.domaine_fonctionnel_id) domaine_fonctionnel_id,
Laurent Lécluse's avatar
Laurent Lécluse committed
1268
          frs.heures_compl_referentiel                heures_a_payer,
1269
1270
          COUNT(*) OVER(PARTITION BY frs.id)          heures_a_payer_pond,
          COALESCE(mep.heures,0)                           heures_demandees,
1271
          CASE WHEN mep.periode_paiement_id IS NULL THEN 0 ELSE mep.heures END heures_payees,
Laurent Lécluse's avatar
Laurent Lécluse committed
1272
          pea.pourc_exercice_aa                       pourc_exercice_aa,
1273
1274
1275
          SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id)  total_heures,
          SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id) * pea.pourc_exercice_aa  total_heures_aa,
          SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id ORDER BY mep.id) cumul_heures,
1276
          CASE WHEN p2.valeur = ''prorata'' THEN COALESCE(mep.heures,0) * pea.pourc_exercice_aa ELSE ose_divers.CALC_HEURES_AA(
1277
1278
1279
1280
1281
            COALESCE(mep.heures,0), -- heures
            pea.pourc_exercice_aa, -- pourc_exercice_aa
            SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id), -- total_heures
            SUM(COALESCE(mep.heures,0)) OVER (partition BY frs.id ORDER BY mep.id) -- cumul_heures
          ) END heures_aa
Laurent Lécluse's avatar
Laurent Lécluse committed
1282
1283
1284
1285
        FROM
                    formule_resultat_service_ref    frs
               JOIN type_volume_horaire             tvh ON tvh.code = ''REALISE''
               JOIN etat_volume_horaire             evh ON evh.code = ''valide''
1286
               JOIN parametre                        p2 ON p2.nom = ''regle_repartition_annee_civile''
Laurent Lécluse's avatar
Laurent Lécluse committed
1287
1288
1289
1290
1291
               JOIN formule_resultat                 fr ON fr.id = frs.formule_resultat_id
                                                       AND fr.type_volume_horaire_id = tvh.id
                                                       AND fr.etat_volume_horaire_id = evh.id

               JOIN intervenant                       i ON i.id = fr.intervenant_id /*@INTERVENANT_ID=i.id*/ /*@ANNEE_ID=a.annee_id*/
1292
               JOIN service_referentiel              sr ON sr.id = frs.service_referentiel_id
Laurent Lécluse's avatar
Laurent Lécluse committed
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
               JOIN (
                 SELECT
                   frvhr.formule_resultat_id,
                   vhr.service_referentiel_id,
                   CASE WHEN SUM(vhr.heures) > 0 THEN
                     SUM(ose_divers.CALC_POURC_AA(NULL, vhr.horaire_debut, vhr.horaire_fin, i.annee_id) * vhr.heures) / SUM(vhr.heures)
                   ELSE
                     SUM(ose_divers.CALC_POURC_AA(NULL, vhr.horaire_debut, vhr.horaire_fin, i.annee_id))
                   END pourc_exercice_aa
                 FROM
                   volume_horaire_ref vhr
                   JOIN service_referentiel        sr ON sr.id = vhr.service_referentiel_id
                   JOIN intervenant                 i ON i.id = sr.intervenant_id /*@INTERVENANT_ID=i.id*/ /*@ANNEE_ID=a.annee_id*/
                   JOIN formule_resultat_vh_ref frvhr ON frvhr.volume_horaire_ref_id = vhr.id
                 GROUP BY
                   frvhr.formule_resultat_id,
                   vhr.service_referentiel_id
                 ) pea ON pea.formule_resultat_id = fr.id AND pea.service_referentiel_id = sr.id
1311
               JOIN fonction_referentiel           fncr ON fncr.id = sr.fonction_id
Laurent Lécluse's avatar
Laurent Lécluse committed
1312
          LEFT JOIN mise_en_paiement                mep ON mep.formule_res_service_ref_id = frs.id
1313
1314
                                                       AND mep.histo_destruction IS NULL
        ) t';
Laurent Lécluse's avatar
Laurent Lécluse committed
1315

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1316
1317
1318
1319
1320
1321
1322
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
1323

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1324
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
1325
1326
1327
    SELECT
      CASE WHEN
            t.ANNEE_ID                               = v.ANNEE_ID
1328
1329
1330
1331
        AND COALESCE(t.SERVICE_ID,0)                 = COALESCE(v.SERVICE_ID,0)
        AND COALESCE(t.SERVICE_REFERENTIEL_ID,0)     = COALESCE(v.SERVICE_REFERENTIEL_ID,0)
        AND COALESCE(t.FORMULE_RES_SERVICE_ID,0)     = COALESCE(v.FORMULE_RES_SERVICE_ID,0)
        AND COALESCE(t.FORMULE_RES_SERVICE_REF_ID,0) = COALESCE(v.FORMULE_RES_SERVICE_REF_ID,0)
Laurent Lécluse's avatar
Laurent Lécluse committed
1332
1333
1334
1335
        AND t.INTERVENANT_ID                         = v.INTERVENANT_ID
        AND t.STRUCTURE_ID                           = v.STRUCTURE_ID
        AND COALESCE(t.MISE_EN_PAIEMENT_ID,0)        = COALESCE(v.MISE_EN_PAIEMENT_ID,0)
        AND COALESCE(t.PERIODE_PAIEMENT_ID,0)        = COALESCE(v.PERIODE_PAIEMENT_ID,0)
1336
        AND COALESCE(t.DOMAINE_FONCTIONNEL_ID,0)     = COALESCE(v.DOMAINE_FONCTIONNEL_ID,0)
Laurent Lécluse's avatar
Laurent Lécluse committed
1337
1338
1339
1340
        AND t.HEURES_A_PAYER                         = v.HEURES_A_PAYER
        AND t.HEURES_A_PAYER_POND                    = v.HEURES_A_PAYER_POND
        AND t.HEURES_DEMANDEES                       = v.HEURES_DEMANDEES
        AND t.HEURES_PAYEES                          = v.HEURES_PAYEES
1341
1342
        AND t.POURC_EXERCICE_AA                      = v.POURC_EXERCICE_AA
        AND t.POURC_EXERCICE_AC                      = v.POURC_EXERCICE_AC
1343
1344
        AND t.HEURES_AA                              = v.HEURES_AA
        AND t.HEURES_AC                              = v.HEURES_AC
Laurent Lécluse's avatar
Laurent Lécluse committed
1345
1346
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
1347
1348
1349
1350
      v.SERVICE_ID,
      v.SERVICE_REFERENTIEL_ID,
      v.FORMULE_RES_SERVICE_ID,
      v.FORMULE_RES_SERVICE_REF_ID,
Laurent Lécluse's avatar
Laurent Lécluse committed
1351
1352
1353
1354
      v.INTERVENANT_ID,
      v.STRUCTURE_ID,
      v.MISE_EN_PAIEMENT_ID,
      v.PERIODE_PAIEMENT_ID,
1355
      v.DOMAINE_FONCTIONNEL_ID,
Laurent Lécluse's avatar
Laurent Lécluse committed
1356
1357
1358
      v.HEURES_A_PAYER,
      v.HEURES_A_PAYER_POND,
      v.HEURES_DEMANDEES,
1359
1360
      v.HEURES_PAYEES,
      v.POURC_EXERCICE_AA,
1361
1362
1363
      v.POURC_EXERCICE_AC,
      v.HEURES_AA,
      v.HEURES_AC
Laurent Lécluse's avatar
Laurent Lécluse committed
1364
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1365
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
1366
      FULL JOIN TBL_PAIEMENT t ON
1367
            COALESCE(t.FORMULE_RES_SERVICE_ID,0)     = COALESCE(v.FORMULE_RES_SERVICE_ID,0)
Laurent Lécluse's avatar
Laurent Lécluse committed
1368
        AND COALESCE(t.FORMULE_RES_SERVICE_REF_ID,0) = COALESCE(v.FORMULE_RES_SERVICE_REF_ID,0)
1369
1370
        AND t.INTERVENANT_ID                         = v.INTERVENANT_ID
        AND COALESCE(t.MISE_EN_PAIEMENT_ID,0)        = COALESCE(v.MISE_EN_PAIEMENT_ID,0)
Laurent Lécluse's avatar
Laurent Lécluse committed
1371
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1372
1373
1374
1375
1376
1377
1378
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_PAIEMENT_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_PAIEMENT values d;
      ELSIF
1379
            d.FORMULE_RES_SERVICE_ID IS NULL
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1380
        AND d.FORMULE_RES_SERVICE_REF_ID IS NULL
1381
1382
        AND d.INTERVENANT_ID IS NULL
        AND d.MISE_EN_PAIEMENT_ID IS NULL
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
      THEN
        DELETE FROM TBL_PAIEMENT WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_PAIEMENT SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_PIECE_JOINTE(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_PIECE_JOINTE%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
    viewQuery := 'WITH t AS (
          SELECT
            pjd.annee_id                                                annee_id,
            pjd.type_piece_jointe_id                                    type_piece_jointe_id,
            pjd.intervenant_id                                          intervenant_id,
            CASE WHEN pjd.intervenant_id IS NULL THEN 0 ELSE 1 END      demandee,
            SUM(CASE WHEN pjf.id IS NULL THEN 0 ELSE 1 END)             fournie,
            SUM(CASE WHEN pjf.validation_id IS NULL THEN 0 ELSE 1 END)  validee,
            COALESCE(pjd.heures_pour_seuil,0)                           heures_pour_seuil,
            COALESCE(pjd.obligatoire,1)                                 obligatoire
          FROM
                      tbl_piece_jointe_demande  pjd
            LEFT JOIN tbl_piece_jointe_fournie  pjf ON pjf.code_intervenant = pjd.code_intervenant
                                                   AND pjf.type_piece_jointe_id = pjd.type_piece_jointe_id
                                                   AND pjd.annee_id BETWEEN pjf.annee_id AND COALESCE(pjf.date_archive - 1,(pjf.annee_id + pjf.duree_vie - 1))
          WHERE
            1=1
            /*@INTERVENANT_ID=pjd.intervenant_id*/
            /*@ANNEE_ID=pjd.annee_id*/
          GROUP BY
            pjd.annee_id, pjd.type_piece_jointe_id, pjd.intervenant_id, pjd.intervenant_id, pjd.heures_pour_seuil, pjd.obligatoire

          UNION ALL

Laurent Lécluse's avatar
Laurent Lécluse committed
1426
          SELECT
1427
1428
1429
1430
1431
1432
1433
1434
            pjf.annee_id                                                annee_id,
            pjf.type_piece_jointe_id                                    type_piece_jointe_id,
            pjf.intervenant_id                                          intervenant_id,
            0                                                           demandee,
            1                                                           fournie,
            SUM(CASE WHEN pjf.validation_id IS NULL THEN 0 ELSE 1 END)  validee,
            0                                                           heures_pour_seuil,
            0                                                           obligatoire
Laurent Lécluse's avatar
Laurent Lécluse committed
1435
          FROM
1436
1437
1438
                      tbl_piece_jointe_fournie pjf
            LEFT JOIN tbl_piece_jointe_demande pjd ON pjd.intervenant_id = pjf.intervenant_id
                                                  AND pjd.type_piece_jointe_id = pjf.type_piece_jointe_id
Laurent Lécluse's avatar
Laurent Lécluse committed
1439
          WHERE
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
            pjd.id IS NULL
            /*@INTERVENANT_ID=pjf.intervenant_id*/
            /*@ANNEE_ID=pjf.annee_id*/
          GROUP BY
            pjf.annee_id, pjf.type_piece_jointe_id, pjf.intervenant_id
        )
        SELECT
          annee_id,
          type_piece_jointe_id,
          intervenant_id,
          demandee,
          CASE WHEN fournie <> 0 THEN 1 ELSE 0 END fournie,
          CASE WHEN validee <> 0 THEN 1 ELSE 0 END validee,
          heures_pour_seuil,
          obligatoire
        FROM
          t';
Laurent Lécluse's avatar
Laurent Lécluse committed
1457

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1458
1459
1460
1461
1462
1463
1464
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
1465

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1466
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
    SELECT
      CASE WHEN
            t.ANNEE_ID                         = v.ANNEE_ID
        AND t.TYPE_PIECE_JOINTE_ID             = v.TYPE_PIECE_JOINTE_ID
        AND t.INTERVENANT_ID                   = v.INTERVENANT_ID
        AND t.DEMANDEE                         = v.DEMANDEE
        AND t.FOURNIE                          = v.FOURNIE
        AND t.VALIDEE                          = v.VALIDEE
        AND t.HEURES_POUR_SEUIL                = v.HEURES_POUR_SEUIL
        AND t.OBLIGATOIRE                      = v.OBLIGATOIRE
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
      v.TYPE_PIECE_JOINTE_ID,
      v.INTERVENANT_ID,
      v.DEMANDEE,
      v.FOURNIE,
      v.VALIDEE,
      v.HEURES_POUR_SEUIL,
      v.OBLIGATOIRE
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1487
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
1488
1489
1490
1491
      FULL JOIN TBL_PIECE_JOINTE t ON
            t.TYPE_PIECE_JOINTE_ID             = v.TYPE_PIECE_JOINTE_ID
        AND t.INTERVENANT_ID                   = v.INTERVENANT_ID
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_PIECE_JOINTE_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_PIECE_JOINTE values d;
      ELSIF
            d.TYPE_PIECE_JOINTE_ID IS NULL
        AND d.INTERVENANT_ID IS NULL
      THEN
        DELETE FROM TBL_PIECE_JOINTE WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_PIECE_JOINTE SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_PIECE_JOINTE_DEMANDE(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_PIECE_JOINTE_DEMANDE%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'WITH i_h AS (
Laurent Lécluse's avatar
Laurent Lécluse committed
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
          SELECT
            s.intervenant_id,
            SUM(CASE WHEN vh.MOTIF_NON_PAIEMENT_ID IS NULL THEN vh.heures ELSE 0 END) heures,
            SUM(CASE WHEN vh.MOTIF_NON_PAIEMENT_ID IS NOT NULL THEN vh.heures ELSE 0 END) heures_non_payables,
            sum(ep.taux_fc) fc
          FROM
                 service               s
            JOIN type_volume_horaire tvh ON tvh.code = ''PREVU''
            JOIN volume_horaire       vh ON vh.service_id = s.id
                                        AND vh.type_volume_horaire_id = tvh.id
                                        AND vh.histo_destruction IS NULL
            JOIN element_pedagogique ep ON ep.id = s.element_pedagogique_id -- Service sur l''établissement
          WHERE
            s.histo_destruction IS NULL
            /*@INTERVENANT_ID=s.intervenant_id*/
          GROUP BY
            s.intervenant_id
        )
        SELECT
          i.annee_id                      annee_id,
          i.code code_intervenant,
          i.id                            intervenant_id,
          tpj.id                          type_piece_jointe_id,
          MAX(COALESCE(i_h.heures, 0))    heures_pour_seuil,
          tpjs.obligatoire obligatoire
        FROM
                    intervenant                 i

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1549
          LEFT JOIN intervenant_dossier         d ON d.intervenant_id = i.id
Laurent Lécluse's avatar
Laurent Lécluse committed
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
                                                 AND d.histo_destruction IS NULL

               JOIN type_piece_jointe_statut tpjs ON tpjs.statut_intervenant_id = i.statut_id
                                                 AND tpjs.histo_destruction IS NULL
                                                 AND i.annee_id BETWEEN COALESCE(tpjs.annee_debut_id,i.annee_id) AND COALESCE(tpjs.annee_fin_id,i.annee_id)

               JOIN type_piece_jointe         tpj ON tpj.id = tpjs.type_piece_jointe_id
                                                 AND tpj.histo_destruction IS NULL

          LEFT JOIN                           i_h ON i_h.intervenant_id = i.id
        WHERE
          -- Gestion de l''historique
          i.histo_destruction IS NULL
          /*@INTERVENANT_ID=i.id*/
          /*@ANNEE_ID=i.annee_id*/

          -- Seuil HETD ou PJ obligatoire meme avec des heures non payables
          AND (COALESCE(i_h.heures,0) > COALESCE(tpjs.seuil_hetd,-1) OR (COALESCE(i_h.heures_non_payables,0) > 0 AND tpjs.obligatoire_hnp = 1 ))


          -- Le RIB n''est demandé QUE s''il est différent!!
          AND CASE
                WHEN tpjs.changement_rib = 0 OR d.id IS NULL THEN 1
1573
                ELSE CASE WHEN replace(i.bic, '' '', '''') = replace(d.bic, '' '', '''') AND replace(i.iban, '' '', '''') = replace(d.iban, '' '', '''') THEN 0 ELSE 1 END
Laurent Lécluse's avatar
Laurent Lécluse committed
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
              END = 1

          -- Filtre FC
          AND (tpjs.fc = 0 OR i_h.fc > 0)
        GROUP BY
          i.annee_id,
          i.id,
          i.code,
          tpj.id,
          tpjs.obligatoire';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1585
1586
1587
1588
1589
1590
1591
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
1592

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1593
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
1594
1595
1596
    SELECT
      CASE WHEN
            t.ANNEE_ID                         = v.ANNEE_ID
1597
        AND t.CODE_INTERVENANT                 = v.CODE_INTERVENANT
Laurent Lécluse's avatar
Laurent Lécluse committed
1598
        AND t.INTERVENANT_ID                   = v.INTERVENANT_ID
1599
        AND t.TYPE_PIECE_JOINTE_ID             = v.TYPE_PIECE_JOINTE_ID
Laurent Lécluse's avatar
Laurent Lécluse committed
1600
1601
1602
1603
        AND t.HEURES_POUR_SEUIL                = v.HEURES_POUR_SEUIL
        AND COALESCE(t.OBLIGATOIRE,0)          = COALESCE(v.OBLIGATOIRE,0)
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
1604
      v.CODE_INTERVENANT,
Laurent Lécluse's avatar
Laurent Lécluse committed
1605
      v.INTERVENANT_ID,
1606
      v.TYPE_PIECE_JOINTE_ID,
Laurent Lécluse's avatar
Laurent Lécluse committed
1607
      v.HEURES_POUR_SEUIL,
1608
      v.OBLIGATOIRE
Laurent Lécluse's avatar
Laurent Lécluse committed
1609
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1610
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
1611
      FULL JOIN TBL_PIECE_JOINTE_DEMANDE t ON
1612
1613
            t.INTERVENANT_ID                   = v.INTERVENANT_ID
        AND t.TYPE_PIECE_JOINTE_ID             = v.TYPE_PIECE_JOINTE_ID
Laurent Lécluse's avatar
Laurent Lécluse committed
1614
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1615
1616
1617
1618
1619
1620
1621
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_PIECE_JOINTE_DEMAND_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_PIECE_JOINTE_DEMANDE values d;
      ELSIF
1622
1623
            d.INTERVENANT_ID IS NULL
        AND d.TYPE_PIECE_JOINTE_ID IS NULL
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
      THEN
        DELETE FROM TBL_PIECE_JOINTE_DEMANDE WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_PIECE_JOINTE_DEMANDE SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_PIECE_JOINTE_FOURNIE(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_PIECE_JOINTE_FOURNIE%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'SELECT
Laurent Lécluse's avatar
Laurent Lécluse committed
1644
1645
1646
1647
1648
1649
1650
          i.annee_id,
          i.code code_intervenant,
          pj.type_piece_jointe_id,
          pj.intervenant_id,
          pj.id piece_jointe_id,
          v.id validation_id,
          f.id fichier_id,
1651
1652
          CASE WHEN MIN(COALESCE(tpjs.duree_vie,1)) IS NULL THEN 1 ELSE MIN(COALESCE(tpjs.duree_vie,1)) END duree_vie,
          CASE WHEN MIN(COALESCE(tpjs.duree_vie,1)) IS NULL THEN i.annee_id+1 ELSE MIN(i.annee_id+COALESCE(tpjs.duree_vie,1)) END date_validite,
Laurent Lécluse's avatar
Laurent Lécluse committed
1653
1654
1655
1656
1657
1658
1659
1660
          pj.date_archive date_archive
        FROM
                    piece_jointe          pj
               JOIN intervenant            i ON i.id = pj.intervenant_id
                                            AND i.histo_destruction IS NULL
               JOIN piece_jointe_fichier pjf ON pjf.piece_jointe_id = pj.id
               JOIN fichier                f ON f.id = pjf.fichier_id
                                            AND f.histo_destruction IS NULL
1661
                LEFT JOIN type_piece_jointe_statut tpjs ON tpjs.statut_intervenant_id = i.statut_id
Laurent Lécluse's avatar
Laurent Lécluse committed
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
                                                   AND tpjs.type_piece_jointe_id = pj.type_piece_jointe_id
                                                   AND tpjs.HISTO_DESTRUCTION IS NULL

         LEFT JOIN validation             v ON v.id = pj.validation_id
                                            AND v.histo_destruction IS NULL
        WHERE
          pj.histo_destruction IS NULL
        GROUP BY
        i.annee_id,
          i.code,
          pj.type_piece_jointe_id,
          pj.intervenant_id,
          pj.id,
          v.id,
          f.id,
          pj.date_archive';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1679
1680
1681
1682
1683
1684
1685
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
1686

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1687
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
1688
1689
1690
    SELECT
      CASE WHEN
            t.ANNEE_ID                         = v.ANNEE_ID
1691
        AND t.CODE_INTERVENANT                 = v.CODE_INTERVENANT
Laurent Lécluse's avatar
Laurent Lécluse committed
1692
1693
        AND t.TYPE_PIECE_JOINTE_ID             = v.TYPE_PIECE_JOINTE_ID
        AND t.INTERVENANT_ID                   = v.INTERVENANT_ID
1694
        AND t.PIECE_JOINTE_ID                  = v.PIECE_JOINTE_ID
Laurent Lécluse's avatar
Laurent Lécluse committed
1695
1696
        AND COALESCE(t.VALIDATION_ID,0)        = COALESCE(v.VALIDATION_ID,0)
        AND COALESCE(t.FICHIER_ID,0)           = COALESCE(v.FICHIER_ID,0)
1697
        AND t.DUREE_VIE                        = v.DUREE_VIE
Laurent Lécluse's avatar
Laurent Lécluse committed
1698
        AND COALESCE(t.DATE_VALIDITE,0)        = COALESCE(v.DATE_VALIDITE,0)
1699
        AND COALESCE(t.DATE_ARCHIVE,0)         = COALESCE(v.DATE_ARCHIVE,0)
Laurent Lécluse's avatar
Laurent Lécluse committed
1700
1701
      THEN -1 ELSE t.ID END ID,
      v.ANNEE_ID,
1702
      v.CODE_INTERVENANT,
Laurent Lécluse's avatar
Laurent Lécluse committed
1703
1704
      v.TYPE_PIECE_JOINTE_ID,
      v.INTERVENANT_ID,
1705
      v.PIECE_JOINTE_ID,
Laurent Lécluse's avatar
Laurent Lécluse committed
1706
1707
      v.VALIDATION_ID,
      v.FICHIER_ID,
1708
      v.DUREE_VIE,
Laurent Lécluse's avatar
Laurent Lécluse committed
1709
      v.DATE_VALIDITE,
1710
      v.DATE_ARCHIVE
Laurent Lécluse's avatar
Laurent Lécluse committed
1711
    FROM
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1712
      (' || QUERY_APPLY_PARAM(viewQuery,param,value) || ') v
Laurent Lécluse's avatar
Laurent Lécluse committed
1713
1714
1715
1716
1717
1718
      FULL JOIN TBL_PIECE_JOINTE_FOURNIE t ON
            t.TYPE_PIECE_JOINTE_ID             = v.TYPE_PIECE_JOINTE_ID
        AND t.INTERVENANT_ID                   = v.INTERVENANT_ID
        AND COALESCE(t.VALIDATION_ID,0)        = COALESCE(v.VALIDATION_ID,0)
        AND COALESCE(t.FICHIER_ID,0)           = COALESCE(v.FICHIER_ID,0)
    WHERE ' || filter;
Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
    LOOP
      FETCH c INTO d; EXIT WHEN c%NOTFOUND;

      IF d.id IS NULL THEN
        d.id := TBL_PIECE_JOINTE_FOURNI_ID_SEQ.NEXTVAL;
        INSERT INTO TBL_PIECE_JOINTE_FOURNIE values d;
      ELSIF
            d.TYPE_PIECE_JOINTE_ID IS NULL
        AND d.INTERVENANT_ID IS NULL
        AND d.VALIDATION_ID IS NULL
        AND d.FICHIER_ID IS NULL
      THEN
        DELETE FROM TBL_PIECE_JOINTE_FOURNIE WHERE id = d.id;
      ELSIF d.id <> -1 THEN
        UPDATE TBL_PIECE_JOINTE_FOURNIE SET row = d WHERE id = d.id;
      END IF;
    END LOOP;
    CLOSE c;
  END;




  PROCEDURE C_SERVICE(param VARCHAR2, value VARCHAR2) IS
  TYPE r_cursor IS REF CURSOR;
  c r_cursor;
  d TBL_SERVICE%rowtype;
  filter VARCHAR2(150);
  viewQuery CLOB;
  BEGIN
    viewQuery := 'WITH t AS (
Laurent Lécluse's avatar
Laurent Lécluse committed
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
1821
1822
1823
1824
1825
1826
1827
1828
1829
1830
1831
1832
1833
1834
1835
1836
1837
1838
1839
1840
        SELECT
          s.id                                                                                      service_id,
          s.intervenant_id                                                                          intervenant_id,
          ep.structure_id                                                                           structure_id,
          ep.id                                                                                     element_pedagogique_id,
          ep.periode_id                                                                             element_pedagogique_periode_id,
          etp.id                                                                                    etape_id,

          vh.type_volume_horaire_id                                                                 type_volume_horaire_id,
          vh.heures                                                                                 heures,
          tvh.code                                                                                  type_volume_horaire_code,

          CASE WHEN ep.histo_destruction IS NULL THEN 1 ELSE 0 END                                  element_pedagogique_histo,
          CASE WHEN etp.histo_destruction IS NULL OR cp.id IS NOT NULL THEN 1 ELSE 0 END            etape_histo,

          CASE WHEN ep.periode_id IS NOT NULL THEN
            SUM( CASE WHEN vh.periode_id <> ep.periode_id THEN 1 ELSE 0 END ) OVER( PARTITION BY vh.service_id, vh.periode_id, vh.type_volume_horaire_id, vh.type_intervention_id )
          ELSE 0 END has_heures_mauvaise_periode,

          CASE WHEN v.id IS NULL AND vh.auto_validation=0 THEN 0 ELSE 1 END valide
        FROM
          service                                       s
          LEFT JOIN element_pedagogique                ep ON ep.id = s.element_pedagogique_id
          LEFT JOIN etape                             etp ON etp.id = ep.etape_id
          LEFT JOIN chemin_pedagogique                 cp ON cp.etape_id = etp.id
                                                         AND cp.element_pedagogique_id = ep.id
                                                         AND cp.histo_destruction IS NULL

               JOIN volume_horaire                     vh ON vh.service_id = s.id
                                                         AND vh.histo_destruction IS NULL

               JOIN type_volume_horaire               tvh ON tvh.id = vh.type_volume_horaire_id

          LEFT JOIN validation_vol_horaire            vvh ON vvh.volume_horaire_id = vh.id

          LEFT JOIN validation                          v ON v.id = vvh.validation_id
                                                         AND v.histo_destruction IS NULL
        WHERE
          s.histo_destruction IS NULL
          /*@INTERVENANT_ID=s.intervenant_id*/
        )
        SELECT
          i.annee_id                                                                                annee_id,
          i.id                                                                                      intervenant_id,
          i.structure_id                                                                            intervenant_structure_id,
          NVL( t.structure_id, i.structure_id )                                                     structure_id,
          ti.id                                                                                     type_intervenant_id,
          ti.code                                                                                   type_intervenant_code,
          si.peut_saisir_service                                                                    peut_saisir_service,

          t.element_pedagogique_id,
          t.service_id,
          t.element_pedagogique_periode_id,
          t.etape_id,
          t.type_volume_horaire_id,
          t.type_volume_horaire_code,
          t.element_pedagogique_histo,
          t.etape_histo,

          CASE WHEN SUM(t.has_heures_mauvaise_periode) > 0 THEN 1 ELSE 0 END has_heures_mauvaise_periode,

          CASE WHEN type_volume_horaire_id IS NULL THEN 0 ELSE count(*) END nbvh,
          CASE WHEN type_volume_horaire_id IS NULL THEN 0 ELSE sum(t.heures) END heures,
          sum(valide) valide
        FROM
          t
          JOIN intervenant                              i ON i.id = t.intervenant_id
          JOIN statut_intervenant                      si ON si.id = i.statut_id
          JOIN type_intervenant                        ti ON ti.id = si.type_intervenant_id
        WHERE
          1=1
          /*@INTERVENANT_ID=i.id*/
          /*@ANNEE_ID=i.annee_id*/
        GROUP BY
          i.annee_id,
          i.id,
          i.structure_id,
          t.structure_id,
          i.structure_id,
          ti.id,
          ti.code,
          si.peut_saisir_service,
          t.element_pedagogique_id,
          t.service_id,
          t.element_pedagogique_periode_id,
          t.etape_id,
          t.type_volume_horaire_id,
          t.type_volume_horaire_code,
          t.element_pedagogique_histo,
          t.etape_histo';

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1841
1842
1843
1844
1845
1846
1847
    IF param IS NULL THEN
      filter := '1=1';
    ELSIF value IS NULL THEN
      filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
    ELSE
      filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
    END IF;
Laurent Lécluse's avatar
Laurent Lécluse committed
1848

Laurent Lécluse's avatar
MAJ DDL    
Laurent Lécluse committed
1849
    OPEN c FOR '
Laurent Lécluse's avatar
Laurent Lécluse committed
1850
1851
1852
1853
    SELECT
      CASE WHEN
            t.ANNEE_ID                                   = v.ANNEE_ID
        AND t.INTERVENANT_ID                             = v.INTERVENANT_ID
1854
        AND COALESCE(t.INTERVENANT_STRUCTURE_ID,0)       = COALESCE(v.INTERVENANT_STRUCTURE_ID,0)
Laurent Lécluse's avatar
Laurent Lécluse committed
1855
        AND COALESCE(t.STRUCTURE_ID,0)                   = COALESCE(v.STRUCTURE_ID,0)
1856
1857
1858
        AND t.TYPE_INTERVENANT_ID                        = v.TYPE_INTERVENANT_ID
        AND t.TYPE_INTERVENANT_CODE                      = v.TYPE_INTERVENANT_CODE
        AND t.PEUT_SAISIR_SERVICE                        = v.PEUT_SAISIR_SERVICE
Laurent Lécluse's avatar
MAJ TBLs   &nbs