diff --git a/sql/import.sql b/sql/import.sql index 5839a97..0a1744d 100644 --- a/sql/import.sql +++ b/sql/import.sql @@ -150,7 +150,7 @@ UPDATE import.personnes SET civility1=json_build_object('fr', trim(civility)) WH -- 21. Prepare personnes gender ALTER TABLE import.personnes ADD COLUMN gender1 VARCHAR; UPDATE import.personnes SET gender1 = CASE - WHEN trim(gender) IN ('Femme', 'femme', 'Woman', 'woman', 'Female', 'female') THEN 'woman' + WHEN trim(gender) IN ('Femme', 'femme', 'Woman', 'woman', 'Female', 'female') THEN 'woman' 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; @@ -209,19 +209,32 @@ UPDATE import.periodes SET acp_scopes1=json_build_object('fr', trim(acp_scopes)) ALTER TABLE import.periodes ADD COLUMN intensity1 text; UPDATE import.periodes SET intensity1='occasional'; UPDATE import.periodes SET intensity1='regular' WHERE intensity='regular'; --- 33. Format mobile numbers +-- 33-34. Format phones numbers ALTER TABLE import.personnes ADD column mobilenumber1 text; -UPDATE import.personnes SET mobilenumber1=NULLIF(regexp_replace(mobilenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars -UPDATE import.personnes SET mobilenumber1=regexp_replace(mobilenumber1, '^0', '') WHERE mobilenumber1 like '0%'; -- remove first 0 prefix -UPDATE import.personnes SET mobilenumber1=regexp_replace(mobilenumber1, '(.*)', '+32\1'); -- add belgium intl prefix - --- 34. Format phone numbers ALTER TABLE import.personnes ADD column phonenumber1 text; -UPDATE import.personnes SET phonenumber1=NULLIF(regexp_replace(phonenumber, '[^0-9]', '', 'g'), ''); -- remove all NaN chars -UPDATE import.personnes SET phonenumber1=regexp_replace(phonenumber1, '^0', '') WHERE phonenumber1 like '0%'; -- remove first 0 prefix -UPDATE import.personnes SET phonenumber1=regexp_replace(phonenumber1, '(.*)', '+32\1'); -- add belgium intl prefix --- SELECT mobilenumber, mobilenumber1, phonenumber, phonenumber1 FROM import.personnes; +DO $$ + DECLARE + intl text := 32; + BEGIN + -- 33. Format mobile numbers + UPDATE import.personnes SET mobilenumber1=NULLIF(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=NULLIF(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 $$; -- 35. Prepare required default dates -- address_validfrom1 | household_startdate1