QueryGeneratorService.php 20 KB
Newer Older
1
2
3
<?php
namespace UnicaenImport\Service;

4
use UnicaenImport\Entity\Schema\Column;
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
use UnicaenImport\Exception\Exception;
use UnicaenImport\Entity\Differentiel\Query;
use UnicaenImport\Options\Traits\ModuleOptionsAwareTrait;
use UnicaenImport\Service\Traits\SchemaServiceAwareTrait;

/**
 *
 *
 * @author Laurent LÉCLUSE <laurent.lecluse at unicaen.fr>
 */
class QueryGeneratorService extends AbstractService
{
    use SchemaServiceAwareTrait;
    use ModuleOptionsAwareTrait;

    const AG_BEGIN          = '-- AUTOMATIC GENERATION --';
    const AG_END            = '-- END OF AUTOMATIC GENERATION --';
    const ANNEE_COLUMN_NAME = 'ANNEE_ID';

    /**
     * Tables
     *
     * @var string[]
     */
    protected $tables;

    /**
     * Colonnes
     *
     * @var array
     */
    protected $cols = [];



    /**
     * Retourne la liste des tables importables
     *
     * @return string[]
     */
    protected function getTables()
    {
        if (empty($this->tables)) {
            $this->tables = $this->getServiceSchema()->getImportTables();
        }

        return $this->tables;
    }



    /**
     * Retourne la liste des colonnes importables d'une table
     *
     * @param string $tableName
     *
     * @return string[]
     */
    protected function getCols($tableName)
    {
        if (!isset($this->cols[$tableName])) {
            $this->cols[$tableName] = $this->getServiceSchema()->getImportCols($tableName);
        }

        return $this->cols[$tableName];
    }



    public function execMajVM($tableName)
    {
        $mviewName = $this->escape('MV_' . $tableName);
        $sql       = "BEGIN DBMS_MVIEW.REFRESH($mviewName, 'C'); END;";
        try {
            $this->getEntityManager()->getConnection()->exec($sql);
        } catch (\Doctrine\DBAL\DBALException $e) {
            throw Exception::duringMajMVException($e, $tableName);
        }
    }



    /**
     * Met à jour des données d'après la requête transmise
     *
     * @param Query $query Requête de filtrage pour la mise à jour
     *
     * @retun self
     */
    public function execMaj(Query $query)
    {
        $currentUser = $this->getDbUser();
        if (empty($currentUser)) {
            throw new Exception('Vous devez être authentifié pour réaliser cette action');
        }
        $userId     = $this->escape($currentUser->getId());
        $procName   = $this->escapeKW('MAJ_' . $query->getTableName());
        $conditions = $query->toSql(false);
        if (!empty($conditions)) {
            $conditions = $this->escape($conditions);
        } else {
            $conditions = 'NULL';
        }
        $ignoreFields = $query->getIgnoreFields();
        if (empty($ignoreFields)) {
            $ignoreFields = 'NULL';
        } else {
            $ignoreFields = $this->escape(implode(',', $ignoreFields));
        }

115
        $sql = "BEGIN " . $this->getPackage() . ".SET_CURRENT_USER($userId);" . $this->getPackage() . ".$procName($conditions,$ignoreFields); END;";
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
        try {
            $this->getEntityManager()->getConnection()->exec($sql);
        } catch (\Doctrine\DBAL\DBALException $e) {
            throw Exception::duringMajException($e, $query->getTableName());
        }

        return $this;
    }



    /**
     * Synchronise une table
     *
     * @param string $tableName
     *
     * @return string[]
     */
    public function syncTable($tableName)
    {
        $currentUser = $this->getDbUser();
        if (empty($currentUser)) {
            throw new Exception('Vous devez être authentifié pour réaliser cette action');
        }
        $userId = $this->escape($currentUser->getId());

        $errors    = [];
        $lastLogId = $this->getLastLogId();
144
        $sql       = "BEGIN " . $this->getPackage() . ".SET_CURRENT_USER($userId);" . $this->getPackage() . "." . $this->escapeKW('MAJ_' . $tableName) . "; END;";
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
        try {
            $this->getEntityManager()->getConnection()->exec($sql);
        } catch (\Doctrine\DBAL\DBALException $e) {
            $errors[] = Exception::duringMajException($e, $tableName)->getMessage();
        }
        $errors = $errors + $this->getLogMessages($lastLogId);

        return $errors;
    }



