Compare commits
13 Commits
Author | SHA1 | Date | |
---|---|---|---|
6b8ca0caa3 | |||
|
c5f892c27d | ||
|
82f69f9845 | ||
|
fd4e68faa8 | ||
|
3651b1a09b | ||
|
db52c72d22 | ||
|
9c90e5ac07 | ||
543a4569fd | |||
36e3bf3b4b | |||
ddfe9b53b3 | |||
ca3ce608c0 | |||
4e866c2d8e | |||
6b11efd18e |
73
README.md
73
README.md
@@ -1,12 +1,12 @@
|
||||
CHILL - Reprise de données
|
||||
==========================
|
||||
|
||||
Ce dépôt contient un script d'import qui s'applique à un canevas excel présenté au client. Le client remplit le fichier excel, puis le script insère les données dans la base de donnée.
|
||||
Ce dépôt contient un script d'import qui s'applique à un canevas excel présenté au client. Le client remplit le fichier excel, puis le script insère les données dans la base de donnée.
|
||||
|
||||
L'opération est semi-automatique et réduit considérablement le temps dédié à l'import en structurant le format des données en entrée. Par contre il y a toujours une série de manipulations, pour préparer et insérer les données correctement.
|
||||
L'opération est semi-automatique et réduit considérablement le temps dédié à l'import en structurant le format des données en entrée. Par contre il y a toujours une série de manipulations, pour préparer et insérer les données correctement.
|
||||
|
||||
Ces manipulations sont décrites ici.
|
||||
|
||||
|
||||
Le client a rempli le canevas. Une relecture du fichier est toujours nécessaire afin de repérer les éventuelles irrégularités.
|
||||
|
||||
## 1. Préparer les fichiers csv
|
||||
@@ -14,18 +14,18 @@ Le client a rempli le canevas. Une relecture du fichier est toujours nécessaire
|
||||
Le fichier se compose de plusieurs feuilles, chacune doit être sauvée au format csv.
|
||||
|
||||
Pour préparer les fichiers on va:
|
||||
- nettoyer le fichier pour ne laisser en étiquette que les noms de colonnes en anglais.
|
||||
- ajouter une colonne de contôle en fin de ligne, par sécurité. Par exemple une colonne 'endcol' qui contient pour chaque cellule 'endrow'.
|
||||
- ajouter les doublequote lors de la sauvegarde du csv,
|
||||
- nettoyer le fichier pour ne laisser en étiquette que les noms de colonnes en anglais. Il faut donc supprimer les 4 premières lignes de chaque fichier + la 6ème ligne.
|
||||
(- ajouter une colonne de contôle en fin de ligne, par sécurité. Par exemple une colonne 'endcol' qui contient pour chaque cellule 'endrow'.)
|
||||
- ajouter les doublequote lors de la sauvegarde du csv,
|
||||
- enlever tous les line breaks et caractères spéciaux.
|
||||
|
||||
```bash
|
||||
# Exemple de remplacements exécutés sur les fichiers csv pour un import spécifique :
|
||||
$ sed -e :1 -e '$q' -e "/$CR\$/b" -e 'N;s/\n//;b1' < file.2.csv > file.3.csv
|
||||
$ sed -e :1 -e '$q' -e "/$CR\$/b" -e 'N;s/\n//;b1' < file.2.csv > file.3.csv
|
||||
$ sed -e 's#"end"#"end"\n#g' < file.3.csv > file.4.csv
|
||||
|
||||
# Exemple pour un autre import:
|
||||
$ cat file2.csv | sed -e 'N; s#_x000D_##g; s#\n##g; s/$CR//g' | tr "\n" " " > file3.csv
|
||||
# Exemple pour un autre import:
|
||||
$ cat file2.csv | sed -e 'N; s#_x000D_##g; s#\n##g; s/$CR//g' | tr "\n" " " > file3.csv
|
||||
$ sed -e 's#"endcol"#"endcol"\n#g; s#"endrow"#"endrow"\n#g' < file3.csv > file4.csv
|
||||
$ sed -e 's#^,##g; s#^ ##g' < file4.csv > file5.csv
|
||||
```
|
||||
@@ -38,14 +38,14 @@ On va insérer chaque feuille csv comme table à part entière d'un nouveau sch
|
||||
- import.choix_periodes
|
||||
- import.periodes
|
||||
|
||||
Pour réaliser cet import, on peut utiliser des outils tels que `pgfutter`, mais celui-ci peut s'avérer capricieux selon le fichier.
|
||||
Pour réaliser cet import, on peut utiliser des outils tels que `pgfutter`, mais celui-ci peut s'avérer capricieux selon le fichier.
|
||||
La meilleure méthode pour moi est de réaliser cette étape en local avec phpstorm, puis d'exporter le schéma `import` avec pg_dump avant de le transférer sur le serveur.
|
||||
|
||||
### 2.a Manipulations dans phpstorm
|
||||
|
||||
- S'il n'existe pas, créer le schéma `import`; s'il existe, s'assurer qu'il ne contient pas de tables ni de données.
|
||||
#### Importer le csv dans la db
|
||||
- ouvre le fichier csv > passe en onglet text > edit as table > set options:
|
||||
- ouvre le fichier csv > passe en onglet text > edit as table > set options:
|
||||
- cocher 'first row is header'
|
||||
- 'null value text': undefined (pas de champs null dans la table, mais un texte vide)
|
||||
- then > open table
|
||||
@@ -56,14 +56,39 @@ La meilleure méthode pour moi est de réaliser cette étape en local avec phpst
|
||||
- then > import
|
||||
#### Exporter en sql
|
||||
- créer un fichier `<client>-data.sql` vide
|
||||
- depuis chaque table du schéma `import`:
|
||||
- depuis chaque table du schéma `import`:
|
||||
- copier le DDL de la table dans le fichier (s'assurer d'ajouter le préfixe `import.` sur chaque requête)
|
||||
- export data > extractor: SQL-insert-multirow > copy to clipboard
|
||||
- export data > extractor: SQL-insert-multirow > copy to clipboard
|
||||
- coller les données dans `<client>-data.sql`
|
||||
|
||||
### 2.b Avec des fonctions Postgresql
|
||||
|
||||
On peut aussi utiliser la fonction `\copy` de psql pour charger un fichier csv dans les tables temporaires du schéma "import".
|
||||
|
||||
Tout d'abord, les tables du schéma "import" doivent être préparées avec le script `prepare-import.sql`.
|
||||
|
||||
Puis on importe les fichiers csv:
|
||||
|
||||
```bash
|
||||
psql chill-import
|
||||
chill-import=# \copy "import".choix_personnes FROM 'choix_personnes.csv' DELIMITER ',' CSV HEADER
|
||||
chill-import=# \copy "import".personnes FROM 'personnes.csv' DELIMITER ',' CSV HEADER
|
||||
chill-import=# \copy "import".choix_periodes FROM 'choix_periodes.csv' DELIMITER ',' CSV HEADER
|
||||
chill-import=# \copy "import".periodes FROM 'periodes.csv' DELIMITER ',' CSV HEADER
|
||||
chill-import=# \copy "import".choix_localisations FROM 'choix_localisations.csv' DELIMITER ',' CSV HEADER
|
||||
chill-import=# \copy "import".localisations FROM 'localisations.csv' DELIMITER ',' CSV HEADER
|
||||
```
|
||||
|
||||
Enfin, on exporte la base de données en sql:
|
||||
|
||||
```bash
|
||||
pg_dump chill-import --no-owner > <client>-data.sql
|
||||
```
|
||||
|
||||
|
||||
## 3. Import du schéma 'import' sur le serveur (safran)
|
||||
|
||||
- transférer le fichier `<client>-data.sql` sur le serveur (avec scp):
|
||||
- transférer le fichier `<client>-data.sql` sur le serveur (avec scp):
|
||||
```bash
|
||||
$ scp cyclo-data.sql debian@safran:~/data/tmp/
|
||||
```
|
||||
@@ -75,6 +100,14 @@ debian@safran:~/bin$ ls -l dump/ | tail -1
|
||||
-rw-r--r-- 1 postgres postgres 234954230 Mar 15 10:40 20230315-104003_cycloprod.sql
|
||||
```
|
||||
|
||||
ou bien simplement:
|
||||
|
||||
```bash
|
||||
sudo su postgres
|
||||
cd
|
||||
pg_dump -p 5436 laplateformereunionprod > laplateformereunionprod.sql
|
||||
```
|
||||
|
||||
- importer le fichier sql sur la base cible: `$ sudo su postgres -c 'psql -p5436'`
|
||||
```sql
|
||||
postgres=# \c cycloprod
|
||||
@@ -91,7 +124,7 @@ cycloprod=# \i '/home/debian/data/tmp/cyclo-data.sql'
|
||||
-- vérifier que le schéma import est en place
|
||||
cycloprod=# \dt import.*
|
||||
List of relations
|
||||
Schema | Name | Type | Owner
|
||||
Schema | Name | Type | Owner
|
||||
--------+-----------------+-------+----------
|
||||
import | choix_periodes | table | postgres
|
||||
import | choix_personnes | table | postgres
|
||||
@@ -100,7 +133,15 @@ cycloprod=# \dt import.*
|
||||
(4 rows)
|
||||
```
|
||||
|
||||
## 4. Exécution du script de migration
|
||||
ou bien simplement:
|
||||
|
||||
```bash
|
||||
sudo su postgres
|
||||
psql -p 5436 laplateformereunionprod < /tmp/chill-import-lpreunion.sql
|
||||
```
|
||||
|
||||
|
||||
## 4. Exécution du script de migration
|
||||
|
||||
Se fait dans la console postgresql, en tant que user postgres, en étant connecté à la base de donnée cible.
|
||||
|
||||
|
BIN
canvas/chill_canevas_reprise-de-données.xlsx
Normal file
BIN
canvas/chill_canevas_reprise-de-données.xlsx
Normal file
Binary file not shown.
356
sql/import.sql
Normal file → Executable file
356
sql/import.sql
Normal file → Executable file
@@ -10,6 +10,7 @@
|
||||
-- * referrer: cfr. 57
|
||||
-- * scopes: cfr. 58
|
||||
--
|
||||
-- vérifier les étiquettes de colonnes: user-> referrer, acp_social_issues-> acp_socialissues
|
||||
|
||||
|
||||
-- 1. Adjust Type cast for id columns
|
||||
@@ -125,7 +126,7 @@ ALTER TABLE import.choix_periodes ADD COLUMN parent1 jsonb;
|
||||
UPDATE import.choix_periodes SET parent1=json_build_object('fr', upper(trim(parent))) WHERE parent !='';
|
||||
ALTER TABLE import.choix_periodes ADD COLUMN enfant1 jsonb;
|
||||
UPDATE import.choix_periodes SET enfant1=json_build_object('fr', upper(trim(enfant))) WHERE enfant !='';
|
||||
WITH max_ordering AS ( SELECT MAX(ordering) as max_ordering FROM chill_person_social_issue )
|
||||
WITH max_ordering AS ( SELECT COALESCE(MAX(ordering),1) as max_ordering FROM chill_person_social_issue )
|
||||
INSERT INTO chill_person_social_issue (id, parent_id, title, ordering)
|
||||
SELECT nextval('chill_person_social_issue_id_seq'),
|
||||
null, t.parent1,
|
||||
@@ -138,7 +139,7 @@ INSERT INTO chill_person_social_issue (id, parent_id, title, ordering)
|
||||
SELECT nextval('chill_person_social_issue_id_seq'),
|
||||
( SELECT id FROM chill_person_social_issue WHERE parent_id IS NULL AND title::jsonb->>'fr' = t.parent1::jsonb->>'fr' ), t.enfant1,
|
||||
max_ordering.max_ordering + row_number() OVER () as ordering
|
||||
FROM ( SELECT DISTINCT ON (acp_socialissues) parent1, enfant1 FROM import.choix_periodes WHERE enfant1 IS NOT NULL ) t
|
||||
FROM ( SELECT DISTINCT ON (acp_social_issues) parent1, enfant1 FROM import.choix_periodes WHERE enfant1 IS NOT NULL ) t
|
||||
CROSS JOIN max_ordering
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_social_issue
|
||||
WHERE title::jsonb->>'fr' = t.enfant1::jsonb->>'fr'
|
||||
@@ -157,7 +158,7 @@ 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 ('Homme', 'homme', 'Man', 'man', 'Male', 'male') THEN 'man'
|
||||
WHEN trim(gender) IN ('', 'Inconnu', 'inconnu', 'Unknown', 'unknown') THEN 'unknown'
|
||||
WHEN trim(gender) IN ('Autre', 'Inconnu', 'inconnu', 'Unknown', 'unknown') THEN 'unknown'
|
||||
ELSE 'both' END;
|
||||
|
||||
-- 22. Prepare personnes nationality
|
||||
@@ -177,9 +178,17 @@ UPDATE import.personnes SET maritalstatus1=json_build_object('fr', trim(maritals
|
||||
|
||||
-- 25. Prepare personnes numberofchildren
|
||||
ALTER TABLE import.personnes ADD COLUMN numberofchildren1 integer;
|
||||
UPDATE import.personnes SET numberofchildren1=NULLIF(numberofchildren, '')::int;
|
||||
UPDATE import.personnes SET numberofchildren1=NULLIF(numberofchildren, 0)::int;
|
||||
-- SELECT numberofchildren, numberofchildren1 FROM import.personnes;
|
||||
|
||||
-- 25bis. Prepare personnes place_of_birth
|
||||
ALTER TABLE import.personnes ADD COLUMN placeofbirth1 varchar;
|
||||
UPDATE import.personnes SET placeofbirth1=CASE WHEN place_of_birth IS NOT NULL THEN place_of_birth ELSE '' END;
|
||||
|
||||
-- 25ter. Prepare personnes memo
|
||||
ALTER TABLE import.personnes ADD COLUMN memo1 varchar;
|
||||
UPDATE import.personnes SET memo1=CASE WHEN memo IS NOT NULL THEN memo ELSE '' END;
|
||||
|
||||
-- 26. Prepare personnes household_composition_type
|
||||
ALTER TABLE import.personnes ADD COLUMN household_composition_type1 JSONB;
|
||||
UPDATE import.personnes SET household_composition_type1=json_build_object('fr', trim(household_composition_type)) WHERE household_composition_type!='';
|
||||
@@ -266,7 +275,7 @@ INSERT INTO chill_person_person (
|
||||
, (SELECT c.id FROM country c WHERE c.name::jsonb->>'fr' = ip.countryofbirth1::jsonb->>'fr' AND ip.countryofbirth1 IS NOT NULL ) -- countryofbirth_id,
|
||||
, (SELECT c.id FROM chill_main_civility c WHERE c.name::jsonb->>'fr' = ip.civility1::jsonb->>'fr' AND ip.civility1 IS NOT NULL ) -- civility_id
|
||||
, (SELECT ms.id FROM chill_person_marital_status ms WHERE ms.name::jsonb->>'fr' = ip.maritalstatus1::jsonb->>'fr' AND ip.maritalstatus1 IS NOT NULL ) -- maritalstatus_id,
|
||||
, TRIM(firstname), UPPER(TRIM(lastname)), birthdate1, TRIM(place_of_birth), TRIM(memo), TRIM(email), TRIM(contactinfo), phonenumber1, mobilenumber1, numberofchildren1, gender1, deathdate1, false
|
||||
, TRIM(firstname), UPPER(TRIM(lastname)), birthdate1, TRIM(placeofbirth1), TRIM(memo1), TRIM(email), TRIM(contactinfo), phonenumber1, mobilenumber1, numberofchildren1, gender1, deathdate1, false
|
||||
, CURRENT_DATE, CURRENT_DATE -- createdat, updatedat (= import date)
|
||||
, (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users) -- createdby_id, updatedby_id
|
||||
, (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM centers) -- center_id
|
||||
@@ -291,7 +300,7 @@ INSERT INTO chill_person_person_center_history (id, person_id, center_id, startd
|
||||
ALTER TABLE import.personnes ADD column address_id BIGINT;
|
||||
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 = postcode AND pc.origin = 0;
|
||||
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;
|
||||
@@ -346,7 +355,7 @@ INSERT INTO chill_person_accompanying_period_participation (id, person_id, accom
|
||||
-- 53. Prepare temporary address location
|
||||
INSERT INTO chill_main_address (id, postcode_id, street, streetnumber, validFrom) SELECT
|
||||
nextval('chill_main_address_id_seq'),
|
||||
(SELECT pc.id FROM chill_main_postal_code pc WHERE pc.code = postcode),
|
||||
(SELECT pc.id FROM chill_main_postal_code pc WHERE pc.code::int = postcode::int),
|
||||
street, streetnumber, date(date_trunc('year', CURRENT_DATE))
|
||||
FROM import.choix_periodes WHERE street != '';
|
||||
ALTER TABLE import.choix_periodes ADD COLUMN address_location_id BIGINT;
|
||||
@@ -385,7 +394,7 @@ FROM (
|
||||
(SELECT id FROM chill_person_social_issue WHERE title::jsonb->>'fr' = icp.enfant1::jsonb->>'fr' AND parent_id =
|
||||
(SELECT id FROM chill_person_social_issue WHERE title::jsonb->>'fr' = icp.parent1::jsonb->>'fr' AND parent_id IS NULL)) AS enfant_id, icp.enfant1
|
||||
FROM import.periodes p
|
||||
JOIN import.choix_periodes icp ON p.acp_socialissues = icp.acp_socialissues
|
||||
JOIN import.choix_periodes icp ON p.acp_socialissues = icp.acp_social_issues
|
||||
ORDER BY id) AS t;
|
||||
|
||||
-- 57. Link referrer to periods
|
||||
@@ -401,7 +410,7 @@ UPDATE chill_person_accompanying_period acp
|
||||
INSERT INTO accompanying_periods_scopes (accompanying_period_id, scope_id)
|
||||
SELECT ip.period_id, COALESCE(
|
||||
(SELECT id FROM scopes s WHERE ip.acp_scopes1::jsonb->>'fr' = s.name::jsonb->>'fr'),
|
||||
(SELECT id from scopes s WHERE s.name::jsonb->>'fr' = 'tous') -- default value 'tous'
|
||||
(SELECT id from scopes s WHERE s.name::jsonb->>'fr' = 'Principal') -- default value 'Principal'
|
||||
)
|
||||
FROM import.periodes ip;
|
||||
|
||||
@@ -460,6 +469,318 @@ 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. Import locations
|
||||
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) );
|
||||
|
||||
|
||||
-- 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,
|
||||
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')
|
||||
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)) );
|
||||
|
||||
|
||||
-- 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) );
|
||||
|
||||
-- ========================================================================================= --
|
||||
|
||||
@@ -467,6 +788,23 @@ FROM import.periodes ip WHERE acp.id = ip.period_id;
|
||||
-- DOWN
|
||||
--
|
||||
|
||||
-- Undo 68.
|
||||
--TODO
|
||||
|
||||
-- Undo 67.
|
||||
--TODO/NOT CRITICAL
|
||||
|
||||
-- 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;
|
||||
|
141
sql/prepare-import.sql
Executable file
141
sql/prepare-import.sql
Executable file
@@ -0,0 +1,141 @@
|
||||
CREATE SCHEMA "import";
|
||||
|
||||
CREATE TABLE "import".choix_personnes (
|
||||
civility varchar(50) NULL,
|
||||
gender varchar(50) NULL,
|
||||
maritalstatus varchar(50) NULL,
|
||||
country varchar(50) NULL,
|
||||
household_composition_type varchar(50) NULL,
|
||||
household_position varchar(50) NULL
|
||||
);
|
||||
|
||||
CREATE TABLE "import".personnes (
|
||||
id varchar(50) NULL,
|
||||
civility varchar(50) NULL,
|
||||
lastname varchar(50) NULL,
|
||||
firstname varchar(50) NULL,
|
||||
gender varchar(50) NULL,
|
||||
gendercomment varchar(50) NULL,
|
||||
nationality varchar(50) NULL,
|
||||
memo varchar(50) NULL,
|
||||
birthdate varchar(50) NULL,
|
||||
place_of_birth varchar(50) NULL,
|
||||
countryofbirth varchar(50) NULL,
|
||||
deathdate varchar(50) NULL,
|
||||
email varchar(50) NULL,
|
||||
phonenumber varchar(50) NULL,
|
||||
mobilenumber varchar(50) NULL,
|
||||
contactinfo varchar(50) NULL,
|
||||
street varchar(50) NULL,
|
||||
extra varchar(50) NULL,
|
||||
streetnumber varchar(50) NULL,
|
||||
postcode varchar(50) NULL,
|
||||
country varchar(50) NULL,
|
||||
validfrom varchar(50) NULL,
|
||||
maritalstatus varchar(50) NULL,
|
||||
maritalstatuscomment varchar(50) NULL,
|
||||
numberofchildren integer NULL,
|
||||
household_composition_type varchar(50) NULL,
|
||||
household_position varchar(50) NULL,
|
||||
household_startdate varchar(50) NULL
|
||||
);
|
||||
|
||||
CREATE TABLE "import".choix_periodes (
|
||||
closingmotive varchar(50) NULL,
|
||||
origin varchar(50) NULL,
|
||||
acp_scopes varchar(50) NULL,
|
||||
job varchar(50) NULL,
|
||||
referrer varchar(50) NULL,
|
||||
parent varchar(50) NULL,
|
||||
enfant varchar(50) NULL,
|
||||
acp_social_issues varchar(50) NULL,
|
||||
work_social_action varchar(50) NULL,
|
||||
street varchar(128) NULL,
|
||||
extra varchar(50) NULL,
|
||||
streetnumber integer NULL,
|
||||
postcode integer NULL,
|
||||
country varchar(50) NULL
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE "import".periodes (
|
||||
id varchar(50) NULL,
|
||||
nom varchar(50) NULL,
|
||||
openingdate varchar(50) NULL,
|
||||
closingdate varchar(50) NULL,
|
||||
closingmotive varchar(50) NULL,
|
||||
origin varchar(50) NULL,
|
||||
remark integer NULL,
|
||||
intensity varchar(50) NULL,
|
||||
referrer varchar(50) NULL,
|
||||
job varchar(50) NULL,
|
||||
acp_scopes varchar(50) NULL,
|
||||
"address" varchar(50) NULL,
|
||||
personlocation varchar(50) NULL,
|
||||
addresslocation varchar(50) NULL,
|
||||
acp_socialissues varchar(50) NULL,
|
||||
work_socialaction varchar(50) NULL,
|
||||
comment1_content varchar(50) NULL,
|
||||
comment2_content varchar(50) NULL,
|
||||
comment3_content varchar(50) NULL,
|
||||
comment4_content varchar(50) NULL,
|
||||
comment5_content varchar(50) NULL
|
||||
);
|
||||
|
||||
CREATE TABLE "import".choix_localisations (
|
||||
title varchar(50) NULL,
|
||||
"addressRequired" varchar(32) NULL,
|
||||
"availableForUsers" boolean DEFAULT TRUE,
|
||||
"contactData" varchar(32) NULL,
|
||||
"defaultFor" varchar(32) NULL,
|
||||
"editableByUsers" boolean DEFAULT TRUE
|
||||
);
|
||||
|
||||
CREATE TABLE "import".localisations (
|
||||
id varchar(50) NULL,
|
||||
locname varchar(50) NULL,
|
||||
phonenumber varchar(50) NULL,
|
||||
phonenumber1 varchar(50) NULL,
|
||||
email varchar(50) NULL,
|
||||
loctype varchar(50) NULL,
|
||||
street varchar(50) NULL,
|
||||
extra varchar(50) NULL,
|
||||
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
|
||||
);
|
||||
|
||||
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
|
||||
);
|
14
third_party/README.md
vendored
Normal file
14
third_party/README.md
vendored
Normal file
@@ -0,0 +1,14 @@
|
||||
Import Third parties into Chill from the canvas
|
||||
===============================================
|
||||
|
||||
This folder contains a single Python script that reads a csv file with Third party and print to the console some SQL to execute on the database.
|
||||
|
||||
The csv file should be simply exported from the sheet "Tiers" from the xls canvas.
|
||||
|
||||
Then, you can run the python script with adapting the following:
|
||||
|
||||
- name of the csv file to open
|
||||
- change the mapping of third party categories, civilities and third party kinds according to your Chill database
|
||||
|
||||
|
||||
So far, the addresses are not treated.
|
118
third_party/import_third_party_to_sql.py
vendored
Normal file
118
third_party/import_third_party_to_sql.py
vendored
Normal file
@@ -0,0 +1,118 @@
|
||||
import csv
|
||||
|
||||
print_to_screen = "INSERT INTO chill_3party.third_party (id, civility_id, name, firstname, name_company, acronym, kind, parent_id, profession, email, telephone, comment, contact_data_anonymous, active, created_at) VALUES"
|
||||
|
||||
|
||||
def get_parent_id(arg):
|
||||
return int(arg) + 1000 if arg else "NULL"
|
||||
|
||||
|
||||
def get_third_party_civility(arg):
|
||||
if arg == "Madame":
|
||||
return 1
|
||||
elif arg == "Monsieur":
|
||||
return 2
|
||||
elif arg == "Docteur":
|
||||
return 3
|
||||
else:
|
||||
return "NULL"
|
||||
|
||||
|
||||
def get_third_party_kind(arg):
|
||||
if arg == "Tiers institutionnel":
|
||||
return "company"
|
||||
elif arg == "Personne de contact":
|
||||
return "child"
|
||||
elif arg == "Personne morale":
|
||||
return "contact"
|
||||
else:
|
||||
return "company"
|
||||
|
||||
|
||||
def make_bool_with_default_false(arg):
|
||||
if arg == "oui":
|
||||
return True
|
||||
else:
|
||||
return False
|
||||
|
||||
|
||||
def make_telephone(arg):
|
||||
if arg:
|
||||
return f"'+32{arg}'"
|
||||
else:
|
||||
return "NULL"
|
||||
|
||||
|
||||
with open("HalleDeHan_tiers.csv", newline="") as csv_file:
|
||||
csv_reader = csv.reader(csv_file)
|
||||
|
||||
for skip in range(7):
|
||||
next(csv_file)
|
||||
|
||||
for row in csv_reader:
|
||||
third_party_id = int(row[0]) + 1000
|
||||
civility = get_third_party_civility(row[1])
|
||||
name = row[2]
|
||||
firstname = row[3]
|
||||
name_company = row[4]
|
||||
acronym = row[5]
|
||||
kind = get_third_party_kind(row[6])
|
||||
parent_id = get_parent_id(row[7])
|
||||
# row[8] is the name of the parent in the csv
|
||||
profession = row[9]
|
||||
# category = row[10] # category -> see below
|
||||
email = row[11]
|
||||
telephone = make_telephone(row[12])
|
||||
# street = row[13] # TODO address
|
||||
# extra = row[14]
|
||||
# streetnumber = row[15]
|
||||
# postcode = row[16]
|
||||
# country = row[17]
|
||||
# validfrom = row[18]
|
||||
comment = row[19]
|
||||
contact_data_anonymous = make_bool_with_default_false(row[20])
|
||||
print_to_screen += f"({third_party_id}, {civility}, '{name}', '{firstname}', '{name_company}', '{acronym}', '{kind}', {parent_id}, '{profession}', '{email}', {telephone}, '{comment}', {contact_data_anonymous}, True, NOW()),"
|
||||
|
||||
print_to_screen = print_to_screen[:-1]
|
||||
|
||||
print(print_to_screen)
|
||||
|
||||
## categories
|
||||
|
||||
print_to_screen_cat = (
|
||||
"INSERT INTO chill_3party.thirdparty_category (thirdparty_id, category_id) VALUES"
|
||||
)
|
||||
|
||||
|
||||
def get_third_party_category(arg):
|
||||
if arg == "Stage vente":
|
||||
return 2
|
||||
elif arg == "Stage reassort":
|
||||
return 8
|
||||
elif arg == "Stage social / educ":
|
||||
return 9
|
||||
elif arg == "Stage logistique":
|
||||
return 10
|
||||
elif arg == "Stage bureautique":
|
||||
return 11
|
||||
else:
|
||||
return None
|
||||
|
||||
|
||||
with open("HalleDeHan_tiers.csv", newline="") as csv_file:
|
||||
csv_reader = csv.reader(csv_file)
|
||||
|
||||
for skip in range(7):
|
||||
next(csv_file)
|
||||
|
||||
for row in csv_reader:
|
||||
third_party_id = int(row[0]) + 1000
|
||||
category_id = get_third_party_category(row[10])
|
||||
if category_id:
|
||||
print_to_screen_cat += f"({third_party_id}, {category_id}),"
|
||||
|
||||
print_to_screen_cat = print_to_screen_cat[:-1]
|
||||
|
||||
print(print_to_screen_cat)
|
||||
|
||||
# TODO addresses
|
Reference in New Issue
Block a user