2023-02-15 13:56:04 +00:00
--
-- CHILL REPRISE DE DONNEES
2023-02-15 16:54:26 +00:00
-- version v0.6 (== version canevas)
2023-02-15 13:56:04 +00:00
--
2023-02-15 16:54:26 +00:00
-- /!\ IMPORTANT
2023-03-08 16:49:13 +00:00
-- Avant de migrer (UP), il faut d'abord avoir importé les codes postaux !!!
2023-02-15 13:56:04 +00:00
--
2023-03-01 19:57:25 +00:00
2023-02-15 16:54:26 +00:00
-- 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 ) ;
2023-02-15 13:56:04 +00:00
--
-- UP
--
2023-02-15 19:21:26 +00:00
-- 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
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM chill_main_civility WHERE name : : jsonb - > > ' fr ' = t . civility1 : : jsonb - > > ' fr ' ) ;
2023-02-15 19:21:26 +00:00
2023-02-15 19:56:50 +00:00
-- 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 )
2023-02-16 18:42:34 +00:00
SELECT nextval ( ' country_id_seq ' ) , t . country1 , ' ZZ '
2023-02-15 19:56:50 +00:00
FROM ( SELECT DISTINCT ON ( country ) country1 FROM import . choix_personnes WHERE country1 IS NOT NULL ) t
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM country WHERE name : : jsonb - > > ' fr ' = t . country1 : : jsonb - > > ' fr ' ) ;
2023-02-15 19:21:26 +00:00
2023-02-17 18:42:14 +00:00
-- 5. Complete table marital_status
2023-02-15 20:28:13 +00:00
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
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_marital_status WHERE name : : jsonb - > > ' fr ' = t . maritalstatus1 : : jsonb - > > ' fr ' ) ;
2023-02-15 19:21:26 +00:00
2023-02-15 20:40:40 +00:00
-- 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
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_household_composition_type WHERE label : : jsonb - > > ' fr ' = t . household_composition_type1 : : jsonb - > > ' fr ' ) ;
2023-02-15 20:40:40 +00:00
2023-02-15 20:57:36 +00:00
-- 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
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_household_position WHERE label : : jsonb - > > ' fr ' = t . household_position1 : : jsonb - > > ' fr ' ) ;
2023-02-15 13:56:04 +00:00
2023-02-17 18:42:14 +00:00
-- 8. Complete table accompanying_period_closingmotive
2023-02-16 17:28:36 +00:00
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
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_accompanying_period_closingmotive WHERE name : : jsonb - > > ' fr ' = t . closingmotive1 : : jsonb - > > ' fr ' ) ;
2023-02-16 17:28:36 +00:00
2023-02-17 18:42:14 +00:00
-- 9. Complete table accompanying_period_origin
2023-02-17 08:43:37 +00:00
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
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_accompanying_period_origin WHERE label : : jsonb - > > ' fr ' = t . origin1 : : jsonb - > > ' fr ' ) ;
2023-02-16 17:28:36 +00:00
2023-02-17 18:42:14 +00:00
-- 10. Complete table user_job
2023-02-16 18:42:34 +00:00
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
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM chill_main_user_job WHERE label : : jsonb - > > ' fr ' = t . job1 : : jsonb - > > ' fr ' ) ;
2023-02-16 18:42:34 +00:00
2023-02-17 18:42:14 +00:00
-- 11. Complete table Scopes
2023-02-17 08:49:16 +00:00
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
2023-03-08 20:05:06 +00:00
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 ;
2023-02-16 18:42:34 +00:00
2023-02-17 18:42:14 +00:00
-- 12. Complete table Users (acp referrer)
2023-02-17 16:53:54 +00:00
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 ) ;
2023-03-08 20:05:06 +00:00
-- SELECT * FROM users;
2023-02-16 18:42:34 +00:00
2023-02-17 18:42:14 +00:00
-- 13. Complete table SocialIssues
2023-02-17 18:15:55 +00:00
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
2023-03-08 20:05:06 +00:00
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_social_issue WHERE title : : jsonb - > > ' fr ' = t . parent1 : : jsonb - > > ' fr ' ) ;
2023-02-17 18:15:55 +00:00
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 ' ) ,
2023-03-08 20:05:06 +00:00
( SELECT id FROM chill_person_social_issue WHERE parent_id IS NULL AND title : : jsonb - > > ' fr ' = t . parent1 : : jsonb - > > ' fr ' ) , t . enfant1 ,
2023-02-17 18:15:55 +00:00
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
2023-03-08 20:05:06 +00:00
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 ' ) ) ;
2023-02-17 18:15:55 +00:00
2023-02-17 18:42:14 +00:00
-- 14. Complete table WorkSocialActions
2023-03-08 16:49:13 +00:00
-- (not yet implemented in canvas)
2023-02-16 18:42:34 +00:00
2023-02-19 13:58:11 +00:00
-- 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
2023-03-10 11:16:51 +00:00
WHEN trim ( gender ) IN ( ' Femme ' , ' femme ' , ' Woman ' , ' woman ' , ' Female ' , ' female ' ) THEN ' woman '
2023-02-19 13:58:11 +00:00
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 ;
2023-03-01 16:34:47 +00:00
UPDATE import . personnes SET numberofchildren1 = NULL IF ( numberofchildren , ' ' ) : : int ;
-- SELECT numberofchildren, numberofchildren1 FROM import.personnes;
2023-02-19 13:58:11 +00:00
-- 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 ' ;
2023-03-10 11:16:51 +00:00
-- 33-34. Format phones numbers
2023-03-01 19:57:25 +00:00
ALTER TABLE import . personnes ADD column mobilenumber1 text ;
ALTER TABLE import . personnes ADD column phonenumber1 text ;
2023-03-10 11:16:51 +00:00
DO $ $
DECLARE
intl text : = 32 ;
BEGIN
-- 33. Format mobile numbers
UPDATE import . personnes SET mobilenumber1 = NULL IF ( 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 = NULL IF ( 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 $ $ ;
2023-02-19 13:58:11 +00:00
2023-03-01 18:17:09 +00:00
-- 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
2023-02-19 13:58:11 +00:00
INSERT INTO chill_person_person (
id
, nationality_id , countryofbirth_id , civility_id , maritalstatus_id
2023-03-01 18:17:09 +00:00
, firstname , lastname , birthdate , place_of_birth , memo , email , contactinfo , phonenumber , mobilenumber , numberofchildren , gender , deathdate , proxyaccompanyingperiodopenstate
, createdat , updatedat , createdby_id , updatedby_id
, center_id
2023-03-10 11:45:23 +00:00
, gendercomment_comment , gendercomment_userid , gendercomment_date
2023-02-19 13:58:11 +00:00
/*
2023-03-01 18:17:09 +00:00
, maritalstatusdate
, maritalstatuscomment_comment , maritalstatuscomment_userid , maritalstatuscomment_date
, acceptsms , acceptemail
2023-02-19 13:58:11 +00:00
* /
) SELECT
2023-03-01 18:17:09 +00:00
person_id -- id
2023-03-08 20:05:06 +00:00
, ( 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,
2023-03-01 18:17:09 +00:00
, TRIM ( firstname ) , UPPER ( TRIM ( lastname ) ) , birthdate1 , TRIM ( place_of_birth ) , TRIM ( memo ) , TRIM ( email ) , TRIM ( contactinfo ) , phonenumber1 , mobilenumber1 , numberofchildren1 , gender1 , deathdate1 , false
2023-03-10 12:08:41 +00:00
, CURRENT_DATE , CURRENT_DATE -- createdat, updatedat (= import date)
2023-03-01 18:17:09 +00:00
, ( 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
2023-03-10 12:08:41 +00:00
, TRIM ( gendercomment ) , ( SELECT distinct ( first_value ( id ) OVER ( ORDER BY id ) ) FROM users ) , date ( date_trunc ( ' year ' , CURRENT_DATE ) ) - - gendercomment_ < comment | userid | date >
2023-02-19 13:58:11 +00:00
/*
2023-03-01 18:17:09 +00:00
, -- maritalstatusdate
, -- maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date
, -- acceptsms, acceptemail
2023-02-19 13:58:11 +00:00
* /
2023-03-01 18:17:09 +00:00
FROM import . personnes ip ;
2023-03-10 16:53:05 +00:00
SELECT setval ( ' chill_person_person_id_seq ' , ( SELECT COALESCE ( max ( id ) ) FROM chill_person_person ) ) ;
2023-03-01 18:17:09 +00:00
2023-03-08 22:44:39 +00:00
-- 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
2023-03-10 12:08:41 +00:00
date ( date_trunc ( ' year ' , CURRENT_DATE ) )
2023-03-08 22:44:39 +00:00
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
2023-03-01 20:20:19 +00:00
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 ;
2023-03-10 15:16:27 +00:00
UPDATE import . personnes SET postcode_id = pc . id FROM chill_main_postal_code pc WHERE pc . code = postcode AND pc . origin = 0 ;
2023-03-01 20:20:19 +00:00
INSERT INTO chill_main_address ( id , postcode_id , street , streetnumber , extra , validFrom ) SELECT
2023-03-10 12:08:41 +00:00
address_id , postcode_id , street , streetnumber , extra , COALESCE ( validfrom1 , date ( date_trunc ( ' year ' , CURRENT_DATE ) ) )
2023-03-08 16:49:13 +00:00
FROM import . personnes WHERE postcode_id IS NOT NULL ;
2023-03-10 16:53:05 +00:00
SELECT setval ( ' chill_main_address_id_seq ' , ( SELECT COALESCE ( max ( id ) ) FROM chill_main_address ) ) ;
2023-03-10 15:16:27 +00:00
-- SELECT ip.person_id, ip.address_id FROM import.personnes ip ;
2023-03-08 16:49:13 +00:00
-- 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;
2023-02-19 13:58:11 +00:00
2023-03-08 22:44:39 +00:00
-- 44. Add houshold and household member with position
2023-03-08 20:06:33 +00:00
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
2023-03-10 12:08:41 +00:00
nextval ( ' chill_person_household_members_id_seq ' ) , person_id , person_id , COALESCE ( household_startdate1 , date ( date_trunc ( ' year ' , CURRENT_DATE ) ) ) ,
2023-03-08 20:06:33 +00:00
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;
2023-03-10 16:53:05 +00:00
-- 45. Link address to household
2023-03-08 20:06:33 +00:00
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
2023-03-08 22:44:39 +00:00
-- 46. Add household composition
2023-03-10 15:17:27 +00:00
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 ;
2023-02-19 13:58:11 +00:00
2023-03-11 09:49:57 +00:00
2023-03-10 16:51:58 +00:00
-- 50. Prepare id mapping before insertion
ALTER TABLE import . periodes ADD column period_id BIGINT ;
UPDATE import . periodes SET period_id = periodid
FROM ( SELECT id , nextval ( ' chill_person_accompanying_period_id_seq ' ) AS periodid FROM import . periodes ORDER BY id ) AS t
WHERE import . periodes . id = t . id ;
- - SELECT ipe . id , ipe . fullname , ipe . period_id , ip . id , ip . person_id FROM import . periodes ipe JOIN import . personnes ip ON ipe . id = ip . id ORDER BY ipe . id ;
-- 51. Insert in chill_person_accompanying_period
2023-03-10 18:58:25 +00:00
INSERT INTO chill_person_accompanying_period ( id , openingdate , closingdate , step , remark , intensity , createdby_id , createdat , updatedby_id , updatedat ) SELECT
2023-03-11 09:49:57 +00:00
period_id ,
COALESCE ( openingdate1 , date ( date_trunc ( ' year ' , CURRENT_DATE ) ) ) , closingdate1 ,
2023-03-10 18:58:25 +00:00
' CONFIRMED ' , COALESCE ( TRIM ( remark ) , ' ' ) , intensity1 ,
2023-03-10 16:51:58 +00:00
( SELECT distinct ( first_value ( id ) OVER ( ORDER BY id ) ) FROM users ) , CURRENT_DATE ,
( SELECT distinct ( first_value ( id ) OVER ( ORDER BY id ) ) FROM users ) , CURRENT_DATE
FROM import . periodes ;
2023-03-10 16:53:05 +00:00
SELECT setval ( ' chill_person_accompanying_period_id_seq ' , ( SELECT max ( id ) FROM chill_person_accompanying_period ) ) ;
2023-02-19 13:58:11 +00:00
2023-03-10 17:32:09 +00:00
-- 52. Link participations to periods
INSERT INTO chill_person_accompanying_period_participation ( id , person_id , accompanyingperiod_id , startdate ) SELECT
nextval ( ' chill_person_accompanying_period_participation_id_seq ' ) , t . person_id , t . period_id , date ( date_trunc ( ' year ' , CURRENT_DATE ) )
FROM ( SELECT person_id , period_id FROM import . periodes ip JOIN import . personnes p ON ip . id = p . id ORDER BY person_id ) AS t ;
2023-03-10 18:27:31 +00:00
-- 53. Prepare temporary address location
INSERT INTO chill_main_address ( id , postcode_id , street , streetnumber , validFrom ) SELECT
nextval ( ' chill_main_address_id_seq ' ) ,
( SELECT pc . id FROM chill_main_postal_code pc WHERE pc . code = postcode ) ,
street , streetnumber , date ( date_trunc ( ' year ' , CURRENT_DATE ) )
FROM import . choix_periodes WHERE street ! = ' ' ;
ALTER TABLE import . choix_periodes ADD COLUMN address_location_id BIGINT ;
UPDATE import . choix_periodes SET address_location_id = ( SELECT max ( id ) FROM chill_main_address ) WHERE street ! = ' ' ;
2023-03-11 14:27:56 +00:00
-- 54. Link person or temporary address location to periods
2023-03-10 18:27:31 +00:00
UPDATE chill_person_accompanying_period acp
SET addresslocation_id = ( SELECT address_location_id FROM import . choix_periodes WHERE address_location_id IS NOT NULL LIMIT 1 )
FROM import . personnes pson JOIN import . periodes piod ON pson . id = piod . id
WHERE piod . period_id = acp . id AND piod . addresslocation = ' oui ' ;
UPDATE chill_person_accompanying_period acp
SET personlocation_id = pson . person_id
FROM import . personnes pson JOIN import . periodes piod ON pson . id = piod . id
WHERE piod . period_id = acp . id AND piod . personlocation = ' oui ' ;
2023-03-10 18:58:25 +00:00
-- 55. Copy period in period_location_history
INSERT INTO chill_person_accompanying_period_location_history ( id , period_id , startdate , enddate , personlocation_id , addresslocation_id , createdat , createdby_id )
SELECT
nextval ( ' chill_person_accompanying_period_location_history_id_seq ' ) , id , acp . openingdate , acp . closingdate ,
acp . personlocation_id , acp . addresslocation_id , acp . createdat , acp . createdby_id
FROM chill_person_accompanying_period acp
WHERE id NOT IN ( SELECT period_id FROM chill_person_accompanying_period_location_history ) AND step LIKE ' CONFIRMED ' ORDER BY id ;
2023-03-11 09:49:57 +00:00
-- 56. Link socialIssues to periods
INSERT INTO chill_person_accompanying_period_social_issues ( accompanyingperiod_id , socialissue_id )
SELECT
DISTINCT ON ( t . period_id ) t . period_id ,
2023-03-11 15:50:11 +00:00
COALESCE (
t . enfant_id ,
t . parent_id ,
1 -- default value ?
) AS socialissue_id
2023-03-11 09:49:57 +00:00
FROM (
SELECT p . period_id ,
( SELECT id FROM chill_person_social_issue WHERE title : : jsonb - > > ' fr ' = icp . parent1 : : jsonb - > > ' fr ' AND parent_id IS NULL ) AS parent_id , icp . parent1 ,
( SELECT id FROM chill_person_social_issue WHERE title : : jsonb - > > ' fr ' = icp . enfant1 : : jsonb - > > ' fr ' AND parent_id =
( SELECT id FROM chill_person_social_issue WHERE title : : jsonb - > > ' fr ' = icp . parent1 : : jsonb - > > ' fr ' AND parent_id IS NULL ) ) AS enfant_id , icp . enfant1
FROM import . periodes p
JOIN import . choix_periodes icp ON p . acp_socialissues = icp . acp_socialissues
ORDER BY id ) AS t ;
2023-03-11 12:39:42 +00:00
-- 57. Link referrer to periods
UPDATE chill_person_accompanying_period acp
2023-03-11 15:50:11 +00:00
SET user_id = COALESCE (
( SELECT id FROM users WHERE users . username = ip . referrer ) ,
1 -- default value ?
)
2023-03-11 12:39:42 +00:00
FROM import . periodes ip WHERE acp . id = ip . period_id ;
- - SELECT ip . id , ( SELECT id FROM users WHERE users . username = ip . referrer ) AS referrer_id , ip . referrer , acp . id as period_id , acp . user_id FROM chill_person_accompanying_period acp JOIN import . periodes ip ON ip . period_id = acp . id ORDER BY ip . id ;
2023-03-11 09:49:57 +00:00
2023-03-11 14:11:47 +00:00
-- 58. Link scopes to periods
INSERT INTO accompanying_periods_scopes ( accompanying_period_id , scope_id )
SELECT ip . period_id , COALESCE (
( SELECT id FROM scopes s WHERE ip . acp_scopes1 : : jsonb - > > ' fr ' = s . name : : jsonb - > > ' fr ' ) ,
2023-03-11 15:50:11 +00:00
( SELECT id from scopes s WHERE s . name : : jsonb - > > ' fr ' = ' tous ' ) -- default value 'tous'
2023-03-11 14:11:47 +00:00
)
FROM import . periodes ip ;
-- 59. Link origin to periods
UPDATE chill_person_accompanying_period acp SET origin_id =
2023-03-11 14:27:56 +00:00
( SELECT id FROM chill_person_accompanying_period_origin o WHERE o . label : : jsonb - > > ' fr ' = ip . origin1 : : jsonb - > > ' fr ' )
2023-03-11 14:11:47 +00:00
FROM import . periodes ip WHERE acp . id = ip . period_id ;
- - SELECT ip . id , ip . origin1 , acp . id as period_id , acp . origin_id FROM chill_person_accompanying_period acp JOIN import . periodes ip ON ip . period_id = acp . id ORDER BY ip . id ;
2023-03-11 14:27:56 +00:00
-- 60. Link jobs to periods
UPDATE chill_person_accompanying_period acp SET job_id =
( SELECT id FROM chill_main_user_job j WHERE j . label : : jsonb - > > ' fr ' = ip . job1 : : jsonb - > > ' fr ' )
FROM import . periodes ip WHERE acp . id = ip . period_id ;
2023-03-10 18:27:31 +00:00
2023-03-08 16:49:13 +00:00
-- ========================================================================================= --
2023-02-19 13:58:11 +00:00
2023-02-15 13:56:04 +00:00
--
-- DOWN
--
2023-03-11 14:27:56 +00:00
-- Undo 60.
UPDATE chill_person_accompanying_period acp SET job_id = null FROM import . periodes ip WHERE acp . id = ip . period_id ;
2023-03-11 09:49:57 +00:00
-- Undo 59.
2023-03-11 13:08:56 +00:00
UPDATE chill_person_accompanying_period acp SET origin_id = null FROM import . periodes ip WHERE ip . period_id = acp . id ;
2023-03-11 09:49:57 +00:00
-- Undo 58.
2023-03-11 14:11:47 +00:00
DELETE FROM accompanying_periods_scopes acs USING import . periodes ip WHERE acs . accompanying_period_id = ip . period_id ;
2023-03-11 09:49:57 +00:00
-- Undo 57.
2023-03-11 12:39:42 +00:00
UPDATE chill_person_accompanying_period acp SET user_id = null FROM import . periodes ip WHERE ip . period_id = acp . id ;
2023-03-11 09:49:57 +00:00
-- Undo 56.
DELETE FROM chill_person_accompanying_period_social_issues asi USING import . periodes ip WHERE asi . accompanyingperiod_id = ip . period_id ;
2023-03-10 18:58:25 +00:00
-- Undo 55.
DELETE FROM chill_person_accompanying_period_location_history history USING import . periodes ip WHERE history . period_id = ip . period_id ;
SELECT setval ( ' chill_person_accompanying_period_location_history_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_accompanying_period_location_history ) ) ;
2023-03-10 18:27:31 +00:00
-- Undo 54.
UPDATE chill_person_accompanying_period acp SET addresslocation_id = NULL , personlocation_id = NULL FROM import . periodes piod WHERE piod . period_id = acp . id ;
-- Undo 53.
DELETE FROM chill_main_address addr USING import . choix_periodes ic WHERE addr . id = ic . address_location_id ;
SELECT setval ( ' chill_main_address_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_main_address ) ) ;
ALTER TABLE import . choix_periodes DROP COLUMN address_location_id ;
2023-03-10 17:32:09 +00:00
-- Undo 52.
DELETE FROM chill_person_accompanying_period_participation part USING import . periodes ip WHERE part . accompanyingperiod_id = ip . period_id ;
SELECT setval ( ' chill_person_accompanying_period_participation_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_accompanying_period_participation ) ) ;
2023-03-10 16:51:58 +00:00
-- Undo 51.
DELETE FROM chill_person_accompanying_period acp USING import . periodes ip WHERE acp . id = ip . period_id ;
SELECT setval ( ' chill_person_accompanying_period_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_accompanying_period ) ) ;
-- Undo 50.
ALTER TABLE import . periodes DROP column period_id ;
2023-03-10 15:17:27 +00:00
-- Undo 46.
DELETE FROM chill_person_household_composition c USING import . personnes ip WHERE c . household_id = ip . person_id ;
2023-03-10 15:18:51 +00:00
SELECT setval ( ' chill_person_household_composition_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_household_composition ) ) ;
2023-03-10 15:17:27 +00:00
2023-03-08 22:44:39 +00:00
-- Undo 45.
2023-03-10 15:18:51 +00:00
DELETE FROM chill_person_household_to_addresses hhaddr USING import . personnes ip WHERE hhaddr . household_id = ip . person_id ;
2023-03-08 20:06:33 +00:00
2023-03-08 22:44:39 +00:00
-- Undo 44.
2023-03-08 22:43:47 +00:00
DELETE FROM chill_person_household_members memb USING import . personnes ip WHERE memb . person_id = ip . person_id ;
2023-03-10 15:18:51 +00:00
SELECT setval ( ' chill_person_household_members_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_household_members ) ) ;
2023-03-08 22:43:47 +00:00
DELETE FROM chill_person_household hh USING import . personnes ip WHERE hh . id = ip . person_id ;
2023-03-10 15:18:51 +00:00
SELECT setval ( ' chill_person_household_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_household ) ) ;
2023-03-08 20:06:33 +00:00
2023-03-08 22:44:39 +00:00
-- Undo 43.
2023-03-08 22:43:47 +00:00
DELETE FROM chill_main_address addr USING import . personnes ip WHERE addr . id = ip . address_id ;
2023-03-10 15:18:51 +00:00
SELECT setval ( ' chill_main_address_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_main_address ) ) ;
2023-03-01 20:20:19 +00:00
ALTER TABLE import . personnes DROP column postcode_id ;
ALTER TABLE import . personnes DROP column address_id ;
2023-03-08 22:44:39 +00:00
-- Undo 42.
DELETE FROM chill_person_person_center_history hist USING import . personnes ip WHERE hist . person_id = ip . person_id ;
2023-03-10 15:18:51 +00:00
SELECT setval ( ' chill_person_person_center_history_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_person_center_history ) ) ;
2023-03-08 22:44:39 +00:00
2023-03-01 18:17:09 +00:00
-- Undo 41.
2023-03-08 22:43:47 +00:00
DELETE FROM chill_person_person p USING import . personnes ip WHERE p . id = ip . person_id ;
2023-03-10 15:18:51 +00:00
SELECT setval ( ' chill_person_person_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_person ) ) ;
2023-03-01 18:17:09 +00:00
-- Undo 40.
ALTER TABLE import . personnes DROP COLUMN person_id ;
2023-03-01 19:57:25 +00:00
-- Undo 34.
ALTER TABLE import . personnes DROP column phonenumber1 ;
-- Undo 33.
ALTER TABLE import . personnes DROP column mobilenumber1 ;
2023-02-19 13:58:11 +00:00
-- 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 ;
2023-02-17 18:42:14 +00:00
-- Undo 14.
2023-02-17 18:15:55 +00:00
-- Undo 13.
DELETE FROM chill_person_social_issue USING import . choix_periodes i
2023-03-10 15:20:58 +00:00
WHERE parent_id IN ( SELECT id FROM chill_person_social_issue cpsi WHERE cpsi . title : : jsonb - > > ' fr ' = i . parent1 : : jsonb - > > ' fr ' AND cpsi . parent_id IS NULL ) ;
DELETE FROM chill_person_social_issue cpsi USING import . choix_periodes icp WHERE cpsi . title : : jsonb - > > ' fr ' = icp . parent1 : : jsonb - > > ' fr ' AND cpsi . parent_id IS NULL ;
2023-02-17 18:15:55 +00:00
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 ;
2023-02-17 16:53:54 +00:00
-- 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 ) ) ;
2023-02-17 08:49:16 +00:00
-- Undo 11.
2023-03-10 15:49:12 +00:00
DELETE FROM scopes USING import . choix_periodes icp WHERE scopes . name : : jsonb - > > ' fr ' = icp . acp_scopes1 : : jsonb - > > ' fr '
AND NOT EXISTS ( SELECT 1 FROM import . choix_periodes WHERE scopes . name : : jsonb - > > ' fr ' = icp . acp_scopes1 : : jsonb - > > ' fr ' ) ;
2023-02-17 16:29:12 +00:00
SELECT setval ( ' scopes_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM scopes ) ) ;
2023-02-17 08:49:16 +00:00
ALTER TABLE import . choix_periodes DROP COLUMN acp_scopes1 ;
2023-02-16 18:42:34 +00:00
-- Undo 10.
2023-03-10 15:49:12 +00:00
DELETE FROM chill_main_user_job cmuj USING import . choix_periodes icp WHERE cmuj . label : : jsonb - > > ' fr ' = icp . job1 : : jsonb - > > ' fr '
AND NOT EXISTS ( SELECT 1 FROM import . choix_periodes WHERE cmuj . label : : jsonb - > > ' fr ' = icp . job1 : : jsonb - > > ' fr ' ) ;
2023-02-17 16:29:12 +00:00
SELECT setval ( ' chill_main_user_job_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_main_user_job ) ) ;
2023-02-16 18:42:34 +00:00
ALTER TABLE import . choix_periodes DROP COLUMN job1 ;
2023-02-17 08:43:37 +00:00
-- Undo 9.
2023-03-10 15:49:12 +00:00
DELETE FROM chill_person_accompanying_period_origin cpapo USING import . choix_periodes icp WHERE cpapo . label : : jsonb - > > ' fr ' = icp . origin1 : : jsonb - > > ' fr '
AND NOT EXISTS ( SELECT 1 FROM import . choix_periodes WHERE cpapo . label : : jsonb - > > ' fr ' = icp . origin1 : : jsonb - > > ' fr ' ) ;
2023-02-17 16:29:12 +00:00
SELECT setval ( ' chill_person_accompanying_period_origin_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_accompanying_period_origin ) ) ;
2023-02-17 08:43:37 +00:00
ALTER TABLE import . choix_periodes DROP COLUMN origin1 ;
2023-02-16 17:28:36 +00:00
-- Undo 8.
2023-03-10 15:49:12 +00:00
DELETE FROM chill_person_accompanying_period_closingmotive cpapcm USING import . choix_periodes icp WHERE cpapcm . name : : jsonb - > > ' fr ' = icp . closingmotive1 : : jsonb - > > ' fr '
AND NOT EXISTS ( SELECT 1 FROM import . choix_periodes WHERE cpapcm . name : : jsonb - > > ' fr ' = icp . closingmotive1 : : jsonb - > > ' fr ' ) ;
2023-02-17 16:29:12 +00:00
SELECT setval ( ' chill_person_accompanying_period_closingmotive_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_accompanying_period_closingmotive ) ) ;
2023-02-16 17:28:36 +00:00
ALTER TABLE import . choix_periodes DROP COLUMN closingmotive1 ;
2023-02-15 20:57:36 +00:00
-- Undo 7.
2023-03-10 15:49:12 +00:00
DELETE FROM chill_person_household_position cphp USING import . choix_personnes icp WHERE cphp . label : : jsonb - > > ' fr ' = icp . household_position1 : : jsonb - > > ' fr '
AND NOT EXISTS ( SELECT 1 FROM import . choix_personnes WHERE cphp . label : : jsonb - > > ' fr ' = icp . household_position1 : : jsonb - > > ' fr ' ) ;
2023-02-17 16:29:12 +00:00
SELECT setval ( ' chill_person_household_position_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_household_position ) ) ;
2023-02-15 20:57:36 +00:00
ALTER TABLE import . choix_personnes DROP COLUMN household_position1 ;
2023-02-15 20:40:40 +00:00
-- Undo 6.
2023-03-10 15:49:12 +00:00
DELETE FROM chill_person_household_composition_type cphct USING import . choix_personnes icp WHERE cphct . label : : jsonb - > > ' fr ' = icp . household_composition_type1 : : jsonb - > > ' fr '
AND NOT EXISTS ( SELECT 1 FROM import . choix_personnes WHERE cphct . label : : jsonb - > > ' fr ' = icp . household_composition_type1 : : jsonb - > > ' fr ' ) ;
2023-02-17 16:29:12 +00:00
SELECT setval ( ' chill_person_household_composition_type_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_person_household_composition_type ) ) ;
2023-02-15 20:40:40 +00:00
ALTER TABLE import . choix_personnes DROP COLUMN household_composition_type1 ;
2023-02-15 20:28:13 +00:00
-- Undo 5.
2023-03-10 15:49:12 +00:00
DELETE FROM chill_person_marital_status cpms USING import . choix_personnes icp WHERE cpms . name : : jsonb - > > ' fr ' = icp . maritalstatus1 : : jsonb - > > ' fr '
AND NOT EXISTS ( SELECT 1 FROM import . choix_personnes WHERE cpms . name : : jsonb - > > ' fr ' = icp . maritalstatus1 : : jsonb - > > ' fr ' ) ;
2023-02-15 20:40:40 +00:00
ALTER TABLE import . choix_personnes DROP COLUMN maritalstatus1 ;
2023-02-15 20:28:13 +00:00
2023-02-15 19:56:50 +00:00
-- Undo 4.
2023-03-10 15:20:58 +00:00
DELETE FROM country USING import . choix_personnes icp WHERE country . name : : jsonb - > > ' fr ' = icp . country1 : : jsonb - > > ' fr ' AND country . id > 249 ; -- 249 existing countries
2023-02-17 16:29:12 +00:00
SELECT setval ( ' country_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM country ) ) ;
2023-02-15 20:40:40 +00:00
ALTER TABLE import . choix_personnes DROP COLUMN country1 ;
2023-02-15 19:56:50 +00:00
2023-02-15 19:21:26 +00:00
-- Undo 3.
2023-03-10 15:49:12 +00:00
DELETE FROM chill_main_civility cmc USING import . choix_personnes ip WHERE cmc . name : : jsonb - > > ' fr ' = ip . civility1 : : jsonb - > > ' fr '
AND NOT EXISTS ( SELECT 1 FROM import . choix_personnes WHERE cmc . name : : jsonb - > > ' fr ' = ip . civility1 : : jsonb - > > ' fr ' ) ;
2023-02-17 16:29:12 +00:00
SELECT setval ( ' chill_main_civility_id_seq ' , ( SELECT COALESCE ( max ( id ) , 1 ) FROM chill_main_civility ) ) ;
2023-02-15 20:40:40 +00:00
ALTER TABLE import . choix_personnes DROP COLUMN civility1 ;
2023-02-15 19:21:26 +00:00
2023-02-15 17:08:06 +00:00
-- Undo 2.
2023-02-15 20:40:40 +00:00
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 ;
2023-02-15 17:08:06 +00:00
2023-02-15 13:56:04 +00:00
2023-02-15 19:21:26 +00:00
2023-03-08 20:06:33 +00:00
-- =============
-- QUESTIONS
--
-- définir par défaut: quel user, quel centre ?
--