473 lines
28 KiB
SQL
473 lines
28 KiB
SQL
--
|
|
-- CHILL REPRISE DE DONNEES
|
|
-- version v0.6 (== version canevas)
|
|
--
|
|
-- /!\ IMPORTANT
|
|
-- Avant de migrer (UP), il faut d'abord avoir importé 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->>'fr' = t.civility1::jsonb->>'fr' );
|
|
|
|
-- 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->>'fr' = t.country1::jsonb->>'fr' );
|
|
|
|
-- 5. Complete table marital_status
|
|
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->>'fr' = t.maritalstatus1::jsonb->>'fr' );
|
|
|
|
-- 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->>'fr' = t.household_composition_type1::jsonb->>'fr' );
|
|
|
|
-- 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->>'fr' = t.household_position1::jsonb->>'fr' );
|
|
|
|
-- 8. Complete table accompanying_period_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->>'fr' = t.closingmotive1::jsonb->>'fr' );
|
|
|
|
-- 9. Complete table accompanying_period_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->>'fr' = t.origin1::jsonb->>'fr' );
|
|
|
|
-- 10. Complete table 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->>'fr' = t.job1::jsonb->>'fr' );
|
|
|
|
-- 11. Complete table 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->>'fr' = t.acp_scopes1::jsonb->>'fr' );
|
|
-- SELECT i.acp_scopes1::jsonb, s.name FROM scopes s LEFT JOIN import.choix_periodes i ON s.name::jsonb = i.acp_scopes1::jsonb WHERE s.name IS NOT NULL or i.acp_scopes1 IS NOT NULL ;
|
|
|
|
-- 12. Complete table Users (acp referrer)
|
|
INSERT INTO users (id, username, password, enabled, locked, attributes, label)
|
|
SELECT nextval('users_id_seq'), t.referrer, '', false, false, '[]', t.referrer
|
|
FROM ( SELECT DISTINCT ON (referrer) referrer FROM import.choix_periodes WHERE referrer <> '') t
|
|
WHERE NOT EXISTS ( SELECT 1 FROM users WHERE username::text = t.referrer );
|
|
-- SELECT * FROM users;
|
|
|
|
-- 13. Complete table SocialIssues
|
|
ALTER TABLE import.choix_periodes ADD COLUMN parent1 jsonb;
|
|
UPDATE import.choix_periodes SET parent1=json_build_object('fr', upper(trim(parent))) WHERE parent !='';
|
|
ALTER TABLE import.choix_periodes ADD COLUMN enfant1 jsonb;
|
|
UPDATE import.choix_periodes SET enfant1=json_build_object('fr', upper(trim(enfant))) WHERE enfant !='';
|
|
WITH max_ordering AS ( SELECT MAX(ordering) as max_ordering FROM chill_person_social_issue )
|
|
INSERT INTO chill_person_social_issue (id, parent_id, title, ordering)
|
|
SELECT nextval('chill_person_social_issue_id_seq'),
|
|
null, t.parent1,
|
|
max_ordering.max_ordering + row_number() OVER () as ordering
|
|
FROM ( SELECT DISTINCT ON (parent) parent1 FROM import.choix_periodes WHERE parent1 IS NOT NULL ) t
|
|
CROSS JOIN max_ordering
|
|
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_social_issue WHERE title::jsonb->>'fr' = t.parent1::jsonb->>'fr' );
|
|
WITH max_ordering AS ( SELECT MAX(ordering) as max_ordering FROM chill_person_social_issue )
|
|
INSERT INTO chill_person_social_issue (id, parent_id, title, ordering)
|
|
SELECT nextval('chill_person_social_issue_id_seq'),
|
|
( SELECT id FROM chill_person_social_issue WHERE parent_id IS NULL AND title::jsonb->>'fr' = t.parent1::jsonb->>'fr' ), t.enfant1,
|
|
max_ordering.max_ordering + row_number() OVER () as ordering
|
|
FROM ( SELECT DISTINCT ON (acp_socialissues) parent1, enfant1 FROM import.choix_periodes WHERE enfant1 IS NOT NULL ) t
|
|
CROSS JOIN max_ordering
|
|
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_social_issue
|
|
WHERE title::jsonb->>'fr' = t.enfant1::jsonb->>'fr'
|
|
AND parent_id = (SELECT id FROM chill_person_social_issue WHERE title::jsonb->>'fr' = t.parent1::jsonb->>'fr'));
|
|
|
|
-- 14. Complete table WorkSocialActions
|
|
-- (not yet implemented in canvas)
|
|
|
|
-- 20. Prepare personnes civility
|
|
ALTER TABLE import.personnes ADD COLUMN civility1 jsonb;
|
|
UPDATE import.personnes SET civility1=json_build_object('fr', trim(civility)) WHERE civility!='';
|
|
-- SELECT i.civility, c.name as civility_name, c.id as civility_id FROM import.personnes i JOIN chill_main_civility c ON i.civility1::jsonb = c.name::jsonb;
|
|
|
|
-- 21. Prepare personnes gender
|
|
ALTER TABLE import.personnes ADD COLUMN gender1 VARCHAR;
|
|
UPDATE import.personnes SET gender1 = CASE
|
|
WHEN trim(gender) IN ('Femme', 'femme', 'Woman', 'woman', 'Female', 'female') THEN 'woman'
|
|
WHEN trim(gender) IN ('Homme', 'homme', 'Man', 'man', 'Male', 'male') THEN 'man'
|
|
WHEN trim(gender) IN ('', 'Inconnu', 'inconnu', 'Unknown', 'unknown') THEN 'unknown'
|
|
ELSE 'both' END;
|
|
|
|
-- 22. Prepare personnes nationality
|
|
ALTER TABLE import.personnes ADD COLUMN nationality1 jsonb;
|
|
UPDATE import.personnes SET nationality1=json_build_object('fr', trim(nationality)) WHERE nationality!='';
|
|
-- SELECT i.nationality, c.name as country_name, c.id as country_id FROM import.personnes i JOIN country c ON i.nationality1::jsonb = c.name::jsonb;
|
|
|
|
-- 23. Prepare personnes countryofbirth
|
|
ALTER TABLE import.personnes ADD COLUMN countryofbirth1 jsonb;
|
|
UPDATE import.personnes SET countryofbirth1=json_build_object('fr', trim(countryofbirth)) WHERE countryofbirth!='';
|
|
-- SELECT i.countryofbirth, c.name as country_name, c.id as country_id FROM import.personnes i JOIN country c ON i.countryofbirth1::jsonb = c.name::jsonb;
|
|
|
|
-- 24. Prepare personnes maritalstatus
|
|
ALTER TABLE import.personnes ADD COLUMN maritalstatus1 jsonb;
|
|
UPDATE import.personnes SET maritalstatus1=json_build_object('fr', trim(maritalstatus)) WHERE maritalstatus!='';
|
|
-- SELECT i.maritalstatus, ms.name as maritalstatus_name, ms.id as maritalstatus_id FROM import.personnes i JOIN chill_person_marital_status ms ON i.maritalstatus1::jsonb = ms.name::jsonb;
|
|
|
|
-- 25. Prepare personnes numberofchildren
|
|
ALTER TABLE import.personnes ADD COLUMN numberofchildren1 integer;
|
|
UPDATE import.personnes SET numberofchildren1=NULLIF(numberofchildren, '')::int;
|
|
-- SELECT numberofchildren, numberofchildren1 FROM import.personnes;
|
|
|
|
-- 26. Prepare personnes household_composition_type
|
|
ALTER TABLE import.personnes ADD COLUMN household_composition_type1 JSONB;
|
|
UPDATE import.personnes SET household_composition_type1=json_build_object('fr', trim(household_composition_type)) WHERE household_composition_type!='';
|
|
-- SELECT i.household_composition_type, cphct.id as household_compo_type_id, cphct.label as household_compo_type_label FROM import.personnes i JOIN chill_person_household_composition_type cphct ON i.household_composition_type1::jsonb = cphct.label::jsonb;
|
|
|
|
-- 27. Prepare personnes household_position
|
|
ALTER TABLE import.personnes ADD COLUMN household_position1 jsonb;
|
|
UPDATE import.personnes SET household_position1=json_build_object('fr', trim(household_position)) WHERE household_position!='';
|
|
-- SELECT i.household_position, hp.label as household_position_label, hp.id as household_position_id FROM import.personnes i JOIN chill_person_household_position hp ON i.household_position1::jsonb = hp.label::jsonb;
|
|
|
|
-- 28. Prepare periodes closingmotive
|
|
ALTER TABLE import.periodes ADD COLUMN closingmotive1 JSONB;
|
|
UPDATE import.periodes SET closingmotive1=json_build_object('fr', trim(closingmotive)) WHERE closingmotive!='';
|
|
-- SELECT i.closingmotive1, cm.id as closingmotive_id, cm.name as closingmotive_name FROM import.periodes i JOIN chill_person_accompanying_period_closingmotive cm ON i.closingmotive1::jsonb = cm.name::jsonb;
|
|
|
|
-- 29. Prepare periodes origin
|
|
ALTER TABLE import.periodes ADD COLUMN origin1 jsonb;
|
|
UPDATE import.periodes SET origin1=json_build_object('fr', trim(origin)) WHERE origin!='';
|
|
-- SELECT i.origin1, o.id as origin_id, o.label as origin_label FROM import.periodes i JOIN chill_person_accompanying_period_origin o ON i.origin1::jsonb = o.label::jsonb;
|
|
|
|
-- 30. Prepare periodes job
|
|
ALTER TABLE import.periodes ADD COLUMN job1 jsonb;
|
|
UPDATE import.periodes SET job1=json_build_object('fr', trim(job)) WHERE job!='';
|
|
-- SELECT i.job1, o.id as job_id, o.label as job_label FROM import.periodes i JOIN chill_main_user_job o ON i.job1::jsonb = o.label::jsonb;
|
|
|
|
-- 31. Prepare periodes acp_scopes
|
|
ALTER TABLE import.periodes ADD COLUMN acp_scopes1 jsonb;
|
|
UPDATE import.periodes SET acp_scopes1=json_build_object('fr', trim(acp_scopes)) WHERE acp_scopes!='';
|
|
-- SELECT i.acp_scopes1, s.id as scopes_id, s.name as scopes_name FROM import.periodes i JOIN scopes s ON i.acp_scopes1::jsonb = s.name::jsonb;
|
|
|
|
-- 32. Prepare periodes intensity
|
|
ALTER TABLE import.periodes ADD COLUMN intensity1 text;
|
|
UPDATE import.periodes SET intensity1='occasional'; UPDATE import.periodes SET intensity1='regular' WHERE intensity='regular';
|
|
|
|
-- 33-34. Format phones numbers
|
|
ALTER TABLE import.personnes ADD column mobilenumber1 text;
|
|
ALTER TABLE import.personnes ADD column phonenumber1 text;
|
|
DO $$
|
|
DECLARE
|
|
intl text := 32;
|
|
BEGIN
|
|
-- 33. Format mobile numbers
|
|
UPDATE import.personnes SET mobilenumber1=NULLIF(regexp_replace(mobilenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars
|
|
UPDATE import.personnes SET mobilenumber1 = CASE -- remove intl prefix
|
|
WHEN LEFT(mobilenumber1, 2) = '00' THEN substr(mobilenumber1, 5, length(mobilenumber1) - 4)
|
|
WHEN LEFT(mobilenumber1, 2) = intl THEN substr(mobilenumber1, 3, length(mobilenumber1) - 2)
|
|
ELSE regexp_replace(mobilenumber1, '^0', '') -- remove first 0 prefix
|
|
END;
|
|
UPDATE import.personnes SET mobilenumber1=regexp_replace(mobilenumber1, '(.*)', '+' || intl || '\1'); -- add intl prefix
|
|
|
|
-- 34. Format phone numbers
|
|
UPDATE import.personnes SET phonenumber1=NULLIF(regexp_replace(phonenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars
|
|
UPDATE import.personnes SET phonenumber1 = CASE -- remove intl prefix
|
|
WHEN LEFT(phonenumber1, 2) = '00' THEN substr(phonenumber1, 5, length(phonenumber1) - 4)
|
|
WHEN LEFT(phonenumber1, 2) = intl THEN substr(phonenumber1, 3, length(phonenumber1) - 2)
|
|
ELSE regexp_replace(phonenumber1, '^0', '') -- remove first 0 prefix
|
|
END;
|
|
UPDATE import.personnes SET phonenumber1=regexp_replace(phonenumber1, '(.*)', '+' || intl || '\1'); -- add intl prefix
|
|
--SELECT mobilenumber, mobilenumber1, phonenumber, phonenumber1 FROM import.personnes ORDER BY id;
|
|
END $$;
|
|
|
|
-- 40. Prepare id mapping before insertion
|
|
ALTER TABLE import.personnes ADD column person_id BIGINT;
|
|
UPDATE import.personnes SET person_id=personid
|
|
FROM (SELECT id, nextval('chill_person_person_id_seq') AS personid FROM import.personnes ORDER BY id) AS t
|
|
WHERE import.personnes.id = t.id;
|
|
|
|
-- 41. Insert in chill_person_person
|
|
INSERT INTO chill_person_person (
|
|
id
|
|
, nationality_id, countryofbirth_id, civility_id, maritalstatus_id
|
|
, firstname, lastname, birthdate, place_of_birth, memo, email, contactinfo, phonenumber, mobilenumber, numberofchildren, gender, deathdate, proxyaccompanyingperiodopenstate
|
|
, createdat, updatedat, createdby_id, updatedby_id
|
|
, center_id
|
|
, gendercomment_comment, gendercomment_userid, gendercomment_date
|
|
/*
|
|
, maritalstatusdate
|
|
, maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date
|
|
, acceptsms, acceptemail
|
|
*/
|
|
) SELECT
|
|
person_id -- id
|
|
, (SELECT c.id FROM country c WHERE c.name::jsonb->>'fr' = ip.nationality1::jsonb->>'fr' AND ip.nationality1 IS NOT NULL) -- nationality_id,
|
|
, (SELECT c.id FROM country c WHERE c.name::jsonb->>'fr' = ip.countryofbirth1::jsonb->>'fr' AND ip.countryofbirth1 IS NOT NULL ) -- countryofbirth_id,
|
|
, (SELECT c.id FROM chill_main_civility c WHERE c.name::jsonb->>'fr' = ip.civility1::jsonb->>'fr' AND ip.civility1 IS NOT NULL ) -- civility_id
|
|
, (SELECT ms.id FROM chill_person_marital_status ms WHERE ms.name::jsonb->>'fr' = ip.maritalstatus1::jsonb->>'fr' AND ip.maritalstatus1 IS NOT NULL ) -- maritalstatus_id,
|
|
, TRIM(firstname), UPPER(TRIM(lastname)), birthdate1, TRIM(place_of_birth), TRIM(memo), TRIM(email), TRIM(contactinfo), phonenumber1, mobilenumber1, numberofchildren1, gender1, deathdate1, false
|
|
, CURRENT_DATE, CURRENT_DATE -- createdat, updatedat (= import date)
|
|
, (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users) -- createdby_id, updatedby_id
|
|
, (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM centers) -- center_id
|
|
, TRIM(gendercomment), (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), date(date_trunc('year', CURRENT_DATE)) --gendercomment_<comment|userid|date>
|
|
/*
|
|
, -- maritalstatusdate
|
|
, -- maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date
|
|
, -- acceptsms, acceptemail
|
|
*/
|
|
FROM import.personnes ip;
|
|
|
|
-- 42. Fill Person center history
|
|
INSERT INTO chill_person_person_center_history (id, person_id, center_id, startdate) SELECT
|
|
nextval('chill_person_person_center_history_id_seq'), person_id,
|
|
(SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM centers) , -- center_id
|
|
date(date_trunc('year', CURRENT_DATE))
|
|
FROM import.personnes ip;
|
|
-- SELECT ip.id, ip.lastname, ip.firstname, ip.person_id, hist.id, hist.person_id, hist.center_id, hist.startdate, p.id, p.fullnamecanonical, p.email FROM chill_person_person p RIGHT JOIN import.personnes ip ON ip.person_id = p.id FULL JOIN chill_person_person_center_history hist on p.id = hist.person_id ORDER BY ip.person_id;
|
|
|
|
-- 43. Add address, and link it to person
|
|
ALTER TABLE import.personnes ADD column address_id BIGINT;
|
|
UPDATE import.personnes SET address_id = nextval('chill_main_address_id_seq');
|
|
ALTER TABLE import.personnes ADD column postcode_id BIGINT;
|
|
UPDATE import.personnes SET postcode_id = pc.id FROM chill_main_postal_code pc WHERE pc.code = postcode AND pc.origin = 0;
|
|
INSERT INTO chill_main_address (id, postcode_id, street, streetnumber, extra, validFrom) SELECT
|
|
address_id, postcode_id, street, streetnumber, extra, COALESCE(validfrom1 , date(date_trunc('year', CURRENT_DATE)))
|
|
FROM import.personnes WHERE postcode_id IS NOT NULL;
|
|
-- SELECT ip.person_id, ip.address_id FROM import.personnes ip ;
|
|
-- SELECT ip.id, ip.person_id, ip.firstname, ip.lastname, addr.* FROM chill_main_address addr RIGHT JOIN import.personnes ip ON addr.id = ip.address_id ORDER BY ip.id;
|
|
|
|
-- 44. Add houshold and household member with position
|
|
INSERT INTO chill_person_household (id) SELECT person_id from import.personnes;
|
|
SELECT setval('chill_person_household_id_seq', (SELECT max(id) FROM chill_person_household));
|
|
INSERT INTO chill_person_household_members (id, person_id, household_id, startdate, sharedhousehold, position_id, holder) SELECT
|
|
nextval('chill_person_household_members_id_seq'), person_id, person_id, COALESCE(household_startdate1, date(date_trunc('year', CURRENT_DATE))),
|
|
true, (SELECT id FROM chill_person_household_position pos WHERE household_position1::jsonb->>'fr' = pos.label::jsonb->>'fr'), false
|
|
FROM import.personnes;
|
|
-- SELECT ip.id, ip.person_id, ip.firstname, ip.lastname, hh.* FROM chill_person_household hh FULL JOIN import.personnes ip ON hh.id = ip.person_id ORDER BY hh.id;
|
|
-- SELECT ip.id, ip.person_id, ip.firstname, ip.lastname, memb.* FROM chill_person_household_members memb JOIN import.personnes ip ON memb.household_id = ip.person_id ORDER BY memb.household_id;
|
|
|
|
-- 45. Add address to household
|
|
INSERT INTO chill_person_household_to_addresses (household_id, address_id) SELECT person_id, address_id
|
|
FROM import.personnes WHERE postcode_id IS NOT NULL; -- cfr (*) adresse insérées seulement si postcode
|
|
|
|
-- 46. Add household composition
|
|
INSERT INTO chill_person_household_composition (id, household_id, startdate, householdcompositiontype_id) SELECT
|
|
nextval('chill_person_household_composition_id_seq'), person_id AS household_id, date(date_trunc('year', CURRENT_DATE))
|
|
, (SELECT id FROM chill_person_household_composition_type ct WHERE household_composition_type1::jsonb->>'fr' = ct.label::jsonb->>'fr')
|
|
FROM import.personnes
|
|
WHERE household_composition_type1 IS NOT NULL ;
|
|
|
|
|
|
-- ========================================================================================= --
|
|
|
|
--
|
|
-- DOWN
|
|
--
|
|
|
|
-- Undo 46.
|
|
DELETE FROM chill_person_household_composition c USING import.personnes ip WHERE c.household_id = ip.person_id;
|
|
SELECT setval('chill_person_household_composition_id_seq', (SELECT max(id) FROM chill_person_household_composition));
|
|
|
|
-- Undo 45.
|
|
DELETE FROM chill_person_household_to_addresses hhaddr USING import.personnes ip WHERE hhaddr.household_id = ip.person_id ;
|
|
|
|
-- Undo 44.
|
|
DELETE FROM chill_person_household_members memb USING import.personnes ip WHERE memb.person_id = ip.person_id;
|
|
SELECT setval('chill_person_household_members_id_seq', (SELECT max(id) FROM chill_person_household_members));
|
|
DELETE FROM chill_person_household hh USING import.personnes ip WHERE hh.id = ip.person_id;
|
|
SELECT setval('chill_person_household_id_seq', (SELECT max(id) FROM chill_person_household));
|
|
|
|
-- Undo 43.
|
|
DELETE FROM chill_main_address addr USING import.personnes ip WHERE addr.id = ip.address_id;
|
|
SELECT setval('chill_main_address_id_seq', (SELECT max(id) FROM chill_main_address));
|
|
ALTER TABLE import.personnes DROP column postcode_id;
|
|
ALTER TABLE import.personnes DROP column address_id;
|
|
|
|
-- Undo 42.
|
|
DELETE FROM chill_person_person_center_history hist USING import.personnes ip WHERE hist.person_id = ip.person_id;
|
|
SELECT setval('chill_person_person_center_history_id_seq', (SELECT max(id) FROM chill_person_person_center_history));
|
|
|
|
-- Undo 41.
|
|
DELETE FROM chill_person_person p USING import.personnes ip WHERE p.id = ip.person_id;
|
|
SELECT setval('chill_person_person_id_seq', (SELECT max(id) FROM chill_person_person));
|
|
|
|
-- Undo 40.
|
|
ALTER TABLE import.personnes DROP COLUMN person_id;
|
|
|
|
-- Undo 34.
|
|
ALTER TABLE import.personnes DROP column phonenumber1;
|
|
|
|
-- Undo 33.
|
|
ALTER TABLE import.personnes DROP column mobilenumber1;
|
|
|
|
-- Undo 32.
|
|
ALTER TABLE import.periodes DROP COLUMN intensity1;
|
|
|
|
-- Undo 31.
|
|
ALTER TABLE import.periodes DROP COLUMN acp_scopes1;
|
|
|
|
-- Undo 30.
|
|
ALTER TABLE import.periodes DROP COLUMN job1;
|
|
|
|
-- Undo 29.
|
|
ALTER TABLE import.periodes DROP COLUMN origin1;
|
|
|
|
-- Undo 28.
|
|
ALTER TABLE import.periodes DROP COLUMN closingmotive1;
|
|
|
|
-- Undo 27.
|
|
ALTER TABLE import.personnes DROP COLUMN household_position1;
|
|
|
|
-- Undo 26.
|
|
ALTER TABLE import.personnes DROP COLUMN household_composition_type1;
|
|
|
|
-- Undo 25.
|
|
ALTER TABLE import.personnes DROP COLUMN numberofchildren1;
|
|
|
|
-- Undo 24.
|
|
ALTER TABLE import.personnes DROP COLUMN maritalstatus1;
|
|
|
|
-- Undo 23.
|
|
ALTER TABLE import.personnes DROP COLUMN countryofbirth1;
|
|
|
|
-- Undo 22.
|
|
ALTER TABLE import.personnes DROP COLUMN nationality1;
|
|
|
|
-- Undo 21.
|
|
ALTER TABLE import.personnes DROP COLUMN gender1;
|
|
|
|
-- Undo 20.
|
|
ALTER TABLE import.personnes DROP COLUMN civility1;
|
|
|
|
-- Undo 14.
|
|
|
|
-- Undo 13.
|
|
DELETE FROM chill_person_social_issue USING import.choix_periodes i
|
|
WHERE parent_id IN ( SELECT id FROM chill_person_social_issue cpsi WHERE cpsi.title::jsonb = i.parent1::jsonb AND cpsi.parent_id IS NULL );
|
|
DELETE FROM chill_person_social_issue cpsi USING import.choix_periodes icp WHERE cpsi.title::jsonb = icp.parent1::jsonb AND cpsi.parent_id IS NULL ;
|
|
SELECT setval('chill_person_social_issue_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_social_issue));
|
|
ALTER TABLE import.choix_periodes DROP COLUMN enfant1;
|
|
ALTER TABLE import.choix_periodes DROP COLUMN parent1;
|
|
|
|
-- Undo 12.
|
|
DELETE FROM users USING import.choix_periodes icp WHERE users.username::text = icp.referrer::text AND users.password = '' AND users.enabled = false;
|
|
SELECT setval('users_id_seq', (SELECT COALESCE(max(id),1) FROM users));
|
|
|
|
-- Undo 11.
|
|
DELETE FROM scopes USING import.choix_periodes icp WHERE scopes.name::jsonb = icp.acp_scopes1::jsonb;
|
|
SELECT setval('scopes_id_seq', (SELECT COALESCE(max(id),1) 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 COALESCE(max(id),1) 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 COALESCE(max(id),1) 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 COALESCE(max(id),1) 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 COALESCE(max(id),1) 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 COALESCE(max(id),1) 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 COALESCE(max(id),1) 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 COALESCE(max(id),1) 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;
|
|
|
|
|
|
-- -------------
|
|
-- tiers choices_list: civility kind profession category
|
|
|
|
-- =============
|
|
-- QUESTIONS
|
|
--
|
|
-- définir par défaut: quel user, quel centre ?
|
|
--
|