    /**
     * retourne le dernier ID du log de synchronisation
     *
     * @return int
     */
    protected function getLastLogId()
    {
        $sql  = "SELECT MAX(id) last_log_id FROM SYNC_LOG";
        $stmt = $this->getEntityManager()->getConnection()->executeQuery($sql);
        if ($r = $stmt->fetch()) {
            return (int)$r['LAST_LOG_ID'];
        }

        return 0;
    }



    /**
     * Retourne tous les messages d'erreur qui sont apparue depuis $since
     *
     * @param int $since
     *
     * @return string[]
     */
    protected function getLogMessages($since)
    {
        $since    = (int)$since;
        $sql      = "SELECT message FROM sync_log WHERE id > :since ORDER BY id";
        $messages = [];
        $stmt     = $this->getEntityManager()->getConnection()->executeQuery($sql, ['since' => (int)$since]);
        while ($r = $stmt->fetch()) {
            $messages[] = $r['MESSAGE'];
        }

        return $messages;
    }



    /**
     *
     * @param string $tableName
     *
     * @return null|string
     */
    public function getSqlCriterion($tableName)
    {
205
        $sql  = 'SELECT ' . $this->getPackage() . '.GET_SQL_CRITERION(' . $this->escape($tableName) . ',\'\') res FROM DUAL';
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
        $stmt = $this->getEntityManager()->getConnection()->executeQuery($sql);

        if ($r = $stmt->fetch()) {
            $res = $r['RES'];
            if ($res) return $res; else return null;
        }

        return null;
    }



    /**
     * Retourne les identifiants des données concernés
     *
     * @param string               $tableName
     * @param string|string[]|null $sourceCode
     * @param integer|null         $anneeId
     *
     * @return integer[]|null
     */
    public function getIdFromSourceCode($tableName, $sourceCode, $anneeId = null)
    {
        if (empty($sourceCode)) return null;

        $sql = 'SELECT ID FROM ' . $this->escapeKW($tableName) . ' WHERE SOURCE_CODE IN (:sourceCode)';
        if ($anneeId) {
            $sql .= ' AND ANNEE_ID = ' . (string)(int)$anneeId;
        }
        $stmt = $this->getEntityManager()->getConnection()->executeQuery(
            $sql,
            ['sourceCode' => (array)$sourceCode],
            ['sourceCode' => \Doctrine\DBAL\Connection::PARAM_INT_ARRAY]
        );
        if ($r = $stmt->fetch()) {
            ;

            return (int)$r['ID'];
        } else {
            return null;
        }
    }



    /**
     * Mettre à jour toutes les infos dans la BDD
     *
     * @return self
     */
    public function updateViewsAndPackages()
    {
        $views = $this->makeDiffViews();

        foreach ($views as $vn => $view) {
            $this->exec($view);
        }

        $declaration = $this->makePackageDeclaration();
        $this->exec($declaration);

        $body = $this->makePackageBody();
        $this->exec($body);

        return $this;
    }



    protected function getPackage()
    {
        return $this->getOptionsModule()->getPackage();
    }



    /**
     * Retourne le code source du package d'import
     *
     * @return string
     */
    protected function getPackageDeclaration()
    {
289
        $sql    = "SELECT TEXT FROM USER_SOURCE WHERE NAME = '" . $this->getPackage() . "' AND type = 'PACKAGE'";
290
291
292
293
294
295
296
297
298
299
300
301
302
303
        $result = $this->query($sql, [], 'TEXT');

        return implode("", $result);
    }



    /**
     * Retourne le code source du package d'import
     *
     * @return string
     */
    protected function getPackageBody()
    {
304
        $sql    = "SELECT TEXT FROM USER_SOURCE WHERE NAME = '" . $this->getPackage() . "' AND type = 'PACKAGE BODY'";
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
        $result = $this->query($sql, [], 'TEXT');

        return implode("", $result);
    }



    /**
     * Construit toutes les vues différentielles
     *
     * @return array
     */
    protected function makeDiffViews()
    {
        $tables = $this->getTables();
        $result = [];
        foreach ($tables as $table) {
            $result[$table] = $this->makeDiffView($table);
        }

        return $result;
    }



    /**
     * Construit toutes les déclarations de procédures
     *
     * @return array
     */
    protected function makeProcDeclarations()
    {
        $tables = $this->getTables();
        $result = [];
        foreach ($tables as $table) {
            $result[$table] = $this->makeProcDeclaration($table);
        }

        return $result;
    }



