From 20517a109b23953f24dee695b119c9a88f4ee1ba Mon Sep 17 00:00:00 2001 From: nobohan Date: Tue, 2 Sep 2025 12:42:29 +0200 Subject: [PATCH] Improved person import with the linkage to reference addresses --- sql/import.sql | 55 ++++++++++++++++++++++++++++++++++++++++++-------- 1 file changed, 47 insertions(+), 8 deletions(-) diff --git a/sql/import.sql b/sql/import.sql index 982f5d2..16768ba 100755 --- a/sql/import.sql +++ b/sql/import.sql @@ -299,16 +299,55 @@ INSERT INTO chill_person_person_center_history (id, person_id, center_id, startd -- 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 +-- a) add new columns ALTER TABLE import.personnes ADD column address_id BIGINT; +ALTER TABLE import.personnes ADD column address_ref_id BIGINT; +ALTER TABLE import.personnes ADD column postcode_arr BIGINT[]; + +-- special command to extract postcode values in text +ALTER TABLE import.personnes ADD COLUMN postcode1 TEXT; +UPDATE import.personnes SET postcode1=SUBSTRING(postcode FROM '\y\d{5}\y') WHERE postcode!=''; + +-- b) find and add postal code references. Check missing correspondances (if you can) +UPDATE import.personnes +SET postcode_arr = ( + SELECT array_agg(pc.id) + FROM chill_main_postal_code AS pc + WHERE pc.code = import.personnes.postcode1 + AND pc.origin = 0 +); +--SELECT * FROM import.personnes as ip WHERE ip.postcode_arr IS NULL -- missing correspondances + +-- c) find and add reference addresses. Check missing correspondances (if you can) +UPDATE import.personnes AS ip SET address_ref_id = cmar.id FROM chill_main_address_reference AS cmar +WHERE + cmar.postcode_id = ANY(ip.postcode_arr) + AND similarity(trim(ip.street), trim(cmar.street)) > 0.6 + AND trim(ip.streetnumber) = trim(cmar.streetnumber); +--SELECT * FROM import.personnes as ip WHERE ip.address_ref_id IS NULL -- missing correspondances + +-- d) fill new chill address 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::int = postcode::int 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; + +-- e) insert reference address into chill_main_addresses +INSERT INTO chill_main_address (id, postcode_id, street, streetnumber, extra, validFrom, addressreference_id, refstatus, point, createdat, updatedat, createdby_id, updatedby_id) + SELECT address_id, postcode_arr[1], street, coalesce(streetnumber, ''), coalesce(extra,''), CURRENT_DATE, address_ref_id, 'match', + (SELECT point FROM chill_main_address_reference WHERE id = address_ref_id), + CURRENT_DATE, + CURRENT_DATE, + (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), + (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users) + FROM import.personnes WHERE address_ref_id IS NOT NULL; + +-- f) insert created addresses in chill_main_addresses +INSERT INTO chill_main_address (id, postcode_id, street, streetnumber, extra, validFrom, createdat, updatedat, createdby_id, updatedby_id) + SELECT address_id, postcode_arr[1], coalesce(street, ''), coalesce(streetnumber, ''), coalesce(extra,''), CURRENT_DATE, + CURRENT_DATE, + CURRENT_DATE, + (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), + (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users) + FROM import.personnes WHERE address_ref_id IS NULL AND postcode_arr[1] IS NOT NULL; SELECT setval('chill_main_address_id_seq', (SELECT COALESCE(max(id)) FROM chill_main_address)); --- 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; @@ -322,7 +361,7 @@ INSERT INTO chill_person_household_members (id, person_id, household_id, startda -- 45. Link 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 + FROM import.personnes WHERE address_id IS NOT NULL AND postcode_arr[1] IS NOT NULL; -- 46. Add household composition INSERT INTO chill_person_household_composition (id, household_id, startdate, householdcompositiontype_id) SELECT