From e08ab0666f2f29550d33b7a0811fc9d8c0ad3482 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Julien=20Fastr=C3=A9?= Date: Mon, 2 Oct 2023 12:06:41 +0200 Subject: [PATCH] Add a constraint to avoid doublons in table chill_person_accompanying_period_location_history #143 --- .../unreleased/Fixed-20231002-120602.yaml | 6 ++ .../migrations/Version20231002094521.php | 60 +++++++++++++++++++ 2 files changed, 66 insertions(+) create mode 100644 .changes/unreleased/Fixed-20231002-120602.yaml create mode 100644 src/Bundle/ChillPersonBundle/migrations/Version20231002094521.php diff --git a/.changes/unreleased/Fixed-20231002-120602.yaml b/.changes/unreleased/Fixed-20231002-120602.yaml new file mode 100644 index 000000000..95a3d239e --- /dev/null +++ b/.changes/unreleased/Fixed-20231002-120602.yaml @@ -0,0 +1,6 @@ +kind: Fixed +body: From the database, avoid the creation of location history for same period and + at same dates +time: 2023-10-02T12:06:02.412233177+02:00 +custom: + Issue: "143" diff --git a/src/Bundle/ChillPersonBundle/migrations/Version20231002094521.php b/src/Bundle/ChillPersonBundle/migrations/Version20231002094521.php new file mode 100644 index 000000000..c960ab8f8 --- /dev/null +++ b/src/Bundle/ChillPersonBundle/migrations/Version20231002094521.php @@ -0,0 +1,60 @@ +addSql( + <<<'SQL' + WITH doublons_ordered AS ( + SELECT h2.id AS h2id, h2.createdAt AS h2createdAt, h2.startDate AS h2start, h2.endDate AS h2end, h1.*, + rank() OVER (partition by h1.period_id ORDER BY h1.id, h2.id) AS ranking + FROM chill_person_accompanying_period_location_history h1 + JOIN chill_person_accompanying_period_location_history h2 ON h1.period_id = h2.period_id AND h1.id <> h2.id + WHERE daterange(h1.startdate, h1.enddate) && daterange(h2.startdate, h2.enddate) ORDER BY h1.period_id, h1.id + ), + keep_only_first AS ( + SELECT id FROM doublons_ordered WHERE ranking > 1 + ) + DELETE FROM chill_person_accompanying_period_location_history WHERE id IN (SELECT id FROM doublons_ordered); + SQL + ); + + $this->addSql( + <<<'SQL' + ALTER TABLE chill_person_accompanying_period_location_history + ADD CONSTRAINT acc_period_location_history_not_overlaps + EXCLUDE USING GIST (period_id with =, tsrange(startdate, enddate) with &&) + DEFERRABLE INITIALLY DEFERRED + SQL + ); + } + + public function down(Schema $schema): void + { + $this->addSql( + <<<'SQL' + ALTER TABLE chill_person_accompanying_period_location_history DROP CONSTRAINT acc_period_location_history_not_overlaps + SQL + ); + } +}