Compare commits
49 Commits
139dd6209a
...
master
Author | SHA1 | Date | |
---|---|---|---|
45755bf797 | |||
08e87503f0 | |||
20517a109b | |||
c17b2ae524 | |||
5bfc7f4a02 | |||
6b8ca0caa3 | |||
|
c5f892c27d | ||
|
82f69f9845 | ||
|
fd4e68faa8 | ||
|
3651b1a09b | ||
|
db52c72d22 | ||
|
9c90e5ac07 | ||
543a4569fd | |||
36e3bf3b4b | |||
ddfe9b53b3 | |||
cea5190174 | |||
ca3ce608c0 | |||
f3bda2a22e | |||
4e866c2d8e | |||
6b11efd18e | |||
290a9b917f | |||
b68e0399cc | |||
07df6c4292 | |||
d9152fc090 | |||
12f0ec0ae4 | |||
264fdb5888 | |||
7893eb3c81 | |||
1adf47e63e | |||
314e625c91 | |||
59daee4790 | |||
6900d66206 | |||
f513dd1b36 | |||
67d020d322 | |||
477565f6e1 | |||
e569d77bd2 | |||
0ab77b77ed | |||
307cfcbe74 | |||
081ce76085 | |||
cadcddddb5 | |||
dd3769e2a0 | |||
1cc1b83435 | |||
9ac2553eb0 | |||
0c7ea76178 | |||
5f78276762 | |||
5a6daae5a4 | |||
3978ee8b1a | |||
838bcb78ff | |||
f3170d0c87 | |||
1a6f3953ca |
0
.gitignore
vendored
Normal file → Executable file
0
.gitignore
vendored
Normal file → Executable file
153
README.md
Executable file
153
README.md
Executable file
@@ -0,0 +1,153 @@
|
||||
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.
|
||||
|
||||
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
|
||||
|
||||
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. 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 '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
|
||||
$ 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
|
||||
```
|
||||
|
||||
## 2. Insérer les csv dans la base de donnée
|
||||
|
||||
On va insérer chaque feuille csv comme table à part entière d'un nouveau schéma `import`. On aura:
|
||||
- import.choix_personnes
|
||||
- import.personnes
|
||||
- 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.
|
||||
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:
|
||||
- cocher 'first row is header'
|
||||
- 'null value text': undefined (pas de champs null dans la table, mais un texte vide)
|
||||
- then > open table
|
||||
- import to database > set options:
|
||||
- régler target/schema: import
|
||||
- et table: même nom que le csv
|
||||
- DDL: TEXT pour tous les champs
|
||||
- then > import
|
||||
#### Exporter en sql
|
||||
- créer un fichier `<client>-data.sql` vide
|
||||
- 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
|
||||
- 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):
|
||||
```bash
|
||||
$ scp cyclo-data.sql debian@safran:~/data/tmp/
|
||||
```
|
||||
|
||||
- faire une sauvegarde de la base sur laquelle on va réaliser l'insertion
|
||||
```bash
|
||||
debian@safran:~/bin$ bash backup_now_db.sh 5436 cycloprod
|
||||
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
|
||||
You are now connected to database "cycloprod" as user "postgres".
|
||||
|
||||
cycloprod=# \dt import.*
|
||||
Did not find any relation named "import.*".
|
||||
|
||||
cycloprod=# CREATE SCHEMA import;
|
||||
|
||||
-- insertion
|
||||
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
|
||||
--------+-----------------+-------+----------
|
||||
import | choix_periodes | table | postgres
|
||||
import | choix_personnes | table | postgres
|
||||
import | periodes | table | postgres
|
||||
import | personnes | table | postgres
|
||||
(4 rows)
|
||||
```
|
||||
|
||||
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.
|
||||
|
||||
On joue pas-à-pas les blocs de la section 'Up' du script `sql/import.sql`
|
||||
|
||||
## Tips
|
||||
|
||||
- Dans phpstorm, si on veut renommer le schéma pour ne pas tout mélanger, il vaut mieux faire 'Modify schema', car 'Rename' va faire des remplacements partout
|
||||
|
BIN
canvas/chill_canevas_reprise-de-données.xlsx
Executable file
BIN
canvas/chill_canevas_reprise-de-données.xlsx
Executable file
Binary file not shown.
0
csv/choix_periodes.dist.csv
Normal file → Executable file
0
csv/choix_periodes.dist.csv
Normal file → Executable file
0
csv/choix_personnes.dist.csv
Normal file → Executable file
0
csv/choix_personnes.dist.csv
Normal file → Executable file
0
csv/periodes.dist.csv
Normal file → Executable file
0
csv/periodes.dist.csv
Normal file → Executable file
0
csv/personnes.dist.csv
Normal file → Executable file
0
csv/personnes.dist.csv
Normal file → Executable file
787
sql/import.sql
Normal file → Executable file
787
sql/import.sql
Normal file → Executable file
@@ -3,8 +3,14 @@
|
||||
-- version v0.6 (== version canevas)
|
||||
--
|
||||
-- /!\ IMPORTANT
|
||||
-- * Avant de migrer (UP), il faut d'abord importer les codes postaux !!!
|
||||
-- * Avant de migrer (UP), il faut d'abord avoir importé les codes postaux !!!
|
||||
-- * Adapter les valeurs par défaut
|
||||
-- * centres: cfr. 41 et 42
|
||||
-- * socialIssues: cfr. 56
|
||||
-- * 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
|
||||
@@ -33,7 +39,7 @@ INSERT INTO chill_main_civility (id, name, abbreviation, active, ordering)
|
||||
max_ordering.max_ordering + row_number() OVER () as ordering
|
||||
FROM ( SELECT DISTINCT ON (civility) civility1 FROM import.choix_personnes WHERE civility1 IS NOT NULL ) t
|
||||
CROSS JOIN max_ordering
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_main_civility WHERE name::jsonb = t.civility1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_main_civility WHERE name::jsonb->>'fr' = t.civility1::jsonb->>'fr' );
|
||||
|
||||
-- 4. Complete table Country
|
||||
ALTER TABLE import.choix_personnes ADD COLUMN country1 JSONB;
|
||||
@@ -41,7 +47,7 @@ UPDATE import.choix_personnes SET country1=json_build_object('fr', trim(country)
|
||||
INSERT INTO country (id, name, countrycode)
|
||||
SELECT nextval('country_id_seq'), t.country1, 'ZZ'
|
||||
FROM ( SELECT DISTINCT ON (country) country1 FROM import.choix_personnes WHERE country1 IS NOT NULL ) t
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM country WHERE name::jsonb = t.country1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM country WHERE name::jsonb->>'fr' = t.country1::jsonb->>'fr' );
|
||||
|
||||
-- 5. Complete table marital_status
|
||||
ALTER TABLE import.choix_personnes ADD COLUMN maritalstatus1 JSONB;
|
||||
@@ -49,7 +55,7 @@ UPDATE import.choix_personnes SET maritalstatus1=json_build_object('fr', trim(ma
|
||||
INSERT INTO chill_person_marital_status (id, name)
|
||||
SELECT substr(md5(random()::text), 1, 7), t.maritalstatus1
|
||||
FROM ( SELECT DISTINCT ON (maritalstatus) maritalstatus1 FROM import.choix_personnes WHERE maritalstatus1 IS NOT NULL ) t
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_marital_status WHERE name::jsonb = t.maritalstatus1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_marital_status WHERE name::jsonb->>'fr' = t.maritalstatus1::jsonb->>'fr' );
|
||||
|
||||
-- 6. Complete table household_composition_type
|
||||
ALTER TABLE import.choix_personnes ADD COLUMN household_composition_type1 JSONB;
|
||||
@@ -57,7 +63,7 @@ UPDATE import.choix_personnes SET household_composition_type1=json_build_object(
|
||||
INSERT INTO chill_person_household_composition_type (id, active, label)
|
||||
SELECT nextval('chill_person_household_composition_type_id_seq'), true, t.household_composition_type1
|
||||
FROM ( SELECT DISTINCT ON (household_composition_type) household_composition_type1 FROM import.choix_personnes WHERE household_composition_type1 IS NOT NULL ) t
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_household_composition_type WHERE label::jsonb = t.household_composition_type1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_household_composition_type WHERE label::jsonb->>'fr' = t.household_composition_type1::jsonb->>'fr' );
|
||||
|
||||
-- 7. Complete table household_position
|
||||
ALTER TABLE import.choix_personnes ADD COLUMN household_position1 JSONB;
|
||||
@@ -69,7 +75,7 @@ INSERT INTO chill_person_household_position (id, label, sharehousehold, allowhol
|
||||
max_ordering.max_ordering + row_number() OVER () as ordering
|
||||
FROM ( SELECT DISTINCT ON (household_position) household_position1 FROM import.choix_personnes WHERE household_position1 IS NOT NULL ) t
|
||||
CROSS JOIN max_ordering
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_household_position WHERE label::jsonb = t.household_position1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_household_position WHERE label::jsonb->>'fr' = t.household_position1::jsonb->>'fr' );
|
||||
|
||||
-- 8. Complete table accompanying_period_closingmotive
|
||||
ALTER TABLE import.choix_periodes ADD COLUMN closingmotive1 JSONB;
|
||||
@@ -81,7 +87,7 @@ INSERT INTO chill_person_accompanying_period_closingmotive (id, name, active, pa
|
||||
max_ordering.max_ordering + row_number() OVER () as ordering
|
||||
FROM ( SELECT DISTINCT ON (closingmotive) closingmotive1 FROM import.choix_periodes WHERE closingmotive1 IS NOT NULL ) t
|
||||
CROSS JOIN max_ordering
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_accompanying_period_closingmotive WHERE name::jsonb = t.closingmotive1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_accompanying_period_closingmotive WHERE name::jsonb->>'fr' = t.closingmotive1::jsonb->>'fr' );
|
||||
|
||||
-- 9. Complete table accompanying_period_origin
|
||||
ALTER TABLE import.choix_periodes ADD COLUMN origin1 JSONB;
|
||||
@@ -89,7 +95,7 @@ UPDATE import.choix_periodes SET origin1=json_build_object('fr', trim(origin)) W
|
||||
INSERT INTO chill_person_accompanying_period_origin (id, label, noactiveafter)
|
||||
SELECT nextval('chill_person_accompanying_period_origin_id_seq'), t.origin1, null
|
||||
FROM ( SELECT DISTINCT ON (origin) origin1 FROM import.choix_periodes WHERE origin1 IS NOT NULL ) t
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_accompanying_period_origin WHERE label::jsonb = t.origin1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_accompanying_period_origin WHERE label::jsonb->>'fr' = t.origin1::jsonb->>'fr' );
|
||||
|
||||
-- 10. Complete table user_job
|
||||
ALTER TABLE import.choix_periodes ADD COLUMN job1 JSONB;
|
||||
@@ -97,7 +103,7 @@ UPDATE import.choix_periodes SET job1=json_build_object('fr', trim(job)) WHERE j
|
||||
INSERT INTO chill_main_user_job (id, label, active)
|
||||
SELECT nextval('chill_main_user_job_id_seq'), t.job1, true
|
||||
FROM ( SELECT DISTINCT ON (job) job1 FROM import.choix_periodes WHERE job1 IS NOT NULL ) t
|
||||
WHERE NOT EXISTS( SELECT 1 FROM chill_main_user_job WHERE label::jsonb = t.job1 );
|
||||
WHERE NOT EXISTS( SELECT 1 FROM chill_main_user_job WHERE label::jsonb->>'fr' = t.job1::jsonb->>'fr' );
|
||||
|
||||
-- 11. Complete table Scopes
|
||||
ALTER TABLE import.choix_periodes ADD COLUMN acp_scopes1 JSONB;
|
||||
@@ -105,40 +111,42 @@ UPDATE import.choix_periodes SET acp_scopes1=json_build_object('fr', trim(acp_sc
|
||||
INSERT INTO scopes (id, name, active)
|
||||
SELECT nextval('scopes_id_seq'), t.acp_scopes1, true
|
||||
FROM ( SELECT DISTINCT ON (acp_scopes) acp_scopes1 FROM import.choix_periodes WHERE acp_scopes1 IS NOT NULL ) t
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM scopes WHERE name::jsonb = t.acp_scopes1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM scopes WHERE name::jsonb->>'fr' = t.acp_scopes1::jsonb->>'fr' );
|
||||
-- SELECT i.acp_scopes1::jsonb, s.name FROM scopes s LEFT JOIN import.choix_periodes i ON s.name::jsonb = i.acp_scopes1::jsonb WHERE s.name IS NOT NULL or i.acp_scopes1 IS NOT NULL ;
|
||||
|
||||
-- 12. Complete table Users (acp referrer)
|
||||
INSERT INTO users (id, username, password, enabled, locked, attributes, label)
|
||||
SELECT nextval('users_id_seq'), t.referrer, '', false, false, '[]', t.referrer
|
||||
FROM ( SELECT DISTINCT ON (referrer) referrer FROM import.choix_periodes WHERE referrer <> '') t
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM users WHERE username::text = t.referrer );
|
||||
-- SELECT * FROM users;
|
||||
|
||||
-- 13. Complete table SocialIssues
|
||||
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,
|
||||
max_ordering.max_ordering + row_number() OVER () as ordering
|
||||
FROM ( SELECT DISTINCT ON (parent) parent1 FROM import.choix_periodes WHERE parent1 IS NOT NULL ) t
|
||||
CROSS JOIN max_ordering
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_social_issue WHERE title::jsonb = t.parent1 );
|
||||
WHERE NOT EXISTS ( SELECT 1 FROM chill_person_social_issue WHERE title::jsonb->>'fr' = t.parent1::jsonb->>'fr' );
|
||||
WITH max_ordering AS ( SELECT MAX(ordering) 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'),
|
||||
( SELECT id FROM chill_person_social_issue WHERE parent_id IS NULL AND title = t.parent1 ), t.enfant1,
|
||||
( 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 = t.enfant1
|
||||
AND parent_id = (SELECT id FROM chill_person_social_issue WHERE title::jsonb = t.parent1));
|
||||
WHERE title::jsonb->>'fr' = t.enfant1::jsonb->>'fr'
|
||||
AND parent_id = (SELECT id FROM chill_person_social_issue WHERE title::jsonb->>'fr' = t.parent1::jsonb->>'fr'));
|
||||
|
||||
-- 14. Complete table WorkSocialActions
|
||||
|
||||
-- (not yet implemented in canvas)
|
||||
|
||||
-- 20. Prepare personnes civility
|
||||
ALTER TABLE import.personnes ADD COLUMN civility1 jsonb;
|
||||
@@ -148,9 +156,9 @@ 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'
|
||||
WHEN trim(gender) IN ('Autre', 'Inconnu', 'inconnu', 'Unknown', 'unknown') THEN 'unknown'
|
||||
ELSE 'both' END;
|
||||
|
||||
-- 22. Prepare personnes nationality
|
||||
@@ -170,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!='';
|
||||
@@ -207,24 +223,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;
|
||||
|
||||
|
||||
-- 35. Prepare required default dates
|
||||
-- address_validfrom1 | household_startdate1
|
||||
-- acp_openingdate1
|
||||
DO $$
|
||||
DECLARE
|
||||
intl text := 33;
|
||||
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 $$;
|
||||
|
||||
-- 40. Prepare id mapping before insertion
|
||||
ALTER TABLE import.personnes ADD column person_id BIGINT;
|
||||
@@ -236,48 +260,675 @@ UPDATE import.personnes SET person_id=personid
|
||||
INSERT INTO chill_person_person (
|
||||
id
|
||||
, nationality_id, countryofbirth_id, civility_id, maritalstatus_id
|
||||
, firstname, lastname, birthdate, place_of_birth, memo, email, contactinfo, phonenumber, mobilenumber, numberofchildren, gender, deathdate, proxyaccompanyingperiodopenstate
|
||||
, firstname, lastname, birthdate, place_of_birth, memo, email, contactinfo, phonenumber, mobilenumber, numberofchildren, deathdate, proxyaccompanyingperiodopenstate
|
||||
, createdat, updatedat, createdby_id, updatedby_id
|
||||
, center_id
|
||||
, gender_id
|
||||
, gendercomment_comment, gendercomment_userid, gendercomment_date
|
||||
/*
|
||||
, maritalstatusdate
|
||||
, maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date
|
||||
, gendercomment_comment, gendercomment_userid, gendercomment_date
|
||||
, acceptsms, acceptemail
|
||||
*/
|
||||
) SELECT
|
||||
person_id -- id
|
||||
, (SELECT c.id FROM country c WHERE c.name::jsonb = ip.nationality1::jsonb AND ip.nationality1 IS NOT NULL) -- nationality_id,
|
||||
, (SELECT c.id FROM country c WHERE c.name::jsonb = ip.countryofbirth1::jsonb AND ip.countryofbirth1 IS NOT NULL ) -- countryofbirth_id,
|
||||
, (SELECT c.id FROM chill_main_civility c WHERE c.name::jsonb = ip.civility1::jsonb AND ip.civility1 IS NOT NULL ) -- civility_id
|
||||
, (SELECT ms.id FROM chill_person_marital_status ms WHERE ms.name::jsonb = ip.maritalstatus1::jsonb 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
|
||||
, CURRENT_DATE, CURRENT_DATE -- createdat, updatedat
|
||||
, (SELECT c.id FROM country c WHERE c.name::jsonb->>'fr' = ip.nationality1::jsonb->>'fr' AND ip.nationality1 IS NOT NULL) -- nationality_id,
|
||||
, (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,
|
||||
, COALESCE(TRIM(firstname),''), UPPER(TRIM(lastname)), birthdate1, TRIM(placeofbirth1), TRIM(memo1), TRIM(email), TRIM(contactinfo), phonenumber1, mobilenumber1, numberofchildren1, 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
|
||||
, NULL -- center_id should be null, deprecated by chill_person_person_center_history
|
||||
, (SELECT g.id FROM chill_main_gender g WHERE g.gendertranslation = ip.gender1)
|
||||
, TRIM(gendercomment), (SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), date(date_trunc('year', CURRENT_DATE)) --gendercomment_<comment|userid|date>
|
||||
/*
|
||||
, -- maritalstatusdate
|
||||
, -- maritalstatuscomment_comment, maritalstatuscomment_userid, maritalstatuscomment_date
|
||||
, -- gendercomment_comment, gendercomment_userid, gendercomment_date
|
||||
, -- acceptsms, acceptemail
|
||||
*/
|
||||
FROM import.personnes ip;
|
||||
SELECT setval('chill_person_person_id_seq', (SELECT COALESCE(max(id)) FROM chill_person_person));
|
||||
|
||||
-- 42. Fill Person center history
|
||||
INSERT INTO chill_person_person_center_history (id, person_id, center_id, startdate) SELECT
|
||||
nextval('chill_person_person_center_history_id_seq'), person_id,
|
||||
(SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM centers) , -- center_id
|
||||
date(date_trunc('year', CURRENT_DATE))
|
||||
FROM import.personnes ip;
|
||||
-- SELECT ip.id, ip.lastname, ip.firstname, ip.person_id, hist.id, hist.person_id, hist.center_id, hist.startdate, p.id, p.fullnamecanonical, p.email FROM chill_person_person p RIGHT JOIN import.personnes ip ON ip.person_id = p.id FULL JOIN chill_person_person_center_history hist on p.id = hist.person_id ORDER BY ip.person_id;
|
||||
|
||||
-- 43. Add address, and link it to person
|
||||
-- a) add new columns
|
||||
ALTER TABLE import.personnes ADD column address_id BIGINT;
|
||||
ALTER TABLE import.personnes ADD column address_ref_id BIGINT;
|
||||
ALTER TABLE import.personnes ADD column postcode_id BIGINT[];
|
||||
|
||||
-- special command to extract postcode values in text
|
||||
ALTER TABLE import.personnes ADD COLUMN postcode1 TEXT;
|
||||
UPDATE import.personnes SET postcode1=SUBSTRING(postcode FROM '\y\d{5}\y') WHERE postcode!='';
|
||||
|
||||
-- b) find and add postal code references. Check missing correspondances (if you can)
|
||||
UPDATE import.personnes
|
||||
SET postcode_id = (
|
||||
SELECT pc.id
|
||||
FROM chill_main_postal_code AS pc
|
||||
WHERE pc.canonical ILIKE import.personnes.postcode
|
||||
AND pc.origin = 0
|
||||
);
|
||||
--SELECT * FROM import.personnes as ip WHERE ip.postcode_id IS NULL -- missing correspondances
|
||||
|
||||
-- c) find and add reference addresses. Check missing correspondances (if you can)
|
||||
UPDATE import.personnes AS ip SET address_ref_id = cmar.id FROM chill_main_address_reference AS cmar
|
||||
WHERE
|
||||
cmar.postcode_id = ip.postcode_id
|
||||
AND similarity(trim(ip.street), trim(cmar.street)) > 0.6
|
||||
AND trim(ip.streetnumber) = trim(cmar.streetnumber);
|
||||
--SELECT * FROM import.personnes as ip WHERE ip.address_ref_id IS NULL -- missing correspondances
|
||||
|
||||
-- d) fill new chill address
|
||||
UPDATE import.personnes 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_id, 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.personnes WHERE address_ref_id IS NOT NULL;
|
||||
|
||||
-- f) insert created addresses in chill_main_addresses
|
||||
INSERT INTO chill_main_address (id, postcode_id, street, streetnumber, extra, validFrom, point, createdat, updatedat, createdby_id, updatedby_id)
|
||||
SELECT address_id, postcode_id, coalesce(street, ''), coalesce(streetnumber, ''), coalesce(extra,''),
|
||||
CURRENT_DATE,
|
||||
(SELECT center FROM chill_main_postal_code WHERE id = postcode_id), -- geolocation is given by the postcode
|
||||
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.personnes WHERE address_ref_id IS NULL AND postcode_id IS NOT NULL;
|
||||
|
||||
SELECT setval('chill_main_address_id_seq', (SELECT COALESCE(max(id)) FROM chill_main_address));
|
||||
|
||||
-- 44. Add houshold and household member with position
|
||||
INSERT INTO chill_person_household (id) SELECT person_id from import.personnes;
|
||||
SELECT setval('chill_person_household_id_seq', (SELECT max(id) FROM chill_person_household));
|
||||
INSERT INTO chill_person_household_members (id, person_id, household_id, startdate, sharedhousehold, position_id, holder) SELECT
|
||||
nextval('chill_person_household_members_id_seq'), person_id, person_id, COALESCE(household_startdate1, date(date_trunc('year', CURRENT_DATE))),
|
||||
true, (SELECT id FROM chill_person_household_position pos WHERE household_position1::jsonb->>'fr' = pos.label::jsonb->>'fr'), false
|
||||
FROM import.personnes;
|
||||
-- SELECT ip.id, ip.person_id, ip.firstname, ip.lastname, hh.* FROM chill_person_household hh FULL JOIN import.personnes ip ON hh.id = ip.person_id ORDER BY hh.id;
|
||||
-- SELECT ip.id, ip.person_id, ip.firstname, ip.lastname, memb.* FROM chill_person_household_members memb JOIN import.personnes ip ON memb.household_id = ip.person_id ORDER BY memb.household_id;
|
||||
|
||||
-- 45. Link address to household
|
||||
INSERT INTO chill_person_household_to_addresses (household_id, address_id) SELECT person_id, address_id
|
||||
FROM import.personnes WHERE address_id IS NOT NULL AND postcode_arr[1] IS NOT NULL;
|
||||
|
||||
-- 46. Add household composition
|
||||
INSERT INTO chill_person_household_composition (id, household_id, startdate, householdcompositiontype_id) SELECT
|
||||
nextval('chill_person_household_composition_id_seq'), person_id AS household_id, date(date_trunc('year', CURRENT_DATE))
|
||||
, (SELECT id FROM chill_person_household_composition_type ct WHERE household_composition_type1::jsonb->>'fr' = ct.label::jsonb->>'fr')
|
||||
FROM import.personnes
|
||||
WHERE household_composition_type1 IS NOT NULL ;
|
||||
|
||||
|
||||
-- 50. Prepare id mapping before insertion
|
||||
ALTER TABLE import.periodes ADD column period_id BIGINT;
|
||||
UPDATE import.periodes SET period_id = periodid
|
||||
FROM (SELECT id, nextval('chill_person_accompanying_period_id_seq') AS periodid FROM import.periodes ORDER BY id) AS t
|
||||
WHERE import.periodes.id = t.id;
|
||||
--SELECT ipe.id, ipe.fullname, ipe.period_id, ip.id, ip.person_id FROM import.periodes ipe JOIN import.personnes ip ON ipe.id = ip.id ORDER BY ipe.id;
|
||||
|
||||
-- country, adresse,
|
||||
-- ajouter dans chill_person_accompanying_course
|
||||
-- 51. Insert in chill_person_accompanying_period
|
||||
INSERT INTO chill_person_accompanying_period (id, openingdate, closingdate, step, remark, intensity, createdby_id, createdat, updatedby_id, updatedat) SELECT
|
||||
period_id,
|
||||
COALESCE(openingdate1, date(date_trunc('year', CURRENT_DATE))), closingdate1,
|
||||
'CONFIRMED', COALESCE(TRIM(remark), ''), intensity1,
|
||||
(SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), CURRENT_DATE,
|
||||
(SELECT distinct(first_value(id) OVER(ORDER BY id)) FROM users), CURRENT_DATE
|
||||
FROM import.periodes;
|
||||
SELECT setval('chill_person_accompanying_period_id_seq', (SELECT max(id) FROM chill_person_accompanying_period));
|
||||
|
||||
-- 52. Link participations to periods
|
||||
INSERT INTO chill_person_accompanying_period_participation (id, person_id, accompanyingperiod_id, startdate) SELECT
|
||||
nextval('chill_person_accompanying_period_participation_id_seq'), t.person_id, t.period_id, date(date_trunc('year', CURRENT_DATE))
|
||||
FROM (SELECT person_id, period_id FROM import.periodes ip JOIN import.personnes p ON ip.id = p.id ORDER BY person_id) AS t;
|
||||
|
||||
-- 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::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;
|
||||
UPDATE import.choix_periodes SET address_location_id = (SELECT max(id) FROM chill_main_address) WHERE street != '';
|
||||
|
||||
-- 54. Link person or temporary address location to periods
|
||||
UPDATE chill_person_accompanying_period acp
|
||||
SET addresslocation_id = (SELECT address_location_id FROM import.choix_periodes WHERE address_location_id IS NOT NULL LIMIT 1)
|
||||
FROM import.personnes pson JOIN import.periodes piod ON pson.id = piod.id
|
||||
WHERE piod.period_id = acp.id AND piod.addresslocation = 'oui';
|
||||
UPDATE chill_person_accompanying_period acp
|
||||
SET personlocation_id = pson.person_id
|
||||
FROM import.personnes pson JOIN import.periodes piod ON pson.id = piod.id
|
||||
WHERE piod.period_id = acp.id AND piod.personlocation = 'oui';
|
||||
|
||||
-- 55. Copy period in period_location_history
|
||||
INSERT INTO chill_person_accompanying_period_location_history (id, period_id, startdate, enddate, personlocation_id, addresslocation_id, createdat, createdby_id)
|
||||
SELECT
|
||||
nextval('chill_person_accompanying_period_location_history_id_seq'), id, acp.openingdate, acp.closingdate,
|
||||
acp.personlocation_id, acp.addresslocation_id, acp.createdat, acp.createdby_id
|
||||
FROM chill_person_accompanying_period acp
|
||||
WHERE id NOT IN (SELECT period_id FROM chill_person_accompanying_period_location_history) AND step LIKE 'CONFIRMED' ORDER BY id;
|
||||
|
||||
-- 56. Link socialIssues to periods
|
||||
INSERT INTO chill_person_accompanying_period_social_issues (accompanyingperiod_id, socialissue_id)
|
||||
SELECT
|
||||
DISTINCT ON (t.period_id) t.period_id,
|
||||
COALESCE(
|
||||
t.enfant_id,
|
||||
t.parent_id,
|
||||
1 -- default value ?
|
||||
) AS socialissue_id
|
||||
FROM (
|
||||
SELECT p.period_id,
|
||||
(SELECT id FROM chill_person_social_issue WHERE title::jsonb->>'fr' = icp.parent1::jsonb->>'fr' AND parent_id IS NULL) AS parent_id, icp.parent1,
|
||||
(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_social_issues
|
||||
ORDER BY id) AS t;
|
||||
|
||||
-- 57. Link referrer to periods
|
||||
UPDATE chill_person_accompanying_period acp
|
||||
SET user_id = COALESCE(
|
||||
(SELECT id FROM users WHERE users.username = ip.referrer),
|
||||
1 -- default value ?
|
||||
)
|
||||
FROM import.periodes ip WHERE acp.id = ip.period_id;
|
||||
--SELECT ip.id, (SELECT id FROM users WHERE users.username = ip.referrer) AS referrer_id, ip.referrer, acp.id as period_id, acp.user_id FROM chill_person_accompanying_period acp JOIN import.periodes ip ON ip.period_id = acp.id ORDER BY ip.id;
|
||||
|
||||
-- 58. Link scopes to periods
|
||||
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' = 'Principal') -- default value 'Principal'
|
||||
)
|
||||
FROM import.periodes ip;
|
||||
|
||||
-- 59. Link origin to periods
|
||||
UPDATE chill_person_accompanying_period acp SET origin_id =
|
||||
(SELECT id FROM chill_person_accompanying_period_origin o WHERE o.label::jsonb->>'fr' = ip.origin1::jsonb->>'fr')
|
||||
FROM import.periodes ip WHERE acp.id = ip.period_id;
|
||||
--SELECT ip.id, ip.origin1, acp.id as period_id, acp.origin_id FROM chill_person_accompanying_period acp JOIN import.periodes ip ON ip.period_id = acp.id ORDER BY ip.id;
|
||||
|
||||
-- 60. Link jobs to periods
|
||||
UPDATE chill_person_accompanying_period acp SET job_id =
|
||||
(SELECT id FROM chill_main_user_job j WHERE j.label::jsonb->>'fr' = ip.job1::jsonb->>'fr')
|
||||
FROM import.periodes ip WHERE acp.id = ip.period_id;
|
||||
|
||||
-- 61. Link administrative Location
|
||||
-- (to be add in csv)
|
||||
|
||||
-- 62. Add and link comments
|
||||
INSERT INTO chill_person_accompanying_period_comment (id, accompanyingperiod_id, content, creator_id, createdat, updatedby_id, updatedat)
|
||||
SELECT nextval('chill_person_accompanying_period_comment_id_seq'), period_id, comment1_content,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP
|
||||
FROM import.periodes ip WHERE ip.comment1_content != '';
|
||||
INSERT INTO chill_person_accompanying_period_comment (id, accompanyingperiod_id, content, creator_id, createdat, updatedby_id, updatedat)
|
||||
SELECT nextval('chill_person_accompanying_period_comment_id_seq'), period_id, comment2_content,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP
|
||||
FROM import.periodes ip WHERE ip.comment2_content != '';
|
||||
INSERT INTO chill_person_accompanying_period_comment (id, accompanyingperiod_id, content, creator_id, createdat, updatedby_id, updatedat)
|
||||
SELECT nextval('chill_person_accompanying_period_comment_id_seq'), period_id, comment3_content,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP
|
||||
FROM import.periodes ip WHERE ip.comment3_content != '';
|
||||
INSERT INTO chill_person_accompanying_period_comment (id, accompanyingperiod_id, content, creator_id, createdat, updatedby_id, updatedat)
|
||||
SELECT nextval('chill_person_accompanying_period_comment_id_seq'), period_id, comment4_content,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP
|
||||
FROM import.periodes ip WHERE ip.comment4_content != '';
|
||||
INSERT INTO chill_person_accompanying_period_comment (id, accompanyingperiod_id, content, creator_id, createdat, updatedby_id, updatedat)
|
||||
SELECT nextval('chill_person_accompanying_period_comment_id_seq'), period_id, comment5_content,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP,
|
||||
(SELECT user_id FROM chill_person_accompanying_period acp WHERE acp.id = ip.period_id), CURRENT_TIMESTAMP
|
||||
FROM import.periodes ip WHERE ip.comment5_content != '';
|
||||
|
||||
-- 63. Link pinned comment to period
|
||||
UPDATE import.periodes SET comment1_content = null WHERE comment1_content = '';
|
||||
UPDATE import.periodes SET comment2_content = null WHERE comment2_content = '';
|
||||
UPDATE import.periodes SET comment3_content = null WHERE comment3_content = '';
|
||||
UPDATE import.periodes SET comment4_content = null WHERE comment4_content = '';
|
||||
UPDATE import.periodes SET comment5_content = null WHERE comment5_content = '';
|
||||
UPDATE chill_person_accompanying_period acp SET pinnedcomment_id =
|
||||
(SELECT id FROM chill_person_accompanying_period_comment com WHERE com.accompanyingperiod_id = acp.id
|
||||
AND com.content = COALESCE(ip.comment5_content, ip.comment4_content, ip.comment3_content, ip.comment2_content, ip.comment1_content)
|
||||
LIMIT 1)
|
||||
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),
|
||||
'',
|
||||
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) );
|
||||
|
||||
-- ========================================================================================= --
|
||||
|
||||
--
|
||||
-- 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;
|
||||
UPDATE import.periodes SET comment2_content = '' WHERE comment2_content IS NULL;
|
||||
UPDATE import.periodes SET comment3_content = '' WHERE comment3_content IS NULL;
|
||||
UPDATE import.periodes SET comment4_content = '' WHERE comment4_content IS NULL;
|
||||
UPDATE import.periodes SET comment5_content = '' WHERE comment5_content IS NULL;
|
||||
|
||||
-- Undo 62.
|
||||
DELETE FROM chill_person_accompanying_period_comment com USING import.periodes ip WHERE com.accompanyingperiod_id = ip.period_id;
|
||||
SELECT setval('chill_person_accompanying_period_comment_id_seq', (SELECT COALESCE(max(id), 1) FROM chill_person_accompanying_period_comment));
|
||||
|
||||
-- Undo 61.
|
||||
|
||||
-- Undo 60.
|
||||
UPDATE chill_person_accompanying_period acp SET job_id = null FROM import.periodes ip WHERE acp.id = ip.period_id;
|
||||
|
||||
-- Undo 59.
|
||||
UPDATE chill_person_accompanying_period acp SET origin_id = null FROM import.periodes ip WHERE ip.period_id = acp.id;
|
||||
|
||||
-- Undo 58.
|
||||
DELETE FROM accompanying_periods_scopes acs USING import.periodes ip WHERE acs.accompanying_period_id = ip.period_id;
|
||||
|
||||
-- Undo 57.
|
||||
UPDATE chill_person_accompanying_period acp SET user_id = null FROM import.periodes ip WHERE ip.period_id = acp.id;
|
||||
|
||||
-- Undo 56.
|
||||
DELETE FROM chill_person_accompanying_period_social_issues asi USING import.periodes ip WHERE asi.accompanyingperiod_id = ip.period_id;
|
||||
|
||||
-- Undo 55.
|
||||
DELETE FROM chill_person_accompanying_period_location_history history USING import.periodes ip WHERE history.period_id = ip.period_id;
|
||||
SELECT setval('chill_person_accompanying_period_location_history_id_seq', (SELECT COALESCE(max(id), 1) FROM chill_person_accompanying_period_location_history));
|
||||
|
||||
-- Undo 54.
|
||||
UPDATE chill_person_accompanying_period acp SET addresslocation_id = NULL, personlocation_id = NULL FROM import.periodes piod WHERE piod.period_id = acp.id;
|
||||
|
||||
-- Undo 53.
|
||||
DELETE FROM chill_main_address addr USING import.choix_periodes ic WHERE addr.id = ic.address_location_id;
|
||||
SELECT setval('chill_main_address_id_seq', (SELECT COALESCE(max(id), 1) FROM chill_main_address));
|
||||
ALTER TABLE import.choix_periodes DROP COLUMN address_location_id;
|
||||
|
||||
-- Undo 52.
|
||||
DELETE FROM chill_person_accompanying_period_participation part USING import.periodes ip WHERE part.accompanyingperiod_id = ip.period_id;
|
||||
SELECT setval('chill_person_accompanying_period_participation_id_seq', (SELECT COALESCE(max(id), 1) FROM chill_person_accompanying_period_participation));
|
||||
|
||||
-- Undo 51.
|
||||
DELETE FROM chill_person_accompanying_period acp USING import.periodes ip WHERE acp.id = ip.period_id;
|
||||
SELECT setval('chill_person_accompanying_period_id_seq', (SELECT COALESCE(max(id), 1) FROM chill_person_accompanying_period));
|
||||
|
||||
-- Undo 50.
|
||||
ALTER TABLE import.periodes DROP column period_id;
|
||||
|
||||
-- Undo 46.
|
||||
DELETE FROM chill_person_household_composition c USING import.personnes ip WHERE c.household_id = ip.person_id;
|
||||
SELECT setval('chill_person_household_composition_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_household_composition));
|
||||
|
||||
-- Undo 45.
|
||||
DELETE FROM chill_person_household_to_addresses hhaddr USING import.personnes ip WHERE hhaddr.household_id = ip.person_id;
|
||||
|
||||
-- Undo 44.
|
||||
DELETE FROM chill_person_household_members memb USING import.personnes ip WHERE memb.person_id = ip.person_id;
|
||||
SELECT setval('chill_person_household_members_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_household_members));
|
||||
DELETE FROM chill_person_household hh USING import.personnes ip WHERE hh.id = ip.person_id;
|
||||
SELECT setval('chill_person_household_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_household));
|
||||
|
||||
-- Undo 43.
|
||||
DELETE FROM chill_main_address addr USING import.personnes ip WHERE addr.id = ip.address_id;
|
||||
SELECT setval('chill_main_address_id_seq', (SELECT COALESCE(max(id),1) FROM chill_main_address));
|
||||
ALTER TABLE import.personnes DROP column postcode_id;
|
||||
ALTER TABLE import.personnes DROP column address_id;
|
||||
|
||||
-- Undo 42.
|
||||
DELETE FROM chill_person_person_center_history hist USING import.personnes ip WHERE hist.person_id = ip.person_id;
|
||||
SELECT setval('chill_person_person_center_history_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_person_center_history));
|
||||
|
||||
-- Undo 41.
|
||||
DELETE FROM chill_person_person cpp USING import.personnes ip WHERE cpp.id = ip.person_id;
|
||||
SELECT setval('chill_person_person_id_seq', (SELECT max(id) FROM chill_person_person));
|
||||
DELETE FROM chill_person_person p USING import.personnes ip WHERE p.id = ip.person_id;
|
||||
SELECT setval('chill_person_person_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_person));
|
||||
|
||||
-- Undo 40.
|
||||
ALTER TABLE import.personnes DROP COLUMN person_id;
|
||||
@@ -331,8 +982,8 @@ ALTER TABLE import.personnes DROP COLUMN civility1;
|
||||
|
||||
-- Undo 13.
|
||||
DELETE FROM chill_person_social_issue USING import.choix_periodes i
|
||||
WHERE parent_id IN ( SELECT id FROM chill_person_social_issue cpsi WHERE cpsi.title::jsonb = i.parent1::jsonb AND cpsi.parent_id IS NULL );
|
||||
DELETE FROM chill_person_social_issue cpsi USING import.choix_periodes icp WHERE cpsi.title::jsonb = icp.parent1::jsonb AND cpsi.parent_id IS NULL ;
|
||||
WHERE parent_id IN ( SELECT id FROM chill_person_social_issue cpsi WHERE cpsi.title::jsonb->>'fr' = i.parent1::jsonb->>'fr' AND cpsi.parent_id IS NULL );
|
||||
DELETE FROM chill_person_social_issue cpsi USING import.choix_periodes icp WHERE cpsi.title::jsonb->>'fr' = icp.parent1::jsonb->>'fr' AND cpsi.parent_id IS NULL ;
|
||||
SELECT setval('chill_person_social_issue_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_social_issue));
|
||||
ALTER TABLE import.choix_periodes DROP COLUMN enfant1;
|
||||
ALTER TABLE import.choix_periodes DROP COLUMN parent1;
|
||||
@@ -342,46 +993,54 @@ DELETE FROM users USING import.choix_periodes icp WHERE users.username::text = i
|
||||
SELECT setval('users_id_seq', (SELECT COALESCE(max(id),1) FROM users));
|
||||
|
||||
-- Undo 11.
|
||||
DELETE FROM scopes USING import.choix_periodes icp WHERE scopes.name::jsonb = icp.acp_scopes1::jsonb;
|
||||
DELETE FROM scopes USING import.choix_periodes icp WHERE scopes.name::jsonb->>'fr' = icp.acp_scopes1::jsonb->>'fr'
|
||||
AND NOT EXISTS (SELECT 1 FROM import.choix_periodes WHERE scopes.name::jsonb->>'fr' = icp.acp_scopes1::jsonb->>'fr');
|
||||
SELECT setval('scopes_id_seq', (SELECT COALESCE(max(id),1) FROM scopes));
|
||||
ALTER TABLE import.choix_periodes DROP COLUMN acp_scopes1;
|
||||
|
||||
-- Undo 10.
|
||||
DELETE FROM chill_main_user_job cmuj USING import.choix_periodes icp WHERE cmuj.label::jsonb = icp.job1::jsonb;
|
||||
DELETE FROM chill_main_user_job cmuj USING import.choix_periodes icp WHERE cmuj.label::jsonb->>'fr' = icp.job1::jsonb->>'fr'
|
||||
AND NOT EXISTS (SELECT 1 FROM import.choix_periodes WHERE cmuj.label::jsonb->>'fr' = icp.job1::jsonb->>'fr');
|
||||
SELECT setval('chill_main_user_job_id_seq', (SELECT COALESCE(max(id),1) FROM chill_main_user_job));
|
||||
ALTER TABLE import.choix_periodes DROP COLUMN job1;
|
||||
|
||||
-- Undo 9.
|
||||
DELETE FROM chill_person_accompanying_period_origin cpapo USING import.choix_periodes icp WHERE cpapo.label::jsonb = icp.origin1::jsonb;
|
||||
DELETE FROM chill_person_accompanying_period_origin cpapo USING import.choix_periodes icp WHERE cpapo.label::jsonb->>'fr' = icp.origin1::jsonb->>'fr'
|
||||
AND NOT EXISTS (SELECT 1 FROM import.choix_periodes WHERE cpapo.label::jsonb->>'fr' = icp.origin1::jsonb->>'fr');
|
||||
SELECT setval('chill_person_accompanying_period_origin_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_accompanying_period_origin));
|
||||
ALTER TABLE import.choix_periodes DROP COLUMN origin1;
|
||||
|
||||
-- Undo 8.
|
||||
DELETE FROM chill_person_accompanying_period_closingmotive cpapcm USING import.choix_periodes icp WHERE cpapcm.name::jsonb = icp.closingmotive1::jsonb;
|
||||
DELETE FROM chill_person_accompanying_period_closingmotive cpapcm USING import.choix_periodes icp WHERE cpapcm.name::jsonb->>'fr' = icp.closingmotive1::jsonb->>'fr'
|
||||
AND NOT EXISTS (SELECT 1 FROM import.choix_periodes WHERE cpapcm.name::jsonb->>'fr' = icp.closingmotive1::jsonb->>'fr');
|
||||
SELECT setval('chill_person_accompanying_period_closingmotive_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_accompanying_period_closingmotive));
|
||||
ALTER TABLE import.choix_periodes DROP COLUMN closingmotive1;
|
||||
|
||||
-- Undo 7.
|
||||
DELETE FROM chill_person_household_position cphp USING import.choix_personnes icp WHERE cphp.label::jsonb = icp.household_position1::jsonb;
|
||||
DELETE FROM chill_person_household_position cphp USING import.choix_personnes icp WHERE cphp.label::jsonb->>'fr' = icp.household_position1::jsonb->>'fr'
|
||||
AND NOT EXISTS (SELECT 1 FROM import.choix_personnes WHERE cphp.label::jsonb->>'fr' = icp.household_position1::jsonb->>'fr');
|
||||
SELECT setval('chill_person_household_position_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_household_position));
|
||||
ALTER TABLE import.choix_personnes DROP COLUMN household_position1;
|
||||
|
||||
-- Undo 6.
|
||||
DELETE FROM chill_person_household_composition_type cphct USING import.choix_personnes icp WHERE cphct.label::jsonb = icp.household_composition_type1::jsonb AND cphct.id > 6;
|
||||
DELETE FROM chill_person_household_composition_type cphct USING import.choix_personnes icp WHERE cphct.label::jsonb->>'fr' = icp.household_composition_type1::jsonb->>'fr'
|
||||
AND NOT EXISTS (SELECT 1 FROM import.choix_personnes WHERE cphct.label::jsonb->>'fr' = icp.household_composition_type1::jsonb->>'fr');
|
||||
SELECT setval('chill_person_household_composition_type_id_seq', (SELECT COALESCE(max(id),1) FROM chill_person_household_composition_type));
|
||||
ALTER TABLE import.choix_personnes DROP COLUMN household_composition_type1;
|
||||
|
||||
-- Undo 5.
|
||||
DELETE FROM chill_person_marital_status cpms USING import.choix_personnes icp WHERE cpms.name::jsonb = icp.maritalstatus1::jsonb AND cpms.id <> 'célibat.' AND cpms.id <> 'marié'; -- existing marital status
|
||||
DELETE FROM chill_person_marital_status cpms USING import.choix_personnes icp WHERE cpms.name::jsonb->>'fr' = icp.maritalstatus1::jsonb->>'fr'
|
||||
AND NOT EXISTS (SELECT 1 FROM import.choix_personnes WHERE cpms.name::jsonb->>'fr' = icp.maritalstatus1::jsonb->>'fr');
|
||||
ALTER TABLE import.choix_personnes DROP COLUMN maritalstatus1;
|
||||
|
||||
-- Undo 4.
|
||||
DELETE FROM country USING import.choix_personnes icp WHERE country.name::jsonb = icp.country1::jsonb AND country.id > 249; -- 249 existing countries
|
||||
DELETE FROM country USING import.choix_personnes icp WHERE country.name::jsonb->>'fr' = icp.country1::jsonb->>'fr' AND country.id > 249; -- 249 existing countries
|
||||
SELECT setval('country_id_seq', (SELECT COALESCE(max(id),1) FROM country));
|
||||
ALTER TABLE import.choix_personnes DROP COLUMN country1;
|
||||
|
||||
-- Undo 3.
|
||||
DELETE FROM chill_main_civility cmc USING import.choix_personnes ip WHERE cmc.name::jsonb = ip.civility1::jsonb;
|
||||
DELETE FROM chill_main_civility cmc USING import.choix_personnes ip WHERE cmc.name::jsonb->>'fr' = ip.civility1::jsonb->>'fr'
|
||||
AND NOT EXISTS (SELECT 1 FROM import.choix_personnes WHERE cmc.name::jsonb->>'fr' = ip.civility1::jsonb->>'fr');
|
||||
SELECT setval('chill_main_civility_id_seq', (SELECT COALESCE(max(id),1) FROM chill_main_civility));
|
||||
ALTER TABLE import.choix_personnes DROP COLUMN civility1;
|
||||
|
||||
@@ -394,7 +1053,9 @@ ALTER TABLE import.periodes DROP COLUMN openingdate1;
|
||||
ALTER TABLE import.periodes DROP COLUMN closingdate1;
|
||||
|
||||
|
||||
-- -------------
|
||||
-- tiers choices_list: civility kind profession category
|
||||
|
||||
|
||||
-- =============
|
||||
-- QUESTIONS
|
||||
--
|
||||
-- définir par défaut: quel user, quel centre ?
|
||||
--
|
||||
|
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
Executable file
14
third_party/README.md
vendored
Executable 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
Executable file
118
third_party/import_third_party_to_sql.py
vendored
Executable 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