Add fullnameCanonical column for trigram matching (fast searching)

This commit is contained in:
Mat 2018-10-23 16:18:09 +02:00
parent 7547f99063
commit 3599a94f94
3 changed files with 88 additions and 1 deletions

View File

@ -113,7 +113,12 @@ class Person implements HasCenterInterface {
* @var \Doctrine\Common\Collections\Collection
*/
private $addresses;
/**
* @var string
*/
private $fullnameCanonical;
public function __construct(\DateTime $opening = null) {
$this->accompanyingPeriods = new ArrayCollection();
$this->spokenLanguages = new ArrayCollection();

View File

@ -51,6 +51,9 @@ Chill\PersonBundle\Entity\Person:
type: text
nullable: true
length: 40
fullnameCanonical:
type: string
length: 255
manyToOne:
countryOfBirth:
targetEntity: Chill\MainBundle\Entity\Country

View File

@ -0,0 +1,79 @@
<?php declare(strict_types=1);
namespace Application\Migrations;
use Doctrine\DBAL\Schema\Schema;
use Doctrine\Migrations\AbstractMigration;
/**
* Add fullnameCanonical column for trigram matching (fast searching)
*/
final class Version20181023101621 extends AbstractMigration
{
public function up(Schema $schema) : void
{
$this->abortIf($this->connection->getDatabasePlatform()->getName() !== 'postgresql', 'Migration can only be executed safely on \'postgresql\'.');
$this->addSql("ALTER TABLE chill_person_person ADD fullnameCanonical VARCHAR(255) DEFAULT '' ");
$this->addSql("UPDATE chill_person_person SET fullnameCanonical=LOWER(UNACCENT(CONCAT(firstname, ' ', lastname)))");
$this->addSql("CREATE INDEX fullnameCanonical_trgm_idx ON chill_person_person USING GIN (fullnameCanonical gin_trgm_ops)");
$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
);
$this->addSql(<<<SQL
CREATE TRIGGER canonicalize_fullname_on_update
AFTER UPDATE
ON chill_person_person
FOR EACH ROW
WHEN (pg_trigger_depth() = 0)
EXECUTE PROCEDURE canonicalize_fullname_on_update();
SQL
);
$this->addSql(<<<'SQL'
CREATE OR REPLACE FUNCTION canonicalize_fullname_on_insert() RETURNS TRIGGER AS
$BODY$
BEGIN
UPDATE chill_person_person
SET fullnameCanonical=LOWER(UNACCENT(CONCAT(NEW.firstname, ' ', NEW.lastname)))
WHERE id=NEW.id;
RETURN NEW;
END;
$BODY$ LANGUAGE PLPGSQL;
SQL
);
$this->addSql(<<<SQL
CREATE TRIGGER canonicalize_fullname_on_insert
AFTER INSERT
ON chill_person_person
FOR EACH ROW
EXECUTE PROCEDURE canonicalize_fullname_on_insert();
SQL
);
}
public function down(Schema $schema) : void
{
$this->abortIf($this->connection->getDatabasePlatform()->getName() !== 'postgresql', 'Migration can only be executed safely on \'postgresql\'.');
$this->addSql('DROP INDEX fullnameCanonical_trgm_idx');
$this->addSql('ALTER TABLE chill_person_person DROP fullnameCanonical');
$this->addSql('DROP TRIGGER canonicalize_fullname_on_update ON chill_person_person');
$this->addSql('DROP FUNCTION canonicalize_fullname_on_update()');
$this->addSql('DROP TRIGGER canonicalize_fullname_on_insert ON chill_person_person');
$this->addSql('DROP FUNCTION canonicalize_fullname_on_insert()');
}
}