chill-bundles/migrations/Version20170117131924.php

124 lines
3.1 KiB
PHP

<?php
namespace Application\Migrations;
use Doctrine\Migrations\AbstractMigration;
use Doctrine\DBAL\Schema\Schema;
/**
* Add postgresql functions to compute last address on person.
*/
class Version20170117131924 extends AbstractMigration
{
public $fields = array(
'address_id' => 'integer',
'streetaddress1' => 'varchar(255)',
'streetaddress2' => 'varchar(255)',
'validfrom' => 'date',
'postcode_label' => 'varchar(255)',
'postcode_code' => 'varchar(100)',
'postcode_id' => 'integer',
'country_name' => 'json',
'country_code' => 'varchar(3)',
'country_id' => 'integer'
);
/**
* @param Schema $schema
*/
public function up(Schema $schema): void
{
$this->addSql(<<<'SQL'
CREATE OR REPLACE FUNCTION public.get_last_address (
pid integer,
before_date date)
RETURNS TABLE(
person_id integer,
address_id integer,
streetaddress1 varchar(255),
streetaddress2 varchar(255),
validfrom date,
postcode_label varchar(255),
postcode_code varchar(100),
postcode_id integer,
country_name json,
country_code varchar(3),
country_id integer)
AS
$BODY$
SELECT
pid AS person_id,
chill_main_address.id AS address_id,
chill_main_address.streetaddress1,
chill_main_address.streetaddress2,
chill_main_address.validfrom,
chill_main_postal_code.label,
chill_main_postal_code.code,
chill_main_postal_code.id AS postal_code_id,
country.name,
country.countrycode,
country.id AS country_id
FROM chill_main_address
JOIN (
SELECT
chill_main_address.id AS address_id,
validfrom,
rank() OVER (PARTITION BY person_id ORDER BY validfrom DESC) as pos
FROM chill_person_persons_to_addresses
JOIN chill_main_address ON chill_person_persons_to_addresses.address_id = chill_main_address.id
WHERE person_id = pid
AND chill_main_address.validfrom <= before_date
) AS ranking ON ranking.address_id = chill_main_address.id
JOIN chill_main_postal_code ON chill_main_address.postcode_id = chill_main_postal_code.id
JOIN country ON chill_main_postal_code.country_id = country.id
WHERE ranking.pos = 1
$BODY$
LANGUAGE sql VOLATILE
COST 100;
SQL
);
// create function to get part of address
foreach ($this->fields as $var => $type) {
$this->addSql(sprintf(<<<'SQL'
CREATE OR REPLACE FUNCTION get_last_address_%s (
pid integer,
before_date date)
RETURNS %s AS
$BODY$
SELECT %s FROM get_last_address(pid, before_date)
$BODY$
LANGUAGE sql volatile
COST 100;
SQL
, $var, $type, $var));
}
}
/**
* @param Schema $schema
*/
public function down(Schema $schema): void
{
// drop function to get parts of address
foreach ($this->fields as $var => $type) {
$this->addSql(<<<SQL
DROP FUNCTION get_last_address_$var (
pid integer,
before_date date)
SQL
);
}
$this->addSQL(<<<SQL
DROP FUNCTION public.get_last_address (
pid integer,
before_date date)
SQL
);
}
}