diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/garage/_mes_aides_garage__models.yml b/pipeline/dbt/models/intermediate/sources/mes_aides/garage/_mes_aides_garage__models.yml index 80d6c182..4b0c96df 100644 --- a/pipeline/dbt/models/intermediate/sources/mes_aides/garage/_mes_aides_garage__models.yml +++ b/pipeline/dbt/models/intermediate/sources/mes_aides/garage/_mes_aides_garage__models.yml @@ -1,7 +1,7 @@ version: 2 models: - - name: int_mes_aides_garages__adresses + - name: int_mes_aides__garages__adresses data_tests: - check_adresse: config: @@ -13,7 +13,7 @@ models: - not_null - dbt_utils.not_empty_string - - name: int_mes_aides_garages__structures + - name: int_mes_aides__garages__structures data_tests: - check_structure: config: @@ -28,10 +28,10 @@ models: data_tests: - not_null - relationships: - to: ref('int_mes_aides_garages__adresses') + to: ref('int_mes_aides__garages__adresses') field: id - - name: int_mes_aides_garages__services + - name: int_mes_aides__garages__services data_tests: - check_service: config: @@ -46,11 +46,11 @@ models: data_tests: - not_null - relationships: - to: ref('int_mes_aides_garages__structures') + to: ref('int_mes_aides__garages__structures') field: id - name: adresse_id data_tests: - not_null - relationships: - to: ref('int_mes_aides_garages__adresses') + to: ref('int_mes_aides__garages__adresses') field: id \ No newline at end of file diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides_garages__adresses.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides__garages__adresses.sql similarity index 100% rename from pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides_garages__adresses.sql rename to pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides__garages__adresses.sql diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides_garages__services.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides__garages__services.sql similarity index 100% rename from pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides_garages__services.sql rename to pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides__garages__services.sql diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides_garages__structures.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides__garages__structures.sql similarity index 100% rename from pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides_garages__structures.sql rename to pipeline/dbt/models/intermediate/sources/mes_aides/garage/int_mes_aides__garages__structures.sql diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__adresses.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__adresses.sql index 7effece8..2c63dc6b 100644 --- a/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__adresses.sql +++ b/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__adresses.sql @@ -1,3 +1,3 @@ {{ dbt_utils.union_relations( - relations=[ref('int_mes_aides_garages__adresses'), ref('int_mes_aides_permis_velo__adresses')] + relations=[ref('int_mes_aides__garages__adresses'), ref('int_mes_aides__permis_velo__adresses')] ) }} diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__services.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__services.sql index 82515118..e4eeff9e 100644 --- a/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__services.sql +++ b/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__services.sql @@ -1,3 +1,20 @@ -{{ dbt_utils.union_relations( - relations=[ref('int_mes_aides_garages__services'), ref('int_mes_aides_permis_velo__services')] -) }} +{{ + dbt_utils.union_relations( + relations=[ + ref('int_mes_aides__permis_velo__services'), + ref('int_mes_aides__garages__services'), + ], + column_override={ + "frais": "TEXT[]", + "justificatifs": "TEXT[]", + "modes_accueil": "TEXT[]", + "modes_orientation_accompagnateur": "TEXT[]", + "modes_orientation_beneficiaire": "TEXT[]", + "pre_requis": "TEXT[]", + "profils": "TEXT[]", + "thematiques": "TEXT[]", + "types": "TEXT[]", + }, + source_column_name=None + ) +}} diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__structures.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__structures.sql index f2558ad2..9e31160a 100644 --- a/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__structures.sql +++ b/pipeline/dbt/models/intermediate/sources/mes_aides/int_mes_aides__structures.sql @@ -1,3 +1,14 @@ -{{ dbt_utils.union_relations( - relations=[ref('int_mes_aides_garages__structures'), ref('int_mes_aides_permis_velo__structures')] -) }} +{{ + dbt_utils.union_relations( + relations=[ + ref('int_mes_aides__permis_velo__structures'), + ref('int_mes_aides__garages__structures'), + ], + column_override={ + "labels_nationaux": "TEXT[]", + "labels_autres": "TEXT[]", + "thematiques": "TEXT[]", + }, + source_column_name=None + ) +}} diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/_map_permis_velo_thematiques.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/_map_permis_velo_thematiques.sql new file mode 100644 index 00000000..a0237f81 --- /dev/null +++ b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/_map_permis_velo_thematiques.sql @@ -0,0 +1,59 @@ +{{ config(materialized='ephemeral') }} +WITH mapping_thematiques AS ( + SELECT x.* + FROM ( + VALUES + ('Financer mon permis', 'transport-et-mobilite', 'mobilite--financer-mon-projet-mobilite'), + ('Financer mon permis', 'transport-et-mobilite', 'mobilite--preparer-son-permis-de-conduire-se-reentrainer-a-la-conduite'), + ('Financer mes trajets', 'transport-et-mobilite', 'mobilite--financer-mon-projet-mobilite'), + ('Financer le carburant', 'transport-et-mobilite', 'mobilite--financer-mon-projet-mobilite'), + ('Financer mon BSR', 'transport-et-mobilite', 'mobilite--financer-mon-projet-mobilite'), + ('Financer l''achat d''un véhicule', 'transport-et-mobilite', 'mobilite--acheter-un-vehicule-motorise'), + ('Déménager', 'logement', 'logement-hebergement--demenagement'), + ('Transports en commun', 'transport-et-mobilite', 'mobilite--comprendre-et-utiliser-les-transports-en-commun'), + ('Transport à la demande', 'transport-et-mobilite', 'mobilite--etre-accompagne-dans-son-parcours-mobilite'), + ('Réparer ma voiture', 'transport-et-mobilite', 'mobilite--entretenir-reparer-son-vehicule'), + ('Louer un vélo électrique', 'transport-et-mobilite', 'mobilite--louer-un-vehicule'), + ('Ma voiture', 'transport-et-mobilite', 'mobilite--louer-un-vehicule'), + ('Ma voiture', 'transport-et-mobilite', 'mobilite--entretenir-reparer-son-vehicule'), + ('Ma voiture', 'transport-et-mobilite', 'mobilite--acheter-un-vehicule-motorise'), + ('Mon vélo électrique', 'transport-et-mobilite', 'mobilite--acheter-un-velo'), + ('Mon vélo électrique', 'transport-et-mobilite', 'mobilite--entretenir-reparer-son-vehicule'), + ('Mon vélo électrique', 'transport-et-mobilite', 'mobilite--apprendre-a-utiliser-un-deux-roues'), + ('Mon vélo électrique', 'transport-et-mobilite', 'mobilite--louer-un-vehicule'), + ('Mon vélo électrique', 'transport-et-mobilite', 'mobilite--acheter-un-vehicule-motorise'), + ('Mon scooter', 'transport-et-mobilite', 'mobilite--entretenir-reparer-son-vehicule'), + ('Mon scooter', 'transport-et-mobilite', 'mobilite--apprendre-a-utiliser-un-deux-roues'), + ('Mon scooter', 'transport-et-mobilite', 'mobilite--louer-un-vehicule'), + ('Acheter un vélo électrique', 'transport-et-mobilite', 'mobilite--acheter-un-velo'), + ('Acheter ou louer un vélo', 'transport-et-mobilite', 'mobilite--acheter-un-velo'), + ('Acheter ou louer un vélo', 'transport-et-mobilite', 'mobilite--louer-un-vehicule'), + ('Acheter ou louer une voiture', 'transport-et-mobilite', 'mobilite--louer-un-vehicule'), + ('Acheter ou louer une voiture', 'transport-et-mobilite', 'mobilite--acheter-un-vehicule-motorise'), + ('Accéder au permis de conduire', 'transport-et-mobilite', 'mobilite--preparer-son-permis-de-conduire-se-reentrainer-a-la-conduite'), + ('Déménager', 'logement', 'logement-hebergement--demenagement'), + ('Partir à l''étranger', 's-ouvrir-a-l-international', 'souvrir-a-linternational--sinformer-sur-les-aides-pour-travailler-a-letranger'), + ('Handicap & mobilité', 'transport-et-mobilite', 'handicap--favoriser-le-retour-et-le-maintien-dans-lemploi'), + ('Trouver une alternance', 'trouver-un-job', 'trouver-un-emploi--suivre-ses-candidatures-et-relancer-les-employeurs'), + ('Trouver une alternance', 'trouver-un-job', 'trouver-un-emploi--convaincre-un-recruteur-en-entretien'), + ('Trouver une alternance', 'trouver-un-job', 'trouver-un-emploi--faire-des-candidatures-spontanees'), + ('Trouver une alternance', 'trouver-un-job', 'trouver-un-emploi--repondre-a-des-offres-demploi'), + ('Trouver un contrat d''apprentissage', 'trouver-un-job', 'trouver-un-emploi--suivre-ses-candidatures-et-relancer-les-employeurs'), + ('Trouver un contrat d''apprentissage', 'trouver-un-job', 'trouver-un-emploi--convaincre-un-recruteur-en-entretien'), + ('Trouver un contrat d''apprentissage', 'trouver-un-job', 'trouver-un-emploi--faire-des-candidatures-spontanees'), + ('Trouver un contrat d''apprentissage', 'trouver-un-job', 'trouver-un-emploi--repondre-a-des-offres-demploi'), + ('Préparer une candidature', 'trouver-un-job', 'preparer-sa-candidature--valoriser-ses-competences'), + ('Rédiger une lettre de motivation ou un CV', 'trouver-un-job', 'preparer-sa-candidature--realiser-un-cv-et-ou-une-lettre-de-motivation'), + ('Devenir locataire', 'logement', 'logement-hebergement--etre-accompagne-pour-se-loger'), + ('Financer mon loyer', 'logement', 'logement-hebergement--gerer-son-budget'), + ('Faire des travaux', 'logement', 'logement-hebergement--besoin-dadapter-mon-logement'), + ('Trouver un logement social', 'logement', 'logement-hebergement--etre-accompagne-pour-se-loger'), + ('Financer une formation', 'formation-et-orientation', 'se-former--monter-son-dossier-de-formation'), + ('Trouver une formation', 'formation-et-orientation', 'se-former--trouver-sa-formation'), + ('Rémunération pendant la formation', 'formation-et-orientation', 'se-former--monter-son-dossier-de-formation'), + ('Reconversion', 'formation-et-orientation', 'se-former--trouver-sa-formation'), + ('Accompagnement personnalisé à la mobilité', 'transport-et-mobilite', 'mobilite--etre-accompagne-dans-son-parcours-mobilite') + ) AS x (besoins, thematiques, correspondance_di) +) + +SELECT * FROM mapping_thematiques diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/_mes_aides__models.yml b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/_mes_aides__models.yml index 9a20a02e..8f2b5e97 100644 --- a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/_mes_aides__models.yml +++ b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/_mes_aides__models.yml @@ -1,7 +1,7 @@ version: 2 models: - - name: int_mes_aides_permis_velo__adresses + - name: int_mes_aides__permis_velo__adresses data_tests: - check_adresse: config: @@ -14,7 +14,7 @@ models: - dbt_utils.not_empty_string - - name: int_mes_aides_permis_velo__structures + - name: int_mes_aides__permis_velo__structures data_tests: - check_structure: config: @@ -29,10 +29,10 @@ models: data_tests: - not_null - relationships: - to: ref('int_mes_aides_permis_velo__adresses') + to: ref('int_mes_aides__permis_velo__adresses') field: id - - name: int_mes_aides_permis_velo__services + - name: int_mes_aides__permis_velo__services data_tests: - check_service: config: @@ -47,11 +47,11 @@ models: data_tests: - not_null - relationships: - to: ref('int_mes_aides_permis_velo__structures') + to: ref('int_mes_aides__permis_velo__structures') field: id - name: adresse_id data_tests: - not_null - relationships: - to: ref('int_mes_aides_permis_velo__adresses') + to: ref('int_mes_aides__permis_velo__adresses') field: id diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides_permis_velo__adresses.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides__permis_velo__adresses.sql similarity index 100% rename from pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides_permis_velo__adresses.sql rename to pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides__permis_velo__adresses.sql diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides__permis_velo__services.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides__permis_velo__services.sql new file mode 100644 index 00000000..88350e8b --- /dev/null +++ b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides__permis_velo__services.sql @@ -0,0 +1,189 @@ +{% set check_structure_str = "Veuillez vérifier sur le site internet de la structure" %} + +WITH permis_velo AS ( + SELECT * FROM {{ ref('stg_mes_aides__permis_velo') }} +), + +communes AS ( + SELECT * FROM {{ ref('stg_decoupage_administratif__communes') }} +), + +departements AS ( + SELECT * FROM {{ ref('stg_decoupage_administratif__departements') }} +), + +regions AS ( + SELECT * FROM {{ ref('stg_decoupage_administratif__regions') }} +), + +mapping_thematiques AS ( + SELECT * FROM {{ ref('_map_permis_velo_thematiques') }} +), + +zone_code AS ( + SELECT + permis_velo.id, + communes.code, + communes.code_epci, + communes.code_departement, + communes.code_region + FROM permis_velo + LEFT JOIN communes ON permis_velo.liaisons_code_postal = ANY(communes.codes_postaux) AND communes.nom LIKE permis_velo.liaisons_ville_nom +), + +types_mapping AS ( + SELECT x.* + FROM ( + VALUES + ('Aide financière', 'aide-financiere'), + ('Prestation', 'aide-materielle'), + ('Accompagnement', 'accompagnement') + ) AS x (types_mes_aides, types_di) +), + +zone_de_diffusion_mapping AS ( + SELECT x.* + FROM ( + VALUES + ('Échelle communale', 'commune'), + ('Échelle intercommunale', 'epci'), + ('Échelle régionale', 'region'), + ('Échelle départementale', 'departement'), + ('France métropolitaine', 'pays'), + ('Échelle nationale', 'pays') + ) AS x (zone_mes_aides, zone_di) +), + +frais_mapping AS ( + SELECT x.* + FROM ( + VALUES + ('payant', ARRAY['Somme d''argent', 'Prise en charge partielle', 'Tarif préférentiel']), + ('gratuit', ARRAY['Prise en charge totale', 'Prêt remboursement']), + ('gratuit-sous-conditions', ARRAY['Facilitation de paiement', 'Prise en charge partielle ou totale']) + ) AS x (frais_di, frais_mes_aides) +), + +zone_diffusion AS ( + SELECT + zone_de_diffusion_mapping.zone_di, + permis_velo.id + FROM permis_velo + INNER JOIN zone_de_diffusion_mapping ON permis_velo.zone_geographique = zone_de_diffusion_mapping.zone_mes_aides +), + +modes_orientation_mapping AS ( + SELECT x.* + FROM ( + VALUES + ('La démarche nécessite un passage ou une prise de contact directe avec votre organisme', ARRAY['envoyer-un-email', 'telephoner'], ARRAY['envoyer-un-email', 'telephoner', 'se-presenter']), + ('La démarche nécessite une connexion sur le site de votre organisme', ARRAY['completer-le-formulaire-dadhesion'], ARRAY['completer-le-formulaire-dadhesion']), + ('La démarche peut être faite par mail', ARRAY['envoyer-un-email'], ARRAY['envoyer-un-email']) + ) AS x (demarche, modes_orientation_accompagnateur, modes_orientation_beneficiaire) +), + +thematiques AS ( + SELECT + ARRAY_AGG(mapping_thematiques.correspondance_di) AS thematiques, + permis_velo.id AS service_id + FROM + permis_velo, + UNNEST(permis_velo.liaisons_besoins_mes_aides) AS mes_aides_besoins + LEFT JOIN mapping_thematiques ON mes_aides_besoins = mapping_thematiques.besoins + WHERE permis_velo.slug_thematique_mes_aides = mapping_thematiques.thematiques + GROUP BY permis_velo.id +), + +transformed_types AS ( + SELECT + permis_velo.id, + ARRAY_AGG(types_mapping.types_di) AS transformed_types + FROM + permis_velo, + UNNEST(permis_velo.types) AS mes_aides_types + LEFT JOIN + types_mapping ON mes_aides_types = types_mapping.types_mes_aides + GROUP BY + permis_velo.id +), + +final AS ( + SELECT + permis_velo.id AS "adresse_id", + TRUE AS "contact_public", + TRUE AS "cumulable", + permis_velo.creee_le AS "date_creation", + permis_velo.modifiee_le AS "date_maj", + CAST(NULL AS DATE) AS "date_suspension", + permis_velo.formulaire_url AS "formulaire_en_ligne", + ARRAY_TO_STRING(permis_velo.nature, '; ') AS "frais_autres", + permis_velo.id AS "id", + CAST(NULL AS TEXT []) AS "justificatifs", + permis_velo.url_mes_aides AS "lien_source", + CASE + WHEN permis_velo.en_ligne = TRUE THEN ARRAY['a-distance'] + ELSE ARRAY['en-presentiel'] + END AS "modes_accueil", + ( + SELECT modes_orientation_mapping.modes_orientation_accompagnateur + FROM modes_orientation_mapping + WHERE permis_velo.methode = modes_orientation_mapping.demarche + ) AS "modes_orientation_accompagnateur", + NULL AS "modes_orientation_accompagnateur_autres", + ( + SELECT modes_orientation_mapping.modes_orientation_beneficiaire + FROM modes_orientation_mapping + WHERE permis_velo.methode = modes_orientation_mapping.demarche + ) AS "modes_orientation_beneficiaire", + permis_velo.demarche AS "modes_orientation_beneficiaire_autres", + permis_velo.nom AS "nom", + CASE + WHEN LENGTH(permis_velo.description) > 280 THEN SUBSTRING(permis_velo.description FROM 1 FOR 277) || '...' + ELSE permis_velo.description + END AS "presentation_resume", + permis_velo.description || COALESCE(E'\n\n' || permis_velo.bon_a_savoir, '') || COALESCE(E'\n\n' || permis_velo.modalite_versement, '') AS "presentation_detail", + NULL AS "prise_rdv", + CAST(NULL AS TEXT []) AS "profils", + NULL AS "recurrence", + permis_velo._di_source_id AS "source", + permis_velo.id AS "structure_id", + thematiques.thematiques AS "thematiques", + transformed_types.transformed_types AS "types", + CASE + WHEN zone_diffusion.zone_di = 'commune' THEN zone_code.code + WHEN zone_diffusion.zone_di = 'epci' THEN zone_code.code_epci + WHEN zone_diffusion.zone_di = 'region' THEN regions.code + WHEN zone_diffusion.zone_di = 'departement' THEN departements.code + WHEN zone_diffusion.zone_di = 'pays' THEN 'FR' + END AS "zone_diffusion_code", + CASE + WHEN zone_diffusion.zone_di = 'commune' THEN permis_velo.liaisons_ville_nom + WHEN zone_diffusion.zone_di = 'epci' THEN permis_velo.liaisons_ville_nom + WHEN zone_diffusion.zone_di = 'region' THEN permis_velo.liaisons_region + WHEN zone_diffusion.zone_di = 'departement' THEN departements.nom + WHEN zone_diffusion.zone_di = 'pays' THEN 'France entière' + END AS "zone_diffusion_nom", + zone_diffusion.zone_di AS "zone_diffusion_type", + CASE + WHEN permis_velo.autres_conditions IS NULL THEN CAST(NULL AS TEXT []) + ELSE ARRAY[permis_velo.autres_conditions] + END AS "pre_requis", + NULL AS "contact_nom_prenom", + permis_velo.contact_email AS "courriel", + permis_velo.contact_telephone AS "telephone", + ( + SELECT ARRAY_AGG(frais_mapping.frais_di) + FROM frais_mapping + WHERE permis_velo.nature && frais_mapping.frais_mes_aides + ) AS "frais", + permis_velo.site AS "page_web" + FROM permis_velo + LEFT JOIN transformed_types ON permis_velo.id = transformed_types.id + LEFT JOIN zone_diffusion ON permis_velo.id = zone_diffusion.id + LEFT JOIN zone_code ON permis_velo.id = zone_code.id + LEFT JOIN departements ON permis_velo.num_departement = departements.code + LEFT JOIN regions ON permis_velo.liaisons_region = regions.nom + LEFT JOIN thematiques ON permis_velo.id = thematiques.service_id +) + +SELECT * FROM final diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides__permis_velo__structures.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides__permis_velo__structures.sql new file mode 100644 index 00000000..6de6faf8 --- /dev/null +++ b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides__permis_velo__structures.sql @@ -0,0 +1,45 @@ +WITH permis_velo AS ( + SELECT * FROM {{ ref('stg_mes_aides__permis_velo') }} +), + +mapping_thematiques AS ( + SELECT * FROM {{ ref('_map_permis_velo_thematiques') }} +), + +thematiques AS ( + SELECT + ARRAY_AGG(mapping_thematiques.correspondance_di) AS thematiques, + permis_velo.id AS service_id + FROM permis_velo + INNER JOIN mapping_thematiques ON mapping_thematiques.besoins = ANY(permis_velo.liaisons_besoins_mes_aides) + WHERE permis_velo.slug_thematique_mes_aides = mapping_thematiques.thematiques + GROUP BY permis_velo.id +), + +final AS ( + SELECT + permis_velo.id AS "id", + permis_velo.id AS "adresse_id", + permis_velo.siret_structure AS "siret", + CAST(NULL AS BOOLEAN) AS "antenne", + NULL AS "rna", + permis_velo.nom_organisme_structure AS "nom", + permis_velo.contact_telephone AS "telephone", + permis_velo.contact_email AS "courriel", + permis_velo.site AS "site_web", + permis_velo._di_source_id AS "source", + permis_velo.url_mes_aides AS "lien_source", + NULL AS "horaires_ouverture", + NULL AS "accessibilite", + CAST(NULL AS TEXT []) AS "labels_nationaux", + CAST(NULL AS TEXT []) AS "labels_autres", + NULL AS "typologie", + NULL AS "presentation_resume", + NULL AS "presentation_detail", + CAST(permis_velo.modifiee_le AS DATE) AS "date_maj", + thematiques.thematiques AS "thematiques" + FROM permis_velo + LEFT JOIN thematiques ON permis_velo.id = thematiques.service_id +) + +SELECT * FROM final diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides_permis_velo__services.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides_permis_velo__services.sql deleted file mode 100644 index b0ca6a06..00000000 --- a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides_permis_velo__services.sql +++ /dev/null @@ -1,194 +0,0 @@ -{% set check_structure_str = "Veuillez vérifier sur le site internet de la structure" %} - -WITH permis_velo AS ( - SELECT * FROM {{ ref('stg_mes_aides__permis_velo') }} -), - -communes AS ( - SELECT * FROM {{ ref('stg_decoupage_administratif__communes') }} -), - -departements AS ( - SELECT * FROM {{ ref('stg_decoupage_administratif__departements') }} -), - -zone_code AS ( - SELECT - permis_velo.id, - communes.code, - communes.code_epci, - communes.code_departement, - communes.code_region - FROM permis_velo - LEFT JOIN communes ON permis_velo.liaisons_code_postal = ANY(communes.codes_postaux) AND permis_velo.liaisons_ville_nom = communes.nom -), - -types_mapping AS ( - SELECT x.* - FROM ( - VALUES - ('Aide financière', 'aide-financiere'), - ('Prestation', 'aide-materielle'), - ('Accompagnement', 'accompagnement') - ) AS x (types_mes_aides, types_di) -), - -zone_de_diffusion_mapping AS ( - SELECT x.* - FROM ( - VALUES - ('Échelle communale', 'commune'), - ('Échelle intercommunale', 'epci'), - ('Échelle régionale', 'region'), - ('Échelle départementale', 'departement'), - ('France métropolitaine', 'pays') - ) AS x (zone_mes_aides, zone_di) -), - -zone_diffusion AS ( - SELECT - zone_de_diffusion_mapping.zone_di, - permis_velo.id - FROM permis_velo - INNER JOIN zone_de_diffusion_mapping ON permis_velo.zone_geographique = zone_de_diffusion_mapping.zone_mes_aides -), - -modes_orientation_mapping AS ( - SELECT x.* - FROM ( - VALUES - ('La démarche nécessite un passage ou une prise de contact directe avec votre organisme', ARRAY['envoyer-un-email', 'telephoner'], ARRAY['envoyer-un-email', 'telephoner', 'se-presenter']), - ('La démarche nécessite une connexion sur le site de votre organisme', ARRAY['completer-le-formulaire-dadhesion'], ARRAY['completer-le-formulaire-dadhesion']), - ('La démarche peut être faite par mail', ARRAY['envoyer-un-email'], ARRAY['envoyer-un-email']) - ) AS x (demarche, modes_orientation_accompagnateur, modes_orientation_beneficiaire) -), - -mapping_thematiques AS ( - SELECT x.* - FROM ( - VALUES - ('Financer mon permis', 'transport-et-mobilite', ARRAY['mobilite--financer-mon-projet-mobilite', 'mobilite--preparer-son-permis-de-conduire-se-reentrainer-a-la-conduite']), - ('Financer mes trajets', 'transport-et-mobilite', ARRAY['mobilite--financer-mon-projet-mobilite']), - ('Financer le carburant', 'transport-et-mobilite', ARRAY['mobilite--financer-mon-projet-mobilite']), - ('Financer mon BSR', 'transport-et-mobilite', ARRAY['mobilite--financer-mon-projet-mobilite']), - ('Financer l''achat d''un véhicule', 'transport-et-mobilite', ARRAY['mobilite--acheter-un-vehicule-motorise']), - ('Déménager', 'logement', ARRAY['logement-hebergement--demenagement']), - ('Transports en commun', 'transport-et-mobilite', ARRAY['mobilite--comprendre-et-utiliser-les-transports-en-commun']), - ('Transport à la demande', 'transport-et-mobilite', ARRAY['mobilite--etre-accompagne-dans-son-parcours-mobilite']), - ('Réparer ma voiture', 'transport-et-mobilite', ARRAY['mobilite--entretenir-reparer-son-vehicule']), - ('Louer un vélo électrique', 'transport-et-mobilite', ARRAY['mobilite--louer-un-vehicule']), - ('Ma voiture', 'transport-et-mobilite', ARRAY['mobilite--louer-un-vehicule', 'mobilite--entretenir-reparer-son-vehicule', 'mobilite--acheter-un-vehicule-motorise']), - ('Mon vélo électrique', 'transport-et-mobilite', ARRAY['mobilite--acheter-un-velo', 'mobilite--entretenir-reparer-son-vehicule', 'mobilite--apprendre-a-utiliser-un-deux-roues', 'mobilite--louer-un-vehicule', 'mobilite--acheter-un-vehicule-motorise']), - ('Mon scooter', 'transport-et-mobilite', ARRAY['mobilite--entretenir-reparer-son-vehicule', 'mobilite--apprendre-a-utiliser-un-deux-roues', 'mobilite--louer-un-vehicule']), - ('Acheter un vélo électrique', 'transport-et-mobilite', ARRAY['mobilite--acheter-un-velo']), - ('Acheter ou louer une voiture', 'transport-et-mobilite', ARRAY['mobilite--louer-un-vehicule', 'mobilite--acheter-un-vehicule-motorise']), - ('Accéder au permis de conduire', 'transport-et-mobilite', ARRAY['mobilite--preparer-son-permis-de-conduire-se-reentrainer-a-la-conduite']), - ('Déménager', 'transport-et-mobilite', ARRAY['logement-hebergement--demenagement']), - ('Partir à l''étranger', 'transport-et-mobilite', ARRAY['souvrir-a-linternational--sinformer-sur-les-aides-pour-travailler-a-letranger']), - ('Handicap & mobilité', 'transport-et-mobilite', ARRAY['handicap--favoriser-le-retour-et-le-maintien-dans-lemploi']), - ('Trouver une alternance', 'trouver-un-job', ARRAY['trouver-un-emploi--suivre-ses-candidatures-et-relancer-les-employeurs', 'trouver-un-emploi--convaincre-un-recruteur-en-entretien', 'trouver-un-emploi--faire-des-candidatures-spontanees', 'trouver-un-emploi--repondre-a-des-offres-demploi']), - ('Trouver un contrat d''apprentissage', 'trouver-un-job', ARRAY['trouver-un-emploi--suivre-ses-candidatures-et-relancer-les-employeurs', 'trouver-un-emploi--convaincre-un-recruteur-en-entretien', 'trouver-un-emploi--faire-des-candidatures-spontanees', 'trouver-un-emploi--repondre-a-des-offres-demploi']), - ('Préparer une candidature', 'trouver-un-job', ARRAY['preparer-sa-candidature--valoriser-ses-competences']), - ('Rédiger une lettre de motivation ou un CV', 'trouver-un-job', ARRAY['preparer-sa-candidature--realiser-un-cv-et-ou-une-lettre-de-motivation']), - ('Devenir locataire', 'logement', ARRAY['logement-hebergement--etre-accompagne-pour-se-loger']), - ('Financer mon loyer', 'logement', ARRAY['logement-hebergement--gerer-son-budget']), - ('Faire des travaux', 'logement', ARRAY['logement-hebergement--besoin-dadapter-mon-logement']), - ('Trouver un logement social', 'logement', ARRAY['logement-hebergement--etre-accompagne-pour-se-loger']), - ('Financer une formation', 'formation-et-orientation', ARRAY['se-former--monter-son-dossier-de-formation']), - ('Trouver une formation', 'formation-et-orientation', ARRAY['se-former--trouver-sa-formation']), - ('Rémunération pendant la formation', 'formation-et-orientation', ARRAY['se-former--monter-son-dossier-de-formation']), - ('Reconversion', 'formation-et-orientation', ARRAY['se-former--trouver-sa-formation']), - ('Accompagnement personnalisé à la mobilité', 'transport-et-mobilite', ARRAY['mobilite--etre-accompagne-dans-son-parcours-mobilite']) - ) AS x (besoins, thematiques, correspondance_di) -), - -transformed_types AS ( - SELECT - permis_velo.id, - ARRAY_AGG(types_mapping.types_di) AS transformed_types - FROM - permis_velo, - UNNEST(permis_velo.types) AS mes_aides_types - LEFT JOIN - types_mapping ON mes_aides_types = types_mapping.types_mes_aides - GROUP BY - permis_velo.id -), - -final AS ( - SELECT - permis_velo.id AS "adresse_id", - TRUE AS "contact_public", - TRUE AS "cumulable", - permis_velo.creee_le AS "date_creation", - permis_velo.modifiee_le AS "date_maj", - CAST(NULL AS DATE) AS "date_suspension", - NULL AS "formulaire_en_ligne", - permis_velo.nature AS "frais_autres", - permis_velo.id AS "id", - CAST(NULL AS TEXT []) AS "justificatifs", - permis_velo.url_mes_aides AS "lien_source", - CASE - WHEN permis_velo.en_ligne = TRUE THEN ARRAY['a-distance'] - ELSE ARRAY['en-presentiel'] - END AS "modes_accueil", - ( - SELECT modes_orientation_mapping.modes_orientation_accompagnateur - FROM modes_orientation_mapping - WHERE permis_velo.methode = modes_orientation_mapping.demarche - ) AS "modes_orientation_accompagnateur", - NULL AS "modes_orientation_accompagnateur_autres", - ( - SELECT modes_orientation_mapping.modes_orientation_beneficiaire - FROM modes_orientation_mapping - WHERE permis_velo.methode = modes_orientation_mapping.demarche - ) AS "modes_orientation_beneficiaire", - permis_velo.demarche AS "modes_orientation_beneficiaire_autres", - permis_velo.nom AS "nom", - CASE - WHEN LENGTH(permis_velo.modalite_versement) > 297 THEN SUBSTRING(permis_velo.modalite_versement FROM 1 FOR 294) || '...' - ELSE permis_velo.modalite_versement - END AS "presentation_resume", - permis_velo.modalite_versement AS "presentation_detail", - NULL AS "prise_rdv", - CAST(NULL AS TEXT []) AS "profils", - NULL AS "recurrence", - permis_velo._di_source_id AS "source", - permis_velo.id AS "structure_id", - ( - SELECT mapping_thematiques.correspondance_di - FROM mapping_thematiques - WHERE - permis_velo.liaisons_besoins_mes_aides = mapping_thematiques.besoins - AND permis_velo.slug_thematique_mes_aides = mapping_thematiques.thematiques - ) AS "thematiques", - transformed_types.transformed_types AS "types", - CASE - WHEN zone_diffusion.zone_di = 'commune' THEN zone_code.code - WHEN zone_diffusion.zone_di = 'epci' THEN zone_code.code_epci - WHEN zone_diffusion.zone_di = 'region' THEN zone_code.code_region - WHEN zone_diffusion.zone_di = 'departement' THEN zone_code.code_departement - WHEN zone_diffusion.zone_di = 'pays' THEN NULL - END AS "zone_diffusion_code", - CASE - WHEN zone_diffusion.zone_di = 'commune' THEN permis_velo.liaisons_ville_nom - WHEN zone_diffusion.zone_di = 'epci' THEN permis_velo.liaisons_ville_nom - WHEN zone_diffusion.zone_di = 'region' THEN permis_velo.liaisons_region - WHEN zone_diffusion.zone_di = 'departement' THEN departements.nom - WHEN zone_diffusion.zone_di = 'pays' THEN NULL - END AS "zone_diffusion_nom", - zone_diffusion.zone_di AS "zone_diffusion_type", - CAST(NULL AS TEXT []) AS "pre_requis", - NULL AS "contact_nom_prenom", - permis_velo.contact_email AS "courriel", - permis_velo.contact_telephone AS "telephone", - CAST(NULL AS TEXT []) AS "frais", - permis_velo.site AS "page_web" - FROM permis_velo - LEFT JOIN transformed_types ON permis_velo.id = transformed_types.id - LEFT JOIN zone_diffusion ON permis_velo.id = zone_diffusion.id - LEFT JOIN zone_code ON permis_velo.id = zone_code.id - LEFT JOIN departements ON permis_velo.num_departement = departements.code -) - -SELECT * FROM final diff --git a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides_permis_velo__structures.sql b/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides_permis_velo__structures.sql deleted file mode 100644 index bde2084d..00000000 --- a/pipeline/dbt/models/intermediate/sources/mes_aides/permis_velo/int_mes_aides_permis_velo__structures.sql +++ /dev/null @@ -1,30 +0,0 @@ -WITH permis_velo AS ( - SELECT * FROM {{ ref('stg_mes_aides__permis_velo') }} -), - -final AS ( - SELECT - id AS "id", - id AS "adresse_id", - siret_structure AS "siret", - CAST(NULL AS BOOLEAN) AS "antenne", - NULL AS "rna", - nom AS "nom", - contact_telephone AS "telephone", - contact_email AS "courriel", - site AS "site_web", - _di_source_id AS "source", - url_mes_aides AS "lien_source", - NULL AS "horaires_ouverture", - NULL AS "accessibilite", - CAST(NULL AS TEXT []) AS "labels_nationaux", - CAST(NULL AS TEXT []) AS "labels_autres", - NULL AS "typologie", - NULL AS "presentation_resume", - NULL AS "presentation_detail", - CAST(modifiee_le AS DATE) AS "date_maj", - ARRAY['mobilite'] AS "thematiques" - FROM permis_velo -) - -SELECT * FROM final diff --git a/pipeline/dbt/models/staging/sources/mes_aides/stg_mes_aides__garages.sql b/pipeline/dbt/models/staging/sources/mes_aides/stg_mes_aides__garages.sql index 21ae2a4d..163e7998 100644 --- a/pipeline/dbt/models/staging/sources/mes_aides/stg_mes_aides__garages.sql +++ b/pipeline/dbt/models/staging/sources/mes_aides/stg_mes_aides__garages.sql @@ -24,7 +24,7 @@ final AS ( ELSE ARRAY[data #>> '{fields,Critères d''éligibilité}'] END AS "criteres_eligibilite", data #>> '{fields,Département Nom}' AS "departement_nom", - data #>> '{fields,Email}' AS "email", + TRIM(data #>> '{fields,Email}') AS "email", CAST(data #>> '{fields,En Ligne}' AS BOOLEAN) AS "en_ligne", data #>> '{fields,ID}' AS "id", -- some rows are formatted as `LAT, LAT`... use first value diff --git a/pipeline/dbt/models/staging/sources/mes_aides/stg_mes_aides__permis_velo.sql b/pipeline/dbt/models/staging/sources/mes_aides/stg_mes_aides__permis_velo.sql index 13d57867..11c7943f 100644 --- a/pipeline/dbt/models/staging/sources/mes_aides/stg_mes_aides__permis_velo.sql +++ b/pipeline/dbt/models/staging/sources/mes_aides/stg_mes_aides__permis_velo.sql @@ -11,10 +11,15 @@ final AS ( data #>> '{fields,N° Départements}' AS "num_departement", data #>> '{fields,Liaisons Régions}' AS "liaisons_region", data #>> '{fields,Nom}' AS "nom", - data #>> '{fields,Liaisons Besoins}' AS "liaisons_besoins_mes_aides", + data #>> '{fields,Description}' AS "description", + data #>> '{fields,Bon à savoir}' AS "bon_a_savoir", + STRING_TO_ARRAY(data #>> '{fields,Liaisons Besoins}', ', ') AS "liaisons_besoins_mes_aides", data #>> '{fields,Slug Thématiques}' AS "slug_thematique_mes_aides", data #>> '{fields,Zone géographique}' AS "zone_geographique", - data #>> '{fields,Nature}' AS "nature", + ( + SELECT ARRAY_AGG(element) + FROM JSONB_ARRAY_ELEMENTS_TEXT(data -> 'fields' -> 'Nature') as element + ) AS "nature", data #>> '{fields,Démarches}' AS "demarche", data #>> '{fields,"Modalité et versement"}' AS "modalite_versement", data #>> '{fields,"Méthode"}' AS "methode", @@ -30,7 +35,8 @@ final AS ( data #>> '{fields,Contact Tel}' AS "contact_telephone", data #>> '{fields,Autres Conditions}' AS "autres_conditions", data #>> '{fields,Url Mes Aides}' AS "url_mes_aides", - STRING_TO_ARRAY(data #>> '{fields,Type}', ',') AS "types" + data #>> '{fields,Formulaire Url}' AS "formulaire_url", + STRING_TO_ARRAY(data #>> '{fields,Type}', ', ') AS "types" FROM source )