[person] Feature: add a person's center history

The association between Person and Center is now stored in a dedicated
Entity: `PersonCenterHistory`, which have a date interval (start date
and endDate). The SQL counterpart is a table, with a constraint which
ensure that no person might be associated with two center at the same time.

For ease, a view is created to get the current center associated with
the person.

The dedicated migration creates also:

* indexes for a rapid search for person at current date;
* and populate the table from current data, setting the startdate to the
  person's creation date and time if any, `NOW()` unless.

The `Person` entity is also updated to use the information from the
PersonCenterHistory classes, but this commit does not yet delete the
`Center` column.
This commit is contained in:
2022-09-26 21:11:01 +02:00
parent e3764f6f91
commit 49d2e98a1a
7 changed files with 468 additions and 3 deletions

View File

@@ -0,0 +1,69 @@
<?php
declare(strict_types=1);
namespace Chill\Migrations\Person;
use Doctrine\DBAL\Schema\Schema;
use Doctrine\Migrations\AbstractMigration;
final class Version20220926154347 extends AbstractMigration
{
public function getDescription(): string
{
return 'Add a center history on person';
}
public function up(Schema $schema): void
{
$this->addSql('CREATE SEQUENCE chill_person_person_center_history_id_seq INCREMENT BY 1 MINVALUE 1 START 1');
$this->addSql('CREATE TABLE chill_person_person_center_history (
id INT NOT NULL, person_id INT DEFAULT NULL, center_id INT DEFAULT NULL,
startDate DATE NOT NULL, endDate DATE DEFAULT NULL, createdAt TIMESTAMP(0) WITHOUT TIME ZONE DEFAULT NULL,
updatedAt TIMESTAMP(0) WITHOUT TIME ZONE DEFAULT NULL, createdBy_id INT DEFAULT NULL,
updatedBy_id INT DEFAULT NULL, PRIMARY KEY(id))');
$this->addSql('CREATE INDEX IDX_CACA67FA217BBB47 ON chill_person_person_center_history (person_id)');
$this->addSql('CREATE INDEX IDX_CACA67FA5932F377 ON chill_person_person_center_history (center_id)');
$this->addSql('CREATE INDEX IDX_CACA67FA3174800F ON chill_person_person_center_history (createdBy_id)');
$this->addSql('CREATE INDEX IDX_CACA67FA65FF1AEC ON chill_person_person_center_history (updatedBy_id)');
$this->addSql('COMMENT ON COLUMN chill_person_person_center_history.startDate IS \'(DC2Type:date_immutable)\'');
$this->addSql('COMMENT ON COLUMN chill_person_person_center_history.endDate IS \'(DC2Type:date_immutable)\'');
$this->addSql('COMMENT ON COLUMN chill_person_person_center_history.createdAt IS \'(DC2Type:datetime_immutable)\'');
$this->addSql('COMMENT ON COLUMN chill_person_person_center_history.updatedAt IS \'(DC2Type:datetime_immutable)\'');
$this->addSql('ALTER TABLE chill_person_person_center_history ADD CONSTRAINT FK_CACA67FA217BBB47 FOREIGN KEY (person_id) REFERENCES chill_person_person (id) NOT DEFERRABLE INITIALLY IMMEDIATE');
$this->addSql('ALTER TABLE chill_person_person_center_history ADD CONSTRAINT FK_CACA67FA5932F377 FOREIGN KEY (center_id) REFERENCES centers (id) NOT DEFERRABLE INITIALLY IMMEDIATE');
$this->addSql('ALTER TABLE chill_person_person_center_history ADD CONSTRAINT FK_CACA67FA3174800F FOREIGN KEY (createdBy_id) REFERENCES users (id) NOT DEFERRABLE INITIALLY IMMEDIATE');
$this->addSql('ALTER TABLE chill_person_person_center_history ADD CONSTRAINT FK_CACA67FA65FF1AEC FOREIGN KEY (updatedBy_id) REFERENCES users (id) NOT DEFERRABLE INITIALLY IMMEDIATE');
// check consistency of history on database side
$this->addSql('ALTER TABLE chill_person_person_center_history ADD CHECK (startdate <= enddate)');
$this->addSql('ALTER TABLE chill_person_person_center_history ADD CONSTRAINT ' .
'chill_internal_person_person_center_history_not_overlaps EXCLUDE USING GIST(
-- extension btree_gist required to include comparaison with integer
person_id WITH =,
daterange(startdate, enddate, \'[)\') WITH &&
)
INITIALLY DEFERRED');
// create index on search by person and date
$this->addSql('CREATE INDEX chill_internal_person_person_center_history_by_date ON chill_person_person_center_history (person_id DESC, startdate DESC, enddate DESC NULLS FIRST)');
// create a view to get the current center on a person
$this->addSql(
'CREATE VIEW view_chill_person_person_center_history_current AS
SELECT id, person_id, center_id, startDate, endDate, createdAt, updatedAt, createdBy_id, updatedBy_id
FROM chill_person_person_center_history WHERE startDate <= NOW() AND (enddate IS NULL OR enddate > NOW())'
);
$this->addSql('INSERT INTO chill_person_person_center_history (id, person_id, center_id, startdate)
SELECT nextval(\'chill_person_person_center_history_id_seq\'), id, center_id, COALESCE(createdat, NOW())
FROM chill_person_person WHERE center_id IS NOT NULL');
}
public function down(Schema $schema): void
{
$this->addSql('DROP VIEW view_chill_person_person_center_history_current');
$this->addSql('DROP SEQUENCE chill_person_person_center_history_id_seq CASCADE');
$this->addSql('DROP TABLE chill_person_person_center_history');
}
}