diff --git a/src/Bundle/ChillPersonBundle/migrations/Version20230427102309.php b/src/Bundle/ChillPersonBundle/migrations/Version20230427102309.php new file mode 100644 index 000000000..7398a2292 --- /dev/null +++ b/src/Bundle/ChillPersonBundle/migrations/Version20230427102309.php @@ -0,0 +1,189 @@ +addSql(<<<'SQL' + CREATE TEMPORARY TABLE acc_period_info AS + SELECT a.id AS accompanyingperiod_id, + 'Chill\PersonBundle\Entity\AccompanyingPeriod'::text AS relatedentity, + a.id AS relatedentityid, + NULL::integer AS user_id, + a.openingdate AS infodate, + 'accompanying_period_start'::text AS discriminator, + '{}'::jsonb AS metadata + FROM chill_person_accompanying_period a + UNION + SELECT w.accompanyingperiod_id, + 'Chill\PersonBundle\Entity\AccompanyingPeriod\AccompanyingPeriodWork'::text AS relatedentity, + w.id AS relatedentityid, + cpapwr.user_id, + w.enddate AS infodate, + 'accompanying_period_work_end'::text AS discriminator, + '{}'::jsonb AS metadata + FROM chill_person_accompanying_period_work w + LEFT JOIN chill_person_accompanying_period_work_referrer cpapwr ON w.id = cpapwr.accompanyingperiodwork_id + WHERE w.enddate IS NOT NULL + UNION + SELECT cpapw.accompanyingperiod_id, + 'Chill\PersonBundle\Entity\AccompanyingPeriod\AccompanyingPeriodWorkEvaluation'::text AS relatedentity, + e.id AS relatedentityid, + e.updatedby_id AS user_id, + e.updatedat AS infodate, + 'accompanying_period_work_evaluation_updated_at'::text AS discriminator, + '{}'::jsonb AS metadata + FROM chill_person_accompanying_period_work_evaluation e + JOIN chill_person_accompanying_period_work cpapw ON cpapw.id = e.accompanyingperiodwork_id + WHERE e.updatedat IS NOT NULL + UNION + SELECT cpapw.accompanyingperiod_id, + 'Chill\PersonBundle\Entity\AccompanyingPeriod\AccompanyingPeriodWorkEvaluation'::text AS relatedentity, + e.id AS relatedentityid, + cpapwr.user_id, + e.maxdate AS infodate, + 'accompanying_period_work_evaluation_start'::text AS discriminator, + '{}'::jsonb AS metadata + FROM chill_person_accompanying_period_work_evaluation e + JOIN chill_person_accompanying_period_work cpapw ON cpapw.id = e.accompanyingperiodwork_id + LEFT JOIN chill_person_accompanying_period_work_referrer cpapwr ON cpapw.id = cpapwr.accompanyingperiodwork_id + WHERE e.maxdate IS NOT NULL + UNION + SELECT cpapw.accompanyingperiod_id, + 'Chill\PersonBundle\Entity\AccompanyingPeriod\AccompanyingPeriodWorkEvaluation'::text AS relatedentity, + e.id AS relatedentityid, + cpapwr.user_id, + e.startdate AS infodate, + 'accompanying_period_work_evaluation_start'::text AS discriminator, + '{}'::jsonb AS metadata + FROM chill_person_accompanying_period_work_evaluation e + JOIN chill_person_accompanying_period_work cpapw ON cpapw.id = e.accompanyingperiodwork_id + LEFT JOIN chill_person_accompanying_period_work_referrer cpapwr ON cpapw.id = cpapwr.accompanyingperiodwork_id + UNION + SELECT cpapw.accompanyingperiod_id, + 'Chill\PersonBundle\Entity\AccompanyingPeriod\AccompanyingPeriodWorkEvaluationDocument'::text AS relatedentity, + doc.id AS relatedentityid, + doc.updatedby_id AS user_id, + doc.updatedat AS infodate, + 'accompanying_period_work_evaluation_document_updated_at'::text AS discriminator, + '{}'::jsonb AS metadata + FROM chill_person_accompanying_period_work_evaluation_document doc + JOIN chill_person_accompanying_period_work_evaluation e ON doc.accompanyingperiodworkevaluation_id = e.id + JOIN chill_person_accompanying_period_work cpapw ON cpapw.id = e.accompanyingperiodwork_id + WHERE doc.updatedat IS NOT NULL + UNION + SELECT cpapw.accompanyingperiod_id, + 'Chill\PersonBundle\Entity\AccompanyingPeriod\AccompanyingPeriodWorkEvaluation'::text AS relatedentity, + e.id AS relatedentityid, + cpapwr.user_id, + e.maxdate AS infodate, + 'accompanying_period_work_evaluation_max'::text AS discriminator, + '{}'::jsonb AS metadata + FROM chill_person_accompanying_period_work_evaluation e + JOIN chill_person_accompanying_period_work cpapw ON cpapw.id = e.accompanyingperiodwork_id + LEFT JOIN chill_person_accompanying_period_work_referrer cpapwr ON cpapw.id = cpapwr.accompanyingperiodwork_id + WHERE e.maxdate IS NOT NULL + UNION + SELECT w.accompanyingperiod_id, + 'Chill\PersonBundle\Entity\AccompanyingPeriod\AccompanyingPeriodWork'::text AS relatedentity, + w.id AS relatedentityid, + cpapwr.user_id, + w.startdate AS infodate, + 'accompanying_period_work_start'::text AS discriminator, + '{}'::jsonb AS metadata + FROM chill_person_accompanying_period_work w + LEFT JOIN chill_person_accompanying_period_work_referrer cpapwr ON w.id = cpapwr.accompanyingperiodwork_id + UNION + SELECT activity.accompanyingperiod_id, + 'Chill\ActivityBundle\Entity\Activity'::text AS relatedentity, + activity.id AS relatedentityid, + au.user_id, + activity.date AS infodate, + 'activity_date'::text AS discriminator, + '{}'::jsonb AS metadata + FROM activity + LEFT JOIN activity_user au ON activity.id = au.activity_id + WHERE activity.accompanyingperiod_id IS NOT NULL; + SQL); + + // create a table to store oldest inactives + $this->addSql(<<<'SQL' + CREATE TEMPORARY TABLE inactive_long AS + SELECT a.accompanyingperiod_id, MAX(infodate) AS last_date + FROM acc_period_info a JOIN chill_person_accompanying_period acp ON acp.id = a.accompanyingperiod_id + WHERE + NOT EXISTS (SELECT 1 FROM acc_period_info WHERE infodate > (NOW() - '2 years'::interval) AND acc_period_info.accompanyingperiod_id = a.accompanyingperiod_id) + AND acp.step LIKE 'CONFIRMED' + GROUP BY accompanyingperiod_id; + SQL); + + $this->addSql(<<<'SQL' + UPDATE chill_person_accompanying_period_step_history SET enddate = GREATEST(last_date + '2 years'::interval, startdate) + FROM inactive_long WHERE inactive_long.accompanyingperiod_id = period_id AND enddate IS NULL; + SQL); + + $this->addSql(<<<'SQL' + INSERT INTO chill_person_accompanying_period_step_history (id, period_id, enddate, startdate, step, createdat, updatedat) + SELECT nextval('chill_person_accompanying_period_step_history_id_seq'), accompanyingperiod_id, NULL, last_date + '2 years'::interval, 'CONFIRMED_INACTIVE_LONG', NOW(), NOW() + FROM inactive_long; + SQL); + + $this->addSql(<<<'SQL' + UPDATE chill_person_accompanying_period a SET step = 'CONFIRMED_INACTIVE_LONG' FROM inactive_long inactive WHERE a.id = inactive.accompanyingperiod_id; + SQL); + + $this->addSql(<<<'SQL' + DROP TABLE inactive_long + SQL); + + $this->addSql(<<<'SQL' + CREATE TEMPORARY TABLE inactive_long AS + SELECT a.accompanyingperiod_id, MAX(infodate) AS last_date + FROM acc_period_info a JOIN chill_person_accompanying_period acp ON acp.id = a.accompanyingperiod_id + WHERE + NOT EXISTS (SELECT 1 FROM acc_period_info WHERE infodate > (NOW() - '6 months'::interval) AND acc_period_info.accompanyingperiod_id = a.accompanyingperiod_id) + AND acp.step LIKE 'CONFIRMED' + GROUP BY accompanyingperiod_id; + SQL); + + $this->addSql(<<<'SQL' + UPDATE chill_person_accompanying_period_step_history SET enddate = GREATEST(last_date + '6 months'::interval, startdate) + FROM inactive_long WHERE inactive_long.accompanyingperiod_id = period_id AND enddate IS NULL; + SQL); + + $this->addSql(<<<'SQL' + INSERT INTO chill_person_accompanying_period_step_history (id, period_id, enddate, startdate, step, createdat, updatedat) + SELECT nextval('chill_person_accompanying_period_step_history_id_seq'), accompanyingperiod_id, NULL, last_date + '6 months'::interval, 'CONFIRMED_INACTIVE_SHORT', NOW(), NOW() + FROM inactive_long; + SQL); + + $this->addSql(<<<'SQL' + UPDATE chill_person_accompanying_period a SET step = 'CONFIRMED_INACTIVE_SHORT' FROM inactive_long inactive WHERE a.id = inactive.accompanyingperiod_id; + SQL); + } + + public function down(Schema $schema): void + { + $this->throwIrreversibleMigrationException(); + } +}