    /**
     * Construit tous les corps de procédures
     *
     * @return array
     */
    protected function makeProcBodies()
    {
        $tables = $this->getTables();
        $result = [];
        foreach ($tables as $table) {
358
            $this->assertSequenceExists($table);
359
360
361
362
363
364
            $result[$table] = $this->makeProcBody($table);
        }

        return $result;
    }

365
366


367
368
369
370
    /**
     * Teste que la séquence correspondant à la table spécifiée existe bien.
     *
     * @param string $table
371
     *
372
373
374
375
376
377
378
379
380
     * @throws \Doctrine\DBAL\DBALException En cas d'erreur en BDD
     * @throws Exception Si la séquence n'existe pas.
     *
     */
    protected function assertSequenceExists($table)
    {
        $sql = 'SELECT COUNT(*) SEQ_FOUND FROM USER_SEQUENCES WHERE SEQUENCE_NAME = :sequenceName';

        $sequenceName = strtoupper($table) . '_ID_SEQ';
381
        $stmt         = $this->getEntityManager()->getConnection()->executeQuery($sql, ['sequenceName' => $sequenceName]);
382
383
384
385
386

        $sequenceFound = false;
        if ($r = $stmt->fetch()) {
            $sequenceFound = (bool)(int)$r['SEQ_FOUND'];
        }
387
        if (!$sequenceFound) {
388
389
390
391
            throw new Exception("La séquence '$sequenceName' doit être créée (ex: CREATE SEQUENCE $sequenceName)");
        }
    }

392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
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
462
463
464
465
466
467
468
469
470
471
472
473


    /**
     * Constuit la nouvelle déclaration du package IMPORT
     *
     * @return string
     */
    protected function makePackageDeclaration()
    {
        $src  = $this->getPackageDeclaration();
        $decl = implode("\n", $this->makeProcDeclarations());

        return $this->updatePackageContent($src, $decl);
    }



    /**
     * Constuit la nouvelle déclaration du package IMPORT
     *
     * @return string
     */
    protected function makePackageBody()
    {
        $src  = $this->getPackageBody();
        $decl = implode("\n\n\n\n", $this->makeProcBodies());

        return $this->updatePackageContent($src, $decl);
    }



    /**
     * Mise à jour du contenu d'un package (déclaration ou corps)
     *
     * @param string $packageSource
     * @param string $newContent
     *
     * @return string
     */
    protected function updatePackageContent($packageSource, $newContent)
    {
        $src = $packageSource;
        if (null === $begin = strpos($packageSource, self::AG_BEGIN)) {
            throw new Exception('Le tag indiquant le début de la zone automatique du package n\'a pas été trouvée');
        }

        if (null === $end = strpos($packageSource, self::AG_END)) {
            throw new Exception('Le tag indiquant la fin de la zone automatique du package n\'a pas été trouvée');
        }

        $src = 'CREATE OR REPLACE '
            . substr($packageSource, 0, $begin + strlen(self::AG_BEGIN))
            . "\n\n" . $newContent . "\n\n  "
            . substr($packageSource, $end);

        return $src;
    }



