Add a constraint to avoid doublons in table chill_person_accompanying_period_location_history

#143
This commit is contained in:
Julien Fastré 2023-10-02 12:06:41 +02:00
parent 217232fe4f
commit e08ab0666f
Signed by: julienfastre
GPG Key ID: BDE2190974723FCB
2 changed files with 66 additions and 0 deletions

View File

@ -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"

View File

@ -0,0 +1,60 @@
<?php
declare(strict_types=1);
/*
* Chill is a software for social workers
*
* For the full copyright and license information, please view
* the LICENSE file that was distributed with this source code.
*/
namespace Chill\Migrations\Person;
use Doctrine\DBAL\Schema\Schema;
use Doctrine\Migrations\AbstractMigration;
final class Version20231002094521 extends AbstractMigration
{
public function getDescription(): string
{
return 'Remove doublons in chill_person_accompanying_period_location_history and add a constraint on startdate / endDate by period';
}
public function up(Schema $schema): void
{
$this->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
);
}
}