Compare commits
3 Commits
b6f26900a7
...
139dd6209a
Author | SHA1 | Date | |
---|---|---|---|
139dd6209a | |||
25510c1efe | |||
a36ee22be6 |
115
sql/import.sql
115
sql/import.sql
@ -6,6 +6,7 @@
|
|||||||
-- * Avant de migrer (UP), il faut d'abord importer les codes postaux !!!
|
-- * Avant de migrer (UP), il faut d'abord importer les codes postaux !!!
|
||||||
--
|
--
|
||||||
|
|
||||||
|
|
||||||
-- 1. Adjust Type cast for id columns
|
-- 1. Adjust Type cast for id columns
|
||||||
ALTER TABLE import.personnes ALTER COLUMN id TYPE INTEGER USING (id::integer);
|
ALTER TABLE import.personnes ALTER COLUMN id TYPE INTEGER USING (id::integer);
|
||||||
ALTER TABLE import.periodes ALTER COLUMN id TYPE INTEGER USING (id::integer);
|
ALTER TABLE import.periodes ALTER COLUMN id TYPE INTEGER USING (id::integer);
|
||||||
@ -169,8 +170,8 @@ UPDATE import.personnes SET maritalstatus1=json_build_object('fr', trim(maritals
|
|||||||
|
|
||||||
-- 25. Prepare personnes numberofchildren
|
-- 25. Prepare personnes numberofchildren
|
||||||
ALTER TABLE import.personnes ADD COLUMN numberofchildren1 integer;
|
ALTER TABLE import.personnes ADD COLUMN numberofchildren1 integer;
|
||||||
UPDATE import.personnes SET numberofchildren1=to_number(trim(numberofchildren::text) ) WHERE numberofchildren!=''; -- <== case BOUM
|
UPDATE import.personnes SET numberofchildren1=NULLIF(numberofchildren, '')::int;
|
||||||
|
-- SELECT numberofchildren, numberofchildren1 FROM import.personnes;
|
||||||
|
|
||||||
-- 26. Prepare personnes household_composition_type
|
-- 26. Prepare personnes household_composition_type
|
||||||
ALTER TABLE import.personnes ADD COLUMN household_composition_type1 JSONB;
|
ALTER TABLE import.personnes ADD COLUMN household_composition_type1 JSONB;
|
||||||
@ -206,73 +207,64 @@ UPDATE import.periodes SET acp_scopes1=json_build_object('fr', trim(acp_scopes))
|
|||||||
ALTER TABLE import.periodes ADD COLUMN intensity1 text;
|
ALTER TABLE import.periodes ADD COLUMN intensity1 text;
|
||||||
UPDATE import.periodes SET intensity1='occasional'; UPDATE import.periodes SET intensity1='regular' WHERE intensity='regular';
|
UPDATE import.periodes SET intensity1='occasional'; UPDATE import.periodes SET intensity1='regular' WHERE intensity='regular';
|
||||||
|
|
||||||
|
-- 33. Format mobile numbers
|
||||||
|
ALTER TABLE import.personnes ADD column mobilenumber1 text;
|
||||||
|
UPDATE import.personnes SET mobilenumber1=NULLIF(regexp_replace(mobilenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars
|
||||||
|
UPDATE import.personnes SET mobilenumber1=regexp_replace(mobilenumber1, '^0', '') WHERE mobilenumber1 like '0%'; -- remove first 0 prefix
|
||||||
|
-- UPDATE import.personnes SET mobilenumber1=regexp_replace(mobilenumber1, '(.*)', '+32\1'); -- add belgium intl prefix
|
||||||
|
|
||||||
-- 33. Prepare required default dates
|
-- 34. Format phone numbers
|
||||||
|
ALTER TABLE import.personnes ADD column phonenumber1 text;
|
||||||
|
UPDATE import.personnes SET phonenumber1=NULLIF(regexp_replace(phonenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars
|
||||||
|
UPDATE import.personnes SET phonenumber1=regexp_replace(phonenumber1, '^0', '') WHERE phonenumber1 like '0%'; -- remove first 0 prefix
|
||||||
|
-- UPDATE import.personnes SET phonenumber1=regexp_replace(phonenumber1, '(.*)', '+32\1'); -- add belgium intl prefix
|
||||||
|
-- SELECT mobilenumber, mobilenumber1, phonenumber, phonenumber1 FROM import.personnes;
|
||||||
|
|
||||||
|
|
||||||
|
-- 35. Prepare required default dates
|
||||||
-- address_validfrom1 | household_startdate1
|
-- address_validfrom1 | household_startdate1
|
||||||
-- acp_openingdate1
|
-- acp_openingdate1
|
||||||
|
|
||||||
-- 34. Format phone numbers
|
|
||||||
-- phonenumber | mobilenumber
|
|
||||||
|
|
||||||
-- 40. insert in chill_person_person
|
-- 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 (
|
INSERT INTO chill_person_person (
|
||||||
id
|
id
|
||||||
, nationality_id, countryofbirth_id, civility_id, maritalstatus_id
|
, nationality_id, countryofbirth_id, civility_id, maritalstatus_id
|
||||||
, firstname, lastname
|
, firstname, lastname, birthdate, place_of_birth, memo, email, contactinfo, phonenumber, mobilenumber, numberofchildren, gender, deathdate, proxyaccompanyingperiodopenstate
|
||||||
, birthdate, place_of_birth
|
, createdat, updatedat, createdby_id, updatedby_id
|
||||||
, memo, email, contactinfo
|
, center_id
|
||||||
, phonenumber, mobilenumber
|
|
||||||
, numberofchildren
|
|
||||||
, gender
|
|
||||||
, deathdate
|
|
||||||
/*
|
/*
|
||||||
maritalstatusdate
|
, maritalstatusdate
|
||||||
acceptsms
|
, maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date
|
||||||
acceptemail
|
, gendercomment_comment, gendercomment_userid, gendercomment_date
|
||||||
gendercomment_comment
|
, acceptsms, acceptemail
|
||||||
gendercomment_userid
|
|
||||||
gendercomment_date
|
|
||||||
maritalstatuscomment_comment
|
|
||||||
maritalstatuscomment_userid
|
|
||||||
maritalstatuscomment_date
|
|
||||||
createdat
|
|
||||||
updatedat
|
|
||||||
createdby_id
|
|
||||||
updatedby_id
|
|
||||||
center_id
|
|
||||||
*/
|
*/
|
||||||
) SELECT
|
) SELECT
|
||||||
id -- id
|
person_id -- id
|
||||||
, (SELECT c.id as country_id FROM import.personnes i JOIN country c ON i.nationality1::jsonb = c.name::jsonb) -- nationality_id,
|
, (SELECT c.id FROM country c WHERE c.name::jsonb = ip.nationality1::jsonb AND ip.nationality1 IS NOT NULL) -- nationality_id,
|
||||||
, (SELECT c.id as country_id FROM import.personnes i JOIN country c ON i.countryofbirth1::jsonb = c.name::jsonb) -- countryofbirth_id,
|
, (SELECT c.id FROM country c WHERE c.name::jsonb = ip.countryofbirth1::jsonb AND ip.countryofbirth1 IS NOT NULL ) -- countryofbirth_id,
|
||||||
, (SELECT c.id as civility_id FROM import.personnes i JOIN chill_main_civility c ON i.civility1::jsonb = c.name::jsonb) -- civility_id
|
, (SELECT c.id FROM chill_main_civility c WHERE c.name::jsonb = ip.civility1::jsonb AND ip.civility1 IS NOT NULL ) -- civility_id
|
||||||
, (SELECT ms.id as maritalstatus_id FROM import.personnes i JOIN chill_person_marital_status ms ON i.maritalstatus1::jsonb = ms.name::jsonb) -- maritalstatus_id,
|
, (SELECT ms.id FROM chill_person_marital_status ms WHERE ms.name::jsonb = ip.maritalstatus1::jsonb AND ip.maritalstatus1 IS NOT NULL ) -- maritalstatus_id,
|
||||||
, firstname, lastname -- firstname, -- lastname,
|
, TRIM(firstname), UPPER(TRIM(lastname)), birthdate1, TRIM(place_of_birth), TRIM(memo), TRIM(email), TRIM(contactinfo), phonenumber1, mobilenumber1, numberofchildren1, gender1, deathdate1, false
|
||||||
, birthdate1, place_of_birth -- birthdate, -- place_of_birth,
|
, CURRENT_DATE, CURRENT_DATE -- createdat, updatedat
|
||||||
, memo, email, contactinfo -- memo, -- email, -- contactinfo,
|
, (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
|
||||||
, phonenumber , mobilenumber -- phonenumber, -- mobilenumber,
|
, (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM centers) -- center_id
|
||||||
, numberofchildren1 -- numberofchildren,
|
|
||||||
, gender1 -- gender,
|
|
||||||
, deathdate1 -- deathdate,
|
|
||||||
FROM import.personnes;
|
|
||||||
/*
|
/*
|
||||||
-- maritalstatusdate,
|
, -- maritalstatusdate
|
||||||
-- acceptsms,
|
, -- maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date
|
||||||
-- acceptemail,
|
, -- gendercomment_comment, gendercomment_userid, gendercomment_date
|
||||||
-- gendercomment_comment,
|
, -- acceptsms, acceptemail
|
||||||
-- gendercomment_userid,
|
|
||||||
-- gendercomment_date,
|
|
||||||
-- maritalstatuscomment_comment,
|
|
||||||
-- maritalstatuscomment_userid,
|
|
||||||
-- maritalstatuscomment_date,
|
|
||||||
-- createdat,
|
|
||||||
-- updatedat,
|
|
||||||
-- createdby_id,
|
|
||||||
-- updatedby_id,
|
|
||||||
-- center_id,
|
|
||||||
*/
|
*/
|
||||||
|
FROM import.personnes ip;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
-- lier civility,
|
|
||||||
-- country, adresse,
|
-- country, adresse,
|
||||||
-- ajouter dans chill_person_accompanying_course
|
-- ajouter dans chill_person_accompanying_course
|
||||||
|
|
||||||
@ -283,6 +275,19 @@ INSERT INTO chill_person_person (
|
|||||||
-- DOWN
|
-- DOWN
|
||||||
--
|
--
|
||||||
|
|
||||||
|
-- Undo 41.
|
||||||
|
DELETE FROM chill_person_person cpp USING import.personnes ip WHERE cpp.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.
|
-- Undo 32.
|
||||||
ALTER TABLE import.periodes DROP COLUMN intensity1;
|
ALTER TABLE import.periodes DROP COLUMN intensity1;
|
||||||
|
|
||||||
|
Loading…
Reference in New Issue
Block a user