From 25510c1efe243ed823db4a159e500582c5a0b12a Mon Sep 17 00:00:00 2001 From: Mathieu Jaumotte Date: Wed, 1 Mar 2023 19:17:09 +0100 Subject: [PATCH] fix query for person insertion --- sql/import.sql | 88 +++++++++++++++++++++----------------------------- 1 file changed, 37 insertions(+), 51 deletions(-) diff --git a/sql/import.sql b/sql/import.sql index 7aea248..ce8b604 100644 --- a/sql/import.sql +++ b/sql/import.sql @@ -172,7 +172,6 @@ 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!=''; @@ -215,65 +214,45 @@ UPDATE import.periodes SET intensity1='occasional'; UPDATE import.periodes SET i -- 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 ( id , nationality_id, countryofbirth_id, civility_id, maritalstatus_id - , firstname, lastname - , birthdate, place_of_birth - , memo, email, contactinfo - , phonenumber, mobilenumber - , numberofchildren - , gender - , deathdate + , firstname, lastname, birthdate, place_of_birth, memo, email, contactinfo, phonenumber, mobilenumber, numberofchildren, gender, deathdate, proxyaccompanyingperiodopenstate + , createdat, updatedat, createdby_id, updatedby_id + , center_id /* - maritalstatusdate - acceptsms - acceptemail - gendercomment_comment - gendercomment_userid - gendercomment_date - maritalstatuscomment_comment - maritalstatuscomment_userid - maritalstatuscomment_date - createdat - updatedat - createdby_id - updatedby_id - center_id + , maritalstatusdate + , maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date + , gendercomment_comment, gendercomment_userid, gendercomment_date + , acceptsms, acceptemail */ ) SELECT - 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 as country_id FROM import.personnes i JOIN country c ON i.countryofbirth1::jsonb = c.name::jsonb) -- 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 ms.id as maritalstatus_id FROM import.personnes i JOIN chill_person_marital_status ms ON i.maritalstatus1::jsonb = ms.name::jsonb) -- maritalstatus_id, - , firstname, lastname -- firstname, -- lastname, - , birthdate1, place_of_birth -- birthdate, -- place_of_birth, - , memo, email, contactinfo -- memo, -- email, -- contactinfo, - , phonenumber , mobilenumber -- phonenumber, -- mobilenumber, - , numberofchildren1 -- numberofchildren, - , gender1 -- gender, - , deathdate1 -- deathdate, - FROM import.personnes; + person_id -- 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 FROM country c WHERE c.name::jsonb = ip.countryofbirth1::jsonb AND ip.countryofbirth1 IS NOT NULL ) -- countryofbirth_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 FROM chill_person_marital_status ms WHERE ms.name::jsonb = ip.maritalstatus1::jsonb 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 + , (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 /* - -- maritalstatusdate, - -- acceptsms, - -- acceptemail, - -- gendercomment_comment, - -- gendercomment_userid, - -- gendercomment_date, - -- maritalstatuscomment_comment, - -- maritalstatuscomment_userid, - -- maritalstatuscomment_date, - -- createdat, - -- updatedat, - -- createdby_id, - -- updatedby_id, - -- center_id, + , -- maritalstatusdate + , -- maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date + , -- gendercomment_comment, gendercomment_userid, gendercomment_date + , -- acceptsms, acceptemail */ +FROM import.personnes ip; + + --- lier civility, -- country, adresse, -- ajouter dans chill_person_accompanying_course @@ -284,6 +263,13 @@ INSERT INTO chill_person_person ( -- 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 32. ALTER TABLE import.periodes DROP COLUMN intensity1;