    /**
     * Génère une vue différentielle pour une table donnée
     *
     * @param string $tableName
     *
     * @return string
     */
    protected function makeDiffView($tableName)
    {
        // Pour l'annualisation :
        $schema   = $this->getServiceSchema()->getSchema($tableName);
        $joinCond = '';
        $delCond  = '';
        $depJoin  = '';
        if (array_key_exists(self::ANNEE_COLUMN_NAME, $schema)) {
            // Si la table courante est annualisée ...
            if ($this->getServiceSchema()->hasColumn('V_DIFF_' . $tableName, self::ANNEE_COLUMN_NAME)) {
                // ... et que la source est également annualisée alors concordance nécessaire
                $joinCond = ' AND S.' . self::ANNEE_COLUMN_NAME . ' = d.' . self::ANNEE_COLUMN_NAME;
            }
            // destruction ssi dans l'année d'import courante
474
            $delCond = ' AND d.' . self::ANNEE_COLUMN_NAME . ' >= ' . $this->getPackage() . '.get_current_annee';
475
476
477
        } else {
            // on recherche si la table dépend d'une table qui, elle, serait annualisée
            foreach ($schema as $columnName => $column) {
478
                /* @var $column \UnicaenImport\Entity\Schema\Column */
479
480
481
482
483
484
485
                if (!empty($column->refTableName)) {
                    $refSchema = $this->getServiceSchema()->getSchema($column->refTableName);
                    if (!empty($refSchema) && array_key_exists(self::ANNEE_COLUMN_NAME, $refSchema)) {
                        // Oui, la table dépend d'une table annualisée!!
                        // Donc, on utilise la table référente
                        $depJoin = "\n  LEFT JOIN " . $column->refTableName . " rt ON rt." . $column->refColumnName . " = d." . $columnName;
                        // destruction ssi dans l'année d'import courante de la table référente
486
                        $delCond = ' AND rt.' . self::ANNEE_COLUMN_NAME . ' >= ' . $this->getPackage() . '.get_current_annee';
487
488
489
490
491
492
493
494
495
496
497
498
499

                        break;
                        /* on stoppe à la première table contenant une année.
                         * S'il en existe une autre tant pis pour elle,
                         * les années doivent de toute manière être concordantes entres sources!!!
                         */
                    }
                }
            }
        }

        // on génère ensuite la bonne requête !!!
        $cols = $this->getCols($tableName);
500
501
502
503
        foreach ($cols as $id => $col) {
            $cols[$id] = $schema[$col];
        }
        $sql = "CREATE OR REPLACE FORCE VIEW V_DIFF_$tableName AS
504
505
506
507
508
509
510
511
512
select diff.* from (SELECT
  COALESCE( D.id, S.id ) id,
  COALESCE( S.source_id, D.source_id ) source_id,
  COALESCE( S.source_code, D.source_code ) source_code,
CASE
    WHEN S.source_code IS NOT NULL AND D.source_code IS NULL THEN 'insert'
    WHEN S.source_code IS NOT NULL AND D.source_code IS NOT NULL AND (D.histo_destruction IS NULL OR D.histo_destruction > SYSDATE) THEN 'update'
    WHEN S.source_code IS NULL AND D.source_code IS NOT NULL AND (D.histo_destruction IS NULL OR D.histo_destruction > SYSDATE)$delCond THEN 'delete'
    WHEN S.source_code IS NOT NULL AND D.source_code IS NOT NULL AND D.histo_destruction IS NOT NULL AND D.histo_destruction <= SYSDATE THEN 'undelete' END import_action,
513
514
515
516
517
518
519
520
521
522
523
524
525
526
  " . $this->formatColQuery($cols, function (Column $col) {
                if ($col->dataType == 'CLOB') {
                    return '  CASE WHEN S.source_code IS NULL AND D.source_code IS NOT NULL THEN D.:column ELSE to_clob(S.:column) END :column';
                } else {
                    return '  CASE WHEN S.source_code IS NULL AND D.source_code IS NOT NULL THEN D.:column ELSE S.:column END :column';
                }
            }, ",\n  ") . ",
  " . $this->formatColQuery($cols, function (Column $col) {
                if ($col->dataType == 'CLOB') {
                    return '  CASE WHEN dbms_lob.compare(D.:column,S.:column) <> 0 OR (D.:column IS NULL AND S.:column IS NOT NULL) OR (D.:column IS NOT NULL AND S.:column IS NULL) THEN 1 ELSE 0 END U_:column';
                } else {
                    return '  CASE WHEN D.:column <> S.:column OR (D.:column IS NULL AND S.:column IS NOT NULL) OR (D.:column IS NOT NULL AND S.:column IS NULL) THEN 1 ELSE 0 END U_:column';
                }
            }, ",\n  ") . "
527
528
529
530
531
532
533
FROM
  $tableName D$depJoin
  FULL JOIN SRC_$tableName S ON S.source_id = D.source_id AND S.source_code = D.source_code$joinCond
WHERE
       (S.source_code IS NOT NULL AND D.source_code IS NOT NULL AND D.histo_destruction IS NOT NULL AND D.histo_destruction <= SYSDATE)
    OR (S.source_code IS NULL AND D.source_code IS NOT NULL AND (D.histo_destruction IS NULL OR D.histo_destruction > SYSDATE))
    OR (S.source_code IS NOT NULL AND D.source_code IS NULL)
