mirror of
https://gitlab.com/Chill-Projet/chill-bundles.git
synced 2025-06-07 18:44:08 +00:00
155 lines
4.9 KiB
PHP
155 lines
4.9 KiB
PHP
<?php declare(strict_types=1);
|
|
|
|
namespace Application\Migrations;
|
|
|
|
use Doctrine\DBAL\Schema\Schema;
|
|
use Doctrine\Migrations\AbstractMigration;
|
|
|
|
/**
|
|
* Add triggers for canicalizing alt names
|
|
*/
|
|
final class Version20200130213446 extends AbstractMigration
|
|
{
|
|
const CANONICALIZE_FULLNAME_ON_UPDATE = <<<'SQL'
|
|
CREATE OR REPLACE FUNCTION public.canonicalize_fullname_on_update()
|
|
RETURNS trigger
|
|
LANGUAGE 'plpgsql'
|
|
COST 100
|
|
VOLATILE NOT LEAKPROOF
|
|
AS $BODY$
|
|
DECLARE
|
|
cur_alt_names CURSOR(pid INTEGER) FOR SELECT label FROM chill_person_alt_name WHERE person_id = pid;
|
|
alt_name RECORD;
|
|
fullname_canonicalized TEXT;
|
|
BEGIN
|
|
fullname_canonicalized := LOWER(UNACCENT(CONCAT(NEW.firstname, ' ', NEW.lastname)));
|
|
OPEN cur_alt_names(pid:=NEW.id);
|
|
LOOP
|
|
FETCH cur_alt_names INTO alt_name;
|
|
|
|
EXIT WHEN NOT FOUND;
|
|
|
|
fullname_canonicalized := CONCAT(fullname_canonicalized, ' ',
|
|
LOWER(UNACCENT(alt_name.label)));
|
|
END LOOP;
|
|
CLOSE cur_alt_names;
|
|
|
|
IF fullname_canonicalized <> OLD.fullnameCanonical
|
|
THEN
|
|
UPDATE chill_person_person
|
|
SET fullnameCanonical=fullname_canonicalized
|
|
WHERE id=NEW.id;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$BODY$;
|
|
SQL;
|
|
|
|
const CANONICALIZE_FULLNAME_ON_ALT_NAME_ALTER = <<<'SQL'
|
|
CREATE OR REPLACE FUNCTION public.canonicalize_fullname_on_alt_name_alter()
|
|
RETURNS trigger
|
|
LANGUAGE 'plpgsql'
|
|
COST 100
|
|
VOLATILE NOT LEAKPROOF
|
|
AS $BODY$
|
|
DECLARE
|
|
target_person_id INTEGER;
|
|
cur_person CURSOR(pid INTEGER) FOR SELECT firstname, lastname FROM chill_person_person WHERE id = pid;
|
|
person RECORD;
|
|
cur_alt_names CURSOR(pid INTEGER) FOR SELECT label FROM chill_person_alt_name WHERE person_id = pid;
|
|
alt_name RECORD;
|
|
fullname_canonicalized TEXT;
|
|
BEGIN
|
|
IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE'
|
|
THEN target_person_id := NEW.person_id;
|
|
ELSE target_person_id := OLD.person_id;
|
|
END IF;
|
|
|
|
OPEN cur_person(pid:=target_person_id);
|
|
FETCH cur_person INTO person;
|
|
fullname_canonicalized := LOWER(UNACCENT(CONCAT(person.firstname, ' ', person.lastname)));
|
|
-- loop over alt names
|
|
OPEN cur_alt_names(pid:=target_person_id);
|
|
LOOP
|
|
FETCH cur_alt_names INTO alt_name;
|
|
|
|
EXIT WHEN NOT FOUND;
|
|
|
|
fullname_canonicalized := CONCAT(fullname_canonicalized, ' ',
|
|
LOWER(UNACCENT(alt_name.label)));
|
|
END LOOP;
|
|
CLOSE cur_alt_names;
|
|
CLOSE cur_person;
|
|
|
|
UPDATE chill_person_person
|
|
SET fullnameCanonical=fullname_canonicalized
|
|
WHERE id=target_person_id;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$BODY$;
|
|
SQL;
|
|
|
|
const CANONICALIZE_FULLNAME_ON_ALT_NAME_INSERT = <<<SQL
|
|
CREATE TRIGGER canonicalize_fullname_on_alt_name_insert
|
|
AFTER INSERT
|
|
ON chill_person_alt_name
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE canonicalize_fullname_on_alt_name_alter();
|
|
SQL;
|
|
|
|
const CANONICALIZE_FULLNAME_ON_ALT_NAME_DELETE = <<<SQL
|
|
CREATE TRIGGER canonicalize_fullname_on_alt_name_delete
|
|
AFTER DELETE
|
|
ON chill_person_alt_name
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE canonicalize_fullname_on_alt_name_alter();
|
|
SQL;
|
|
|
|
const CANONICALIZE_FULLNAME_ON_ALT_NAME_UPDATE = <<<SQL
|
|
CREATE TRIGGER canonicalize_fullname_on_alt_name_update
|
|
AFTER UPDATE
|
|
ON chill_person_alt_name
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE canonicalize_fullname_on_alt_name_alter();
|
|
SQL;
|
|
|
|
public function up(Schema $schema): void
|
|
{
|
|
// update fullname
|
|
$this->addSql("ALTER TABLE chill_person_person ALTER fullnamecanonical TYPE TEXT;");
|
|
$this->addSql("ALTER TABLE chill_person_person ALTER fullnamecanonical DROP DEFAULT;");
|
|
// insert function and triggers
|
|
$this->addSql(self::CANONICALIZE_FULLNAME_ON_UPDATE);
|
|
$this->addSql(self::CANONICALIZE_FULLNAME_ON_ALT_NAME_ALTER);
|
|
$this->addSql(self::CANONICALIZE_FULLNAME_ON_ALT_NAME_INSERT);
|
|
$this->addSql(self::CANONICALIZE_FULLNAME_ON_ALT_NAME_DELETE);
|
|
$this->addSql(self::CANONICALIZE_FULLNAME_ON_ALT_NAME_UPDATE);
|
|
|
|
}
|
|
|
|
public function down(Schema $schema): void
|
|
{
|
|
$this->addSql("DROP TRIGGER canonicalize_fullname_on_alt_name_update ON chill_person_alt_name;");
|
|
$this->addSql("DROP TRIGGER canonicalize_fullname_on_alt_name_insert ON chill_person_alt_name;");
|
|
$this->addSql("DROP TRIGGER canonicalize_fullname_on_alt_name_delete ON chill_person_alt_name;");
|
|
$this->addSql("DROP FUNCTION canonicalize_fullname_on_alt_name_alter();");
|
|
$this->addSql(<<<'SQL'
|
|
CREATE OR REPLACE FUNCTION canonicalize_fullname_on_update() RETURNS TRIGGER AS
|
|
$BODY$
|
|
BEGIN
|
|
IF NEW.firstname <> OLD.firstname OR NEW.lastname <> OLD.lastname
|
|
THEN
|
|
UPDATE chill_person_person
|
|
SET fullnameCanonical=LOWER(UNACCENT(CONCAT(NEW.firstname, ' ', NEW.lastname)))
|
|
WHERE id=NEW.id;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$BODY$ LANGUAGE PLPGSQL;
|
|
SQL
|
|
);
|
|
}
|
|
|
|
}
|