-- -- 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, 'ZZZ' 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 ); -- -- DOWN -- -- 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 maritalstatus household_composition_type household_position -- 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; SELECT DISTINCT ON (civility) civility1 FROM import.personnes WHERE civility1 IS NOT NULL;