534
535
536
537
538
539
540
    OR " . $this->formatColQuery($cols, function (Column $col) {
                if ($col->dataType == 'CLOB') {
                    return 'dbms_lob.compare(D.:column,S.:column) <> 0 OR (D.:column IS NULL AND S.:column IS NOT NULL) OR (D.:column IS NOT NULL AND S.:column IS NULL)';
                } else {
                    return 'D.:column <> S.:column OR (D.:column IS NULL AND S.:column IS NOT NULL) OR (D.:column IS NOT NULL AND S.:column IS NULL)';
                }
            }, "\n  OR ") . "
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
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
) diff JOIN source on source.id = diff.source_id WHERE import_action IS NOT NULL AND source.importable = 1";

        return $sql;
    }



    /**
     * Génère une déclaration de procédure pour une table donnée
     *
     * @param string $tableName
     *
     * @return string
     */
    protected function makeProcDeclaration($tableName)
    {
        return "  PROCEDURE MAJ_$tableName(SQL_CRITERION CLOB DEFAULT '', IGNORE_UPD_COLS CLOB DEFAULT '');";
    }



    /**
     * Génère un corps de procédure pour une table donnée
     *
     * @param string $tableName
     *
     * @return string
     */
    protected function makeProcBody($tableName)
    {
        $cols = $this->getCols($tableName);

        $sql = "  PROCEDURE MAJ_$tableName(SQL_CRITERION CLOB DEFAULT '', IGNORE_UPD_COLS CLOB DEFAULT '') IS
    TYPE r_cursor IS REF CURSOR;
    sql_query CLOB;
    diff_cur r_cursor;
    diff_row V_DIFF_$tableName%ROWTYPE;
  BEGIN
    sql_query := 'SELECT V_DIFF_$tableName.* FROM V_DIFF_$tableName ' || get_sql_criterion('$tableName',SQL_CRITERION);
    OPEN diff_cur FOR sql_query;
    LOOP
      FETCH diff_cur INTO diff_row; EXIT WHEN diff_cur%NOTFOUND;
      BEGIN

        CASE diff_row.import_action
          WHEN 'insert' THEN
587
            INSERT INTO $tableName
588
589
590
591
592
593
594
              ( id, " . $this->formatColQuery($cols) . ", source_id, source_code, histo_createur_id, histo_modificateur_id )
            VALUES
              ( COALESCE(diff_row.id,$tableName" . "_ID_SEQ.NEXTVAL), " . $this->formatColQuery($cols, 'diff_row.:column') . ", diff_row.source_id, diff_row.source_code, get_current_user, get_current_user );

          WHEN 'update' THEN
            " . $this->formatColQuery(
                $cols,
595
                "IF (diff_row.u_:column = 1 AND IN_COLUMN_LIST(':column',IGNORE_UPD_COLS) = 0) THEN UPDATE $tableName SET :column = diff_row.:column WHERE ID = diff_row.id; END IF;"
596
597
598
599
                , "\n          "
            ) . "

          WHEN 'delete' THEN
600
            UPDATE $tableName SET histo_destruction = SYSDATE, histo_destructeur_id = get_current_user WHERE ID = diff_row.id;
601
602
603
604

          WHEN 'undelete' THEN
            " . $this->formatColQuery(
                $cols,
605
                "IF (diff_row.u_:column = 1 AND IN_COLUMN_LIST(':column',IGNORE_UPD_COLS) = 0) THEN UPDATE $tableName SET :column = diff_row.:column WHERE ID = diff_row.id; END IF;"
606
607
                , "\n          "
            ) . "
608
            UPDATE $tableName SET histo_destruction = NULL, histo_destructeur_id = NULL WHERE ID = diff_row.id;
609
610
611
612

        END CASE;

      EXCEPTION WHEN OTHERS THEN
613
        " . $this->getPackage() . ".SYNC_LOG( SQLERRM, '$tableName', diff_row.source_code );
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
      END;
    END LOOP;
    CLOSE diff_cur;

  END MAJ_$tableName;";

        return $sql;
    }



    /**
     * Retourne une chaîne SQL correspondant, pour chaque colonne donnée, au résultat du formatage donné,
     * concaténé selon le séparateur transmis.
     *
     * L'opérateur $c permet de situer l'endroit où devont être placées les colonnes.
     *
     * @param array  $cols
     * @param string $format
     * @param string $separator
     *
     * @return string
     */
    protected function formatColQuery(array $cols, $format = ':column', $separator = ',')
    {
        $res = [];
        foreach ($cols as $col) {
641
642
643
644
645
646
647
            if (is_callable($format)) {
                $f = $format($col);
            } else {
                $f = $format;
            }

            $res[] = str_replace(':column', $col, $f);
648
649
650
651
652
        }

        return implode($separator, $res);
    }
}