180 lines
10 KiB
SQL
180 lines
10 KiB
SQL
--
|
|
-- CHILL REPRISE DE DONNEES
|
|
-- version v0.6 (== version canevas)
|
|
--
|
|
-- /!\ IMPORTANT
|
|
-- * Avant de migrer (UP), il faut d'abord importer les codes postaux !!!
|
|
--
|
|
|
|
-- 1. Adjust Type cast for id columns
|
|
ALTER TABLE import.personnes ALTER COLUMN id TYPE INTEGER USING (id::integer);
|
|
ALTER TABLE import.periodes ALTER COLUMN id TYPE INTEGER USING (id::integer);
|
|
|
|
--
|
|
-- UP
|
|
--
|
|
|
|
-- 2. Copy date columns with right date type
|
|
ALTER TABLE import.personnes ADD COLUMN birthdate1 DATE; UPDATE import.personnes SET birthdate1 = to_date(birthdate,'DD/MM/YYYY') WHERE birthdate != '';
|
|
ALTER TABLE import.personnes ADD COLUMN deathdate1 DATE; UPDATE import.personnes SET deathdate1 = to_date(deathdate,'DD/MM/YYYY') WHERE deathdate != '';
|
|
ALTER TABLE import.personnes ADD COLUMN validfrom1 DATE; UPDATE import.personnes SET validfrom1 = to_date(validfrom,'DD/MM/YYYY') WHERE validfrom != '';
|
|
ALTER TABLE import.personnes ADD COLUMN household_startdate1 DATE; UPDATE import.personnes SET household_startdate1 = to_date(household_startdate,'DD/MM/YYYY') WHERE household_startdate != '';
|
|
ALTER TABLE import.periodes ADD COLUMN openingdate1 DATE; UPDATE import.periodes SET openingdate1 = to_date(openingdate::text,'DD/MM/YYYY') WHERE openingdate != '';
|
|
ALTER TABLE import.periodes ADD COLUMN closingdate1 DATE; UPDATE import.periodes SET closingdate1 = to_date(closingdate,'DD/MM/YYYY') WHERE closingdate != '';
|
|
|
|
-- 3. Complete table Civility
|
|
ALTER TABLE import.choix_personnes ADD COLUMN civility1 JSONB;
|
|
UPDATE import.choix_personnes SET civility1=json_build_object('fr', trim(civility)) WHERE civility!='';
|
|
WITH max_ordering AS ( SELECT MAX(ordering) as max_ordering FROM chill_main_civility )
|
|
INSERT INTO chill_main_civility (id, name, abbreviation, active, ordering)
|
|
SELECT nextval('chill_main_civility_id_seq'),
|
|
t.civility1, t.civility1, true,
|
|
max_ordering.max_ordering + row_number() OVER () as ordering
|
|
FROM ( SELECT DISTINCT ON (civility) civility1 FROM import.choix_personnes WHERE civility1 IS NOT NULL ) t
|
|
CROSS JOIN max_ordering
|
|
WHERE NOT EXISTS ( SELECT 1 FROM chill_main_civility WHERE name::jsonb = t.civility1 );
|
|
|
|
-- 4. Complete table Country
|
|
ALTER TABLE import.choix_personnes ADD COLUMN country1 JSONB;
|
|
UPDATE import.choix_personnes SET country1=json_build_object('fr', trim(country)) WHERE country!='';
|
|
INSERT INTO country (id, name, countrycode)
|
|
SELECT nextval('country_id_seq'), t.country1, 'ZZ'
|
|
FROM ( SELECT DISTINCT ON (country) country1 FROM import.choix_personnes WHERE country1 IS NOT NULL ) t
|
|
WHERE NOT EXISTS ( SELECT 1 FROM country WHERE name::jsonb = t.country1 );
|
|
|
|
-- 5. Complete table maritalstatus
|
|
ALTER TABLE import.choix_personnes ADD COLUMN maritalstatus1 JSONB;
|
|
UPDATE import.choix_personnes SET maritalstatus1=json_build_object('fr', trim(maritalstatus)) WHERE maritalstatus!='';
|
|
INSERT INTO chill_person_marital_status (id, name)
|
|
SELECT substr(md5(random()::text), 1, 7), t.maritalstatus1
|
|
FROM ( SELECT DISTINCT ON (maritalstatus) maritalstatus1 FROM import.choix_personnes WHERE maritalstatus1 IS NOT NULL ) t
|
|
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_marital_status WHERE name::jsonb = t.maritalstatus1 );
|
|
|
|
-- 6. Complete table household_composition_type
|
|
ALTER TABLE import.choix_personnes ADD COLUMN household_composition_type1 JSONB;
|
|
UPDATE import.choix_personnes SET household_composition_type1=json_build_object('fr', trim(household_composition_type)) WHERE household_composition_type!='';
|
|
INSERT INTO chill_person_household_composition_type (id, active, label)
|
|
SELECT nextval('chill_person_household_composition_type_id_seq'), true, t.household_composition_type1
|
|
FROM ( SELECT DISTINCT ON (household_composition_type) household_composition_type1 FROM import.choix_personnes WHERE household_composition_type1 IS NOT NULL ) t
|
|
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_household_composition_type WHERE label::jsonb = t.household_composition_type1 );
|
|
|
|
-- 7. Complete table household_position
|
|
ALTER TABLE import.choix_personnes ADD COLUMN household_position1 JSONB;
|
|
UPDATE import.choix_personnes SET household_position1=json_build_object('fr', trim(household_position)) WHERE household_position!='';
|
|
WITH max_ordering AS ( SELECT MAX(ordering) as max_ordering FROM chill_person_household_position )
|
|
INSERT INTO chill_person_household_position (id, label, sharehousehold, allowholder, ordering)
|
|
SELECT
|
|
nextval('chill_person_household_position_id_seq'), t.household_position1, true, false,
|
|
max_ordering.max_ordering + row_number() OVER () as ordering
|
|
FROM ( SELECT DISTINCT ON (household_position) household_position1 FROM import.choix_personnes WHERE household_position1 IS NOT NULL ) t
|
|
CROSS JOIN max_ordering
|
|
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_household_position WHERE label::jsonb = t.household_position1 );
|
|
|
|
-- 8. Complete closingmotive
|
|
ALTER TABLE import.choix_periodes ADD COLUMN closingmotive1 JSONB;
|
|
UPDATE import.choix_periodes SET closingmotive1=json_build_object('fr', trim(closingmotive)) WHERE closingmotive!='';
|
|
WITH max_ordering AS ( SELECT MAX(ordering) as max_ordering FROM chill_person_accompanying_period_closingmotive )
|
|
INSERT INTO chill_person_accompanying_period_closingmotive (id, name, active, parent_id, ordering)
|
|
SELECT nextval('chill_person_accompanying_period_closingmotive_id_seq'),
|
|
t.closingmotive1, true, null,
|
|
max_ordering.max_ordering + row_number() OVER () as ordering
|
|
FROM ( SELECT DISTINCT ON (closingmotive) closingmotive1 FROM import.choix_periodes WHERE closingmotive1 IS NOT NULL ) t
|
|
CROSS JOIN max_ordering
|
|
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_accompanying_period_closingmotive WHERE name::jsonb = t.closingmotive1 );
|
|
|
|
-- 9. Complete origin
|
|
ALTER TABLE import.choix_periodes ADD COLUMN origin1 JSONB;
|
|
UPDATE import.choix_periodes SET origin1=json_build_object('fr', trim(origin)) WHERE origin!='';
|
|
INSERT INTO chill_person_accompanying_period_origin (id, label, noactiveafter)
|
|
SELECT nextval('chill_person_accompanying_period_origin_id_seq'), t.origin1, null
|
|
FROM ( SELECT DISTINCT ON (origin) origin1 FROM import.choix_periodes WHERE origin1 IS NOT NULL ) t
|
|
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_accompanying_period_origin WHERE label::jsonb = t.origin1 );
|
|
|
|
-- 10. Complete user_job
|
|
ALTER TABLE import.choix_periodes ADD COLUMN job1 JSONB;
|
|
UPDATE import.choix_periodes SET job1=json_build_object('fr', trim(job)) WHERE job!='';
|
|
INSERT INTO chill_main_user_job (id, label, active)
|
|
SELECT nextval('chill_main_user_job_id_seq'), t.job1, true
|
|
FROM ( SELECT DISTINCT ON (job) job1 FROM import.choix_periodes WHERE job1 IS NOT NULL ) t
|
|
WHERE NOT EXISTS( SELECT 1 FROM chill_main_user_job WHERE label::jsonb = t.job1 );
|
|
|
|
-- 11. Complete acp_scopes
|
|
ALTER TABLE import.choix_periodes ADD COLUMN acp_scopes1 JSONB;
|
|
UPDATE import.choix_periodes SET acp_scopes1=json_build_object('fr', trim(acp_scopes)) WHERE acp_scopes!='';
|
|
INSERT INTO scopes (id, name, active)
|
|
SELECT nextval('scopes_id_seq'), t.acp_scopes1, true
|
|
FROM ( SELECT DISTINCT ON (acp_scopes) acp_scopes1 FROM import.choix_periodes WHERE acp_scopes1 IS NOT NULL ) t
|
|
WHERE NOT EXISTS ( SELECT 1 FROM scopes WHERE name::jsonb = t.acp_scopes1 );
|
|
|
|
|
|
|
|
|
|
--
|
|
-- DOWN
|
|
--
|
|
|
|
-- Undo 11.
|
|
DELETE FROM scopes USING import.choix_periodes icp WHERE scopes.name::jsonb = icp.acp_scopes1::jsonb;
|
|
SELECT setval('scopes_id_seq', (SELECT max(id) FROM scopes));
|
|
ALTER TABLE import.choix_periodes DROP COLUMN acp_scopes1;
|
|
|
|
-- Undo 10.
|
|
DELETE FROM chill_main_user_job cmuj USING import.choix_periodes icp WHERE cmuj.label::jsonb = icp.job1::jsonb;
|
|
SELECT setval('chill_main_user_job_id_seq', (SELECT max(id) FROM chill_main_user_job));
|
|
ALTER TABLE import.choix_periodes DROP COLUMN job1;
|
|
|
|
-- Undo 9.
|
|
DELETE FROM chill_person_accompanying_period_origin cpapo USING import.choix_periodes icp WHERE cpapo.label::jsonb = icp.origin1::jsonb;
|
|
SELECT setval('chill_person_accompanying_period_origin_id_seq', (SELECT max(id) FROM chill_person_accompanying_period_origin));
|
|
ALTER TABLE import.choix_periodes DROP COLUMN origin1;
|
|
|
|
-- Undo 8.
|
|
DELETE FROM chill_person_accompanying_period_closingmotive cpapcm USING import.choix_periodes icp WHERE cpapcm.name::jsonb = icp.closingmotive1::jsonb;
|
|
SELECT setval('chill_person_accompanying_period_closingmotive_id_seq', (SELECT max(id) FROM chill_person_accompanying_period_closingmotive));
|
|
ALTER TABLE import.choix_periodes DROP COLUMN closingmotive1;
|
|
|
|
-- Undo 7.
|
|
DELETE FROM chill_person_household_position cphp USING import.choix_personnes icp WHERE cphp.label::jsonb = icp.household_position1::jsonb;
|
|
SELECT setval('chill_person_household_position_id_seq', (SELECT max(id) FROM chill_person_household_position));
|
|
ALTER TABLE import.choix_personnes DROP COLUMN household_position1;
|
|
|
|
-- Undo 6.
|
|
DELETE FROM chill_person_household_composition_type cphct USING import.choix_personnes icp WHERE cphct.label::jsonb = icp.household_composition_type1::jsonb AND cphct.id > 6;
|
|
SELECT setval('chill_person_household_composition_type_id_seq', (SELECT max(id) FROM chill_person_household_composition_type));
|
|
ALTER TABLE import.choix_personnes DROP COLUMN household_composition_type1;
|
|
|
|
-- Undo 5.
|
|
DELETE FROM chill_person_marital_status cpms USING import.choix_personnes icp WHERE cpms.name::jsonb = icp.maritalstatus1::jsonb AND cpms.id <> 'célibat.' AND cpms.id <> 'marié'; -- existing marital status
|
|
ALTER TABLE import.choix_personnes DROP COLUMN maritalstatus1;
|
|
|
|
-- Undo 4.
|
|
DELETE FROM country USING import.choix_personnes icp WHERE country.name::jsonb = icp.country1::jsonb AND country.id > 249; -- 249 existing countries
|
|
SELECT setval('country_id_seq', (SELECT max(id) FROM country));
|
|
ALTER TABLE import.choix_personnes DROP COLUMN country1;
|
|
|
|
-- Undo 3.
|
|
DELETE FROM chill_main_civility cmc USING import.choix_personnes ip WHERE cmc.name::jsonb = ip.civility1::jsonb;
|
|
SELECT setval('chill_main_civility_id_seq', (SELECT max(id) FROM chill_main_civility));
|
|
ALTER TABLE import.choix_personnes DROP COLUMN civility1;
|
|
|
|
-- Undo 2.
|
|
ALTER TABLE import.personnes DROP COLUMN birthdate1;
|
|
ALTER TABLE import.personnes DROP COLUMN deathdate1;
|
|
ALTER TABLE import.personnes DROP COLUMN validfrom1;
|
|
ALTER TABLE import.personnes DROP COLUMN household_startdate1;
|
|
ALTER TABLE import.periodes DROP COLUMN openingdate1;
|
|
ALTER TABLE import.periodes DROP COLUMN closingdate1;
|
|
|
|
|
|
-- -------------
|
|
|
|
-- personnes choices_list: gender
|
|
-- periodes choices_list: intensity referrer job acp_scopes acp_socialissues work_socialaction
|
|
-- tiers choices_list: civility kind profession category
|
|
|
|
--
|
|
-- SELECT
|
|
--
|
|
SELECT DISTINCT civility FROM import.personnes;
|
|
SELECT * FROM import.periodes;
|