From 6b8ca0caa39103937436727a9b7db74ebdc273de Mon Sep 17 00:00:00 2001 From: julien Date: Thu, 14 Aug 2025 18:14:13 +0200 Subject: [PATCH] Add sql for third party --- sql/import.sql | 155 ++++++++++++++++++++++++++++++++++++++++- sql/prepare-import.sql | 22 ++++++ 2 files changed, 176 insertions(+), 1 deletion(-) mode change 100644 => 100755 sql/import.sql mode change 100644 => 100755 sql/prepare-import.sql diff --git a/sql/import.sql b/sql/import.sql old mode 100644 new mode 100755 index 9a6152c..e4d8f7b --- a/sql/import.sql +++ b/sql/import.sql @@ -606,7 +606,7 @@ INSERT INTO public.users t."login", t.email, t.email, - t.nom_prenom, + CONCAT(t.prenom, ' ', t.nom), CASE WHEN t.civility = 'F' THEN (SELECT id FROM chill_main_civility WHERE "name"::jsonb->>'fr' = 'Madame') WHEN t.civility = 'M' THEN (SELECT id FROM chill_main_civility WHERE "name"::jsonb->>'fr' = 'Monsieur') @@ -629,6 +629,159 @@ FROM import.users AS t WHERE NOT EXISTS ( SELECT 1 FROM chill_main_user_job_history WHERE user_id = (SELECT id FROM users WHERE username = SPLIT_PART(t."email",'@',1)) ); +-- 69. Complete table party_category +WITH categories AS (SELECT DISTINCT(trim(t.categorie)) AS title +FROM IMPORT.tiers AS t) +INSERT INTO chill_3party.party_category (id, "name", active) +SELECT + nextval('chill_3party.party_category_id_seq'), + jsonb_build_object('fr', c.title), + TRUE +FROM categories AS c +WHERE NOT EXISTS ( SELECT 1 FROM chill_3party.party_category WHERE "name"::json->>'fr' = c.title ); + +-- 70. Add addresses to be linked with third parties +-- a) add new columns +ALTER TABLE import.tiers ADD column postcode_arr BIGINT[]; +ALTER TABLE import.tiers ADD column address_id BIGINT; +ALTER TABLE import.tiers ADD column address_ref_id BIGINT; + +-- b) find and add postal code references. Check missing correspondances (if you can) +UPDATE import.tiers +SET postcode_arr = ( + SELECT array_agg(pc.id) + FROM chill_main_postal_code AS pc + WHERE pc.code = import.tiers.cp + AND pc.origin = 0 +); + +-- c) find and add reference addresses. Check missing correspondances (if you can) +UPDATE import.tiers AS tiers SET address_ref_id = cmar.id FROM chill_main_address_reference AS cmar +WHERE + cmar.postcode_id = ANY(tiers.postcode_arr) + AND similarity(trim(tiers.adresse), trim(cmar.street)) > 0.6 + +--SELECT * FROM import.tiers as l +--WHERE l.address_ref_id IS NULL + +-- d) fill new chill address +UPDATE import.tiers SET address_id = nextval('chill_main_address_id_seq') WHERE postcode_arr 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], coalesce(adresse,''), '', '', 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.tiers 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], coalesce(adresse,''), '', '', 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.tiers WHERE address_ref_id IS NULL AND postcode_arr IS NOT NULL; +SELECT setval('chill_main_address_id_seq', (SELECT COALESCE(max(id)) FROM chill_main_address)); + +-- 71. Import third parties +DO $$ + DECLARE + intl text := 33; -- change this value to +32 or +33, or... + BEGIN + UPDATE import.tiers SET phonenumber=NULLIF(regexp_replace(phonenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars + UPDATE import.tiers 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.tiers SET phonenumber=regexp_replace(phonenumber, '(.*)', '+' || intl || '\1'); -- add intl prefix + + UPDATE import.tiers SET phonenumber_2=NULLIF(regexp_replace(phonenumber_2, '[^0-9]', '', 'g'), ''); -- remove all NaN chars + UPDATE import.tiers SET phonenumber_2 = CASE -- remove intl prefix + WHEN LEFT(phonenumber_2, 2) = '00' THEN substr(phonenumber_2, 5, length(phonenumber_2) - 4) + WHEN LEFT(phonenumber_2, 2) = '33' THEN substr(phonenumber_2, 3, length(phonenumber_2) - 2) + ELSE regexp_replace(phonenumber_2, '^0', '') -- remove first 0 prefix + END; + UPDATE import.tiers SET phonenumber_2=regexp_replace(phonenumber_2, '(.*)', '+' || intl || '\1'); -- add intl prefix +END $$; + + +-- Insert companies (parent) first +INSERT INTO chill_3party.third_party +(id, "name", telephone, email, "comment", "types", active, address_id, parent_id, updated_by, name_company, acronym, created_at, updated_at, created_by, civility_id, kind, canonicalized, contact_data_anonymous, firstname, profession, telephone2) + SELECT nextval('chill_3party.third_party_id_seq'), + trim(nom), + t.phonenumber, + t.email, + concat('horaires: ', t.horaires, ' \n \n observations: ', t.observations), + NULL, + TRUE, + t.address_id, + NULL, -- parent + (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), + NULL, -- service/dpt + NULL, + CURRENT_DATE, + CURRENT_DATE, + (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), + NULL, + 'company', -- il n'y a pas de personnes physiques ('contact) + lower(trim(nom)), + FALSE, + '', + '', + t.phonenumber_2 +FROM import.tiers AS t WHERE t.nom != '' +AND t.personne_nom IS NULL +AND NOT EXISTS ( SELECT 1 FROM chill_3party.third_party WHERE "name" = trim(t.nom) ); + +-- Do the mapping of thirdparty categories +INSERT INTO chill_3party.thirdparty_category +(thirdparty_id, category_id) +SELECT DISTINCT + tp.id, + (SELECT id FROM chill_3party.party_category WHERE "name"::jsonb->>'fr' = t.categorie) +FROM import.tiers AS t LEFT JOIN chill_3party.third_party AS tp ON trim(t.nom) = tp."name" +WHERE tp.id IS NOT NULL; + +-- Insert contact (child) second +INSERT INTO chill_3party.third_party +(id, "name", telephone, email, "comment", "types", active, address_id, parent_id, updated_by, name_company, acronym, created_at, updated_at, created_by, civility_id, kind, canonicalized, contact_data_anonymous, firstname, profession, telephone2) +SELECT + nextval('chill_3party.third_party_id_seq'), + trim(t.personne_nom), + NULL, -- telephone + NULL::character varying, -- email + '', -- comment + NULL, -- types + TRUE, -- active + NULL, -- address_id + (SELECT id FROM chill_3party.third_party AS tp WHERE tp."name" = trim(t.nom) LIMIT 1), -- parent_id + (SELECT id FROM users ORDER BY id LIMIT 1), -- updated_by + NULL::character varying, -- name_company + NULL::character varying, -- acronym + CURRENT_DATE, -- created_at + CURRENT_DATE, -- updated_at + (SELECT id FROM users ORDER BY id LIMIT 1), -- created_by + CASE + WHEN t.personne_civilite = 'Mme' THEN (SELECT id FROM chill_main_civility WHERE "name"::jsonb->>'fr' = 'Madame') + WHEN t.personne_civilite = 'M' THEN (SELECT id FROM chill_main_civility WHERE "name"::jsonb->>'fr' = 'Monsieur') + ELSE NULL + END, -- civility_id + 'contact', -- kind + lower(trim(t.personne_nom)), + FALSE, -- contact_data_anonymous + COALESCE(trim(t.personne_prenom),''), -- firstname + ''::text, -- profession + NULL::character varying -- telephone2 +FROM import.tiers AS t WHERE t.nom != '' +AND t.personne_nom IS NOT NULL AND lower(trim(t.personne_nom)) IS NOT NULL +AND NOT EXISTS ( SELECT 1 FROM chill_3party.third_party WHERE "name" = trim(t.personne_nom) ); + -- ========================================================================================= -- -- diff --git a/sql/prepare-import.sql b/sql/prepare-import.sql old mode 100644 new mode 100755 index 29530e4..9ce5731 --- a/sql/prepare-import.sql +++ b/sql/prepare-import.sql @@ -116,4 +116,26 @@ CREATE TABLE "import".users ( phonenumber varchar(50) NULL, email varchar(50) NULL, metier varchar(50) NULL +); + +CREATE TABLE "import".tiers ( + ID INT PRIMARY KEY, + CATEGORIE VARCHAR(255), + SECTEUR_AS VARCHAR(255), + COMMUNE VARCHAR(255), + NOM VARCHAR(255), + PHONENUMBER VARCHAR(20), + PHONENUMBER_2 VARCHAR(20), + EMAIL VARCHAR(255), + PERSONNE_NOM VARCHAR(255), + PERSONNE_prenom VARCHAR(255), + PERSONNE_CIVILITE VARCHAR(20), + adresse TEXT, + CP VARCHAR(10), + TIERS_PARENT VARCHAR(255), + TIERS_PHYSIQUE_VS_MORALE VARCHAR(50), + POINT_DE_CONTACT_SUR_LE_TERRITOIRE TEXT, + COORDONNEES TEXT, + HORAIRES TEXT, + OBSERVATIONS TEXT ); \ No newline at end of file