From 82f69f98450c0dec84f2a47e2fb86c4c648138c2 Mon Sep 17 00:00:00 2001 From: nobohan Date: Fri, 11 Jul 2025 11:48:24 +0200 Subject: [PATCH] FEATURE add sql for import location_type and location --- sql/import.sql | 109 +++++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 109 insertions(+) diff --git a/sql/import.sql b/sql/import.sql index d5c8361..226a9fb 100644 --- a/sql/import.sql +++ b/sql/import.sql @@ -469,6 +469,104 @@ FROM import.periodes ip WHERE acp.id = ip.period_id; -- ~~Link closingmotive~~ (to be removed from csv) +-- 64. Complete table chill_main_location_type +ALTER TABLE import.choix_localisations ADD COLUMN title1 JSONB; +UPDATE import.choix_localisations SET title1=json_build_object('fr', trim(title)) WHERE title!=''; +INSERT INTO chill_main_location_type (id, title, availableforusers, addressrequired, contactdata, active, defaultfor, editablebyusers) + SELECT nextval('chill_main_location_type_id_seq'), + t.title1, true, coalesce(t."addressRequired", 'optional'), coalesce(t."contactData", 'optional'), true, + t."defaultFor", coalesce(t."editableByUsers", true) + FROM import.choix_localisations AS t WHERE title!='' AND + NOT EXISTS ( SELECT 1 FROM chill_main_location_type WHERE title::jsonb->>'fr' = t.title1::jsonb->>'fr' ); + +-- 65. Add addresses to be linked with location +-- a) add new columns +ALTER TABLE import.localisations ADD column postcode_arr BIGINT[]; +ALTER TABLE import.localisations ADD column address_id BIGINT; +ALTER TABLE import.localisations ADD column address_ref_id BIGINT; + +-- b) find and add postal code references. Check missing correspondances (if you can) +UPDATE import.localisations +SET postcode_arr = ( + SELECT array_agg(pc.id) + FROM chill_main_postal_code AS pc + WHERE pc.code = import.localisations.postcode + AND pc.origin = 0 +); + +-- c) find and add reference addresses. Check missing correspondances (if you can) +UPDATE import.localisations AS loc SET address_ref_id = cmar.id FROM chill_main_address_reference AS cmar +WHERE + cmar.postcode_id = ANY(loc.postcode_arr) + AND similarity(trim(loc.street), trim(cmar.street)) > 0.6 + AND trim(loc.streetnumber) = trim(cmar.streetnumber) + +--SELECT * FROM import.localisations as l +--WHERE l.address_ref_id IS NULL + +-- d) fill new chill address +UPDATE import.localisations SET address_id = nextval('chill_main_address_id_seq'); + +-- 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.localisations WHERE address_ref_id IS NOT NULL; + +-- f) insert new 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], 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.localisations WHERE address_ref_id IS NULL; +SELECT setval('chill_main_address_id_seq', (SELECT COALESCE(max(id)) FROM chill_main_address)); + +-- 66. Add address to be linked with location +DO $$ + DECLARE + intl text := 33; -- change this value to +32 or +33, or... + BEGIN + UPDATE import.localisations SET phonenumber=NULLIF(regexp_replace(phonenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars + UPDATE import.localisations SET phonenumber = CASE -- remove intl prefix + WHEN LEFT(phonenumber, 2) = '00' THEN substr(phonenumber, 5, length(phonenumber) - 4) + WHEN LEFT(phonenumber, 2) = '33' THEN substr(phonenumber, 3, length(phonenumber) - 2) + ELSE regexp_replace(phonenumber, '^0', '') -- remove first 0 prefix + END; + UPDATE import.localisations SET phonenumber=regexp_replace(phonenumber, '(.*)', '+' || intl || '\1'); -- add intl prefix + + UPDATE import.localisations SET phonenumber1=NULLIF(regexp_replace(phonenumber1, '[^0-9]', '', 'g'), ''); -- remove all NaN chars + UPDATE import.localisations SET phonenumber1 = CASE -- remove intl prefix + WHEN LEFT(phonenumber1, 2) = '00' THEN substr(phonenumber1, 5, length(phonenumber1) - 4) + WHEN LEFT(phonenumber1, 2) = '33' THEN substr(phonenumber1, 3, length(phonenumber1) - 2) + ELSE regexp_replace(phonenumber1, '^0', '') -- remove first 0 prefix + END; + UPDATE import.localisations SET phonenumber1=regexp_replace(phonenumber1, '(.*)', '+' || intl || '\1'); -- add intl prefix +END $$; + +INSERT INTO public.chill_main_location +(id, address_id, "name", phonenumber1, phonenumber2, email, availableforusers, createdat, updatedat, locationtype_id, createdby_id, updatedby_id, active) + SELECT nextval('chill_main_location_id_seq'), + t.address_id, + trim(t.locname), + t.phonenumber, + t.phonenumber1, + t.email, + TRUE, + CURRENT_DATE, + CURRENT_DATE, + (SELECT id FROM public.chill_main_location_type AS mlt WHERE mlt.title::jsonb->>'fr' = trim(t.loctype)), + (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), + (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), + TRUE +FROM import.localisations AS t WHERE locname != '' AND +NOT EXISTS ( SELECT 1 FROM chill_main_location WHERE "name" = trim(t.locname) ); + -- ========================================================================================= -- @@ -476,6 +574,17 @@ FROM import.periodes ip WHERE acp.id = ip.period_id; -- DOWN -- +-- Undo 66. +DELETE FROM chill_main_location WHERE createdat >= CURRENT_DATE; + + +-- Undo 65. +DELETE FROM chill_main_address WHERE createdat >= CURRENT_DATE; + + +-- Undo 64. +--TODO/NOT CRITICAL + -- Undo 63. UPDATE chill_person_accompanying_period acp SET pinnedcomment_id = null FROM import.periodes ip WHERE acp.id = ip.period_id; UPDATE import.periodes SET comment1_content = '' WHERE comment1_content IS NULL;