diff --git a/sql/import.sql b/sql/import.sql index 226a9fb..9a6152c 100644 --- a/sql/import.sql +++ b/sql/import.sql @@ -527,7 +527,7 @@ INSERT INTO chill_main_address (id, postcode_id, street, streetnumber, extra, va 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 +-- 66. Import locations DO $$ DECLARE intl text := 33; -- change this value to +32 or +33, or... @@ -568,12 +568,79 @@ FROM import.localisations AS t WHERE locname != '' AND NOT EXISTS ( SELECT 1 FROM chill_main_location WHERE "name" = trim(t.locname) ); +-- 67. Import/update user job (métiers) +INSERT INTO public.chill_main_user_job +(id, "label", active) +SELECT + nextval('chill_main_user_job_id_seq'), + json_build_object('fr', trim(t.metier)), + TRUE +FROM ( + SELECT DISTINCT metier + FROM import.users +) AS t +WHERE NOT EXISTS ( SELECT 1 FROM chill_main_user_job WHERE label::jsonb->>'fr' = t.metier ); + +-- 68. Imports users +DO $$ + DECLARE + intl text := 33; -- change this value to +32 or +33, or... + BEGIN + UPDATE import.users SET phonenumber=NULLIF(regexp_replace(phonenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars + UPDATE import.users 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.users SET phonenumber=regexp_replace(phonenumber, '(.*)', '+' || intl || '\1'); -- add intl prefix + +END $$; + +INSERT INTO public.users +(id, username, "password", enabled, "locked", usernamecanonical, email, emailcanonical, "label", civility_id, phonenumber) + SELECT nextval('users_id_seq'), + SPLIT_PART(t."email",'@',1), + '', --TODO PW + TRUE, + TRUE, + t."login", + t.email, + t.email, + t.nom_prenom, + 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') + ELSE NULL + END, + t.phonenumber +FROM import.users AS t +WHERE NOT EXISTS ( SELECT 1 FROM users WHERE username = SPLIT_PART(t."email",'@',1) ); + +-- Update also user job history +INSERT INTO public.chill_main_user_job_history +(id, job_id, user_id, enddate, startdate) +SELECT + nextval('chill_main_user_job_history_id_seq'), + (SELECT id FROM chill_main_user_job WHERE label::jsonb->>'fr' = t.metier), + (SELECT id FROM users WHERE username = SPLIT_PART(t."email",'@',1)), + NULL::timestamp without time zone, + CURRENT_DATE +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)) ); + + -- ========================================================================================= -- -- -- DOWN -- +-- Undo 68. +--TODO + +-- Undo 67. +--TODO/NOT CRITICAL + -- Undo 66. DELETE FROM chill_main_location WHERE createdat >= CURRENT_DATE; diff --git a/sql/prepare-import.sql b/sql/prepare-import.sql index 82d555c..29530e4 100644 --- a/sql/prepare-import.sql +++ b/sql/prepare-import.sql @@ -103,4 +103,17 @@ CREATE TABLE "import".localisations ( streetnumber varchar(50) NULL, postcode varchar(50) NULL, country varchar(50) NULL +); + +CREATE TABLE "import".users ( + id varchar(50) NULL, + "login" varchar(50) NULL, + civility varchar(50) NULL, + nom varchar(50) NULL, + prenom varchar(50) NULL, + libl varchar(50) NULL, + nom_prenom varchar(50) NULL, + phonenumber varchar(50) NULL, + email varchar(50) NULL, + metier varchar(50) NULL ); \ No newline at end of file