diff --git a/api/CONTRIBUTING.md b/api/CONTRIBUTING.md index cc27ed611..90881cc58 100644 --- a/api/CONTRIBUTING.md +++ b/api/CONTRIBUTING.md @@ -61,7 +61,7 @@ After running the main dag: source .venv/bin/activate # Launch command to import the Admin Express database -python src/data_inclusion/api/cli.py import_admin_express +python src/data_inclusion/api/cli.py import_communes # Launch command to import data python src/data_inclusion/api/cli.py load_inclusion_data diff --git a/api/src/alembic/versions/20241017_105705_9bb9919e6b83_add_profils_autres_field_in_service.py b/api/src/alembic/versions/20241017_105705_9bb9919e6b83_add_profils_autres_field_in_service.py new file mode 100644 index 000000000..edab24a7c --- /dev/null +++ b/api/src/alembic/versions/20241017_105705_9bb9919e6b83_add_profils_autres_field_in_service.py @@ -0,0 +1,44 @@ +"""add profils_precisions field in service + +Revision ID: 9bb9919e6b83 +Revises: e3f3dfa4ad01 +Create Date: 2024-10-17 10:57:05.985264 + +""" + +import sqlalchemy as sa +from alembic import op + +# revision identifiers, used by Alembic. +revision = "9bb9919e6b83" +down_revision = "e3f3dfa4ad01" +branch_labels = None +depends_on = None + + +def upgrade() -> None: + op.add_column( + "api__services", + sa.Column( + "profils_precisions", + sa.String(), + nullable=True, + ), + ) + op.execute( + """ + ALTER TABLE public.api__services + ADD COLUMN searchable_index_profils_precisions tsvector + GENERATED ALWAYS AS ( + to_tsvector( + 'french'::regconfig, + COALESCE(profils_precisions, ''::character varying)::text + ) + ) STORED NULL; + """ + ) + + +def downgrade() -> None: + op.drop_column("api__services", "searchable_index_profils_precisions") + op.drop_column("api__services", "profils_precisions") diff --git a/api/src/data_inclusion/api/inclusion_data/models.py b/api/src/data_inclusion/api/inclusion_data/models.py index 894869c96..f032f845d 100644 --- a/api/src/data_inclusion/api/inclusion_data/models.py +++ b/api/src/data_inclusion/api/inclusion_data/models.py @@ -92,6 +92,8 @@ class Service(Base): presentation_resume: Mapped[str | None] prise_rdv: Mapped[str | None] profils: Mapped[list[str] | None] + profils_precisions: Mapped[str | None] + searchable_index_profils_precisions: Mapped[str | None] recurrence: Mapped[str | None] source: Mapped[str] structure_id: Mapped[str] diff --git a/api/src/data_inclusion/api/inclusion_data/routes.py b/api/src/data_inclusion/api/inclusion_data/routes.py index c97c27ad1..37c4f3690 100644 --- a/api/src/data_inclusion/api/inclusion_data/routes.py +++ b/api/src/data_inclusion/api/inclusion_data/routes.py @@ -214,6 +214,15 @@ def list_services_endpoint( """ ), ] = None, + profils_precisions: Annotated[ + Optional[str], + fastapi.Query( + description="""Une recherche elargie sur les profils. + Chaque résultat renvoyé correspond a la recherche fulltext sur + ce champs. + """ + ), + ] = None, modes_accueil: Annotated[ Optional[list[di_schema.ModeAccueil]], fastapi.Query( @@ -267,6 +276,7 @@ def list_services_endpoint( code_commune=code_commune, frais=frais, profils=profils, + profils_precisions=profils_precisions, modes_accueil=modes_accueil, types=types, include_outdated=inclure_suspendus, diff --git a/api/src/data_inclusion/api/inclusion_data/services.py b/api/src/data_inclusion/api/inclusion_data/services.py index 2c91b6602..19b85ee64 100644 --- a/api/src/data_inclusion/api/inclusion_data/services.py +++ b/api/src/data_inclusion/api/inclusion_data/services.py @@ -7,7 +7,7 @@ import geoalchemy2 import sqlalchemy as sqla -from sqlalchemy import orm +from sqlalchemy import func, orm import fastapi @@ -305,6 +305,7 @@ def list_services( code_commune: di_schema.CodeCommune | None = None, frais: list[di_schema.Frais] | None = None, profils: list[di_schema.Profil] | None = None, + profils_precisions: str | None = None, modes_accueil: list[di_schema.ModeAccueil] | None = None, types: list[di_schema.TypologieService] | None = None, include_outdated: bool | None = False, @@ -326,6 +327,13 @@ def list_services( if code_commune is not None: query = query.filter(models.Service.code_insee == code_commune) + if profils_precisions is not None: + query = query.filter( + models.Service.searchable_index_profils_precisions.bool_op("@@")( + func.websearch_to_tsquery("french", profils_precisions) + ) + ) + query = filter_services( query=query, sources=sources, diff --git a/deployment/MIGRATION.md b/deployment/MIGRATION.md index 0c8534823..00c588c38 100644 --- a/deployment/MIGRATION.md +++ b/deployment/MIGRATION.md @@ -5,7 +5,7 @@ Here is the corrected and formatted version of your migration process: 1. **Connect via SSH to the instance** ```bash - ssh root@163.172.186.56 + ssh root@163.172.171.247 ``` 2. **Install PostgreSQL 17** ```bash diff --git a/pipeline/dbt/macros/domain/checks/check_service.sql b/pipeline/dbt/macros/domain/checks/check_service.sql index db2e3553e..05b350040 100644 --- a/pipeline/dbt/macros/domain/checks/check_service.sql +++ b/pipeline/dbt/macros/domain/checks/check_service.sql @@ -24,6 +24,7 @@ CREATE OR REPLACE FUNCTION LIST_SERVICE_ERRORS( presentation_resume TEXT, prise_rdv TEXT, profils TEXT[], + profils_precisions TEXT, recurrence TEXT, source TEXT, structure_id TEXT, @@ -111,6 +112,7 @@ WITH final AS ( presentation_resume, prise_rdv, profils, + profils_precisions, recurrence, source, structure_id, diff --git a/pipeline/dbt/models/intermediate/int__union_services__enhanced.sql b/pipeline/dbt/models/intermediate/int__union_services__enhanced.sql index dbd6f0743..c8e642a6a 100644 --- a/pipeline/dbt/models/intermediate/int__union_services__enhanced.sql +++ b/pipeline/dbt/models/intermediate/int__union_services__enhanced.sql @@ -124,6 +124,7 @@ valid_services AS ( services.presentation_resume, services.prise_rdv, services.profils, + services.profils_precisions, services.recurrence, services.source, services.structure_id, diff --git a/pipeline/dbt/models/intermediate/sources/action_logement/int_action_logement__services.sql b/pipeline/dbt/models/intermediate/sources/action_logement/int_action_logement__services.sql index f3e42831f..3fc323593 100644 --- a/pipeline/dbt/models/intermediate/sources/action_logement/int_action_logement__services.sql +++ b/pipeline/dbt/models/intermediate/sources/action_logement/int_action_logement__services.sql @@ -32,6 +32,7 @@ final AS ( services.presentation_resume AS "presentation_resume", services.prise_rdv AS "prise_rdv", services.profils AS "profils", + ARRAY_TO_STRING(services.profils, '') AS "profils_precisions", services.pre_requis AS "pre_requis", services.recurrence AS "recurrence", services.thematiques AS "thematiques", @@ -41,7 +42,7 @@ final AS ( 'departement' AS "zone_diffusion_type", NULL AS "zone_diffusion_code", NULL AS "zone_diffusion_nom", - CAST(NULL AS DATE) AS "date_suspension", + NULL::DATE AS "date_suspension", structures.id || '-' || services.id AS "id" FROM services CROSS JOIN structures diff --git a/pipeline/dbt/models/intermediate/sources/agefiph/int_agefiph__services.sql b/pipeline/dbt/models/intermediate/sources/agefiph/int_agefiph__services.sql index 2c0f0b0e8..4e9ae7926 100644 --- a/pipeline/dbt/models/intermediate/sources/agefiph/int_agefiph__services.sql +++ b/pipeline/dbt/models/intermediate/sources/agefiph/int_agefiph__services.sql @@ -75,13 +75,13 @@ final AS ( NULL AS "page_web", 'https://www.agefiph.fr' || services.attributes__path__alias AS "modes_orientation_accompagnateur_autres", 'https://www.agefiph.fr' || services.attributes__path__alias AS "modes_orientation_beneficiaire_autres", - CAST(NULL AS TEXT []) AS "justificatifs", - CAST(NULL AS TEXT []) AS "pre_requis", - CAST(NULL AS BOOLEAN) AS "cumulable", - CAST(NULL AS DATE) AS "date_suspension", + NULL::TEXT [] AS "justificatifs", + NULL::TEXT [] AS "pre_requis", + NULL::BOOLEAN AS "cumulable", + NULL::DATE AS "date_suspension", 'https://www.agefiph.fr' || services.attributes__path__alias AS "lien_source", - CAST(services.attributes__created AS DATE) AS "date_creation", - CAST(services.attributes__changed AS DATE) AS "date_maj", + (services.attributes__created)::DATE AS "date_creation", + (services.attributes__changed)::DATE AS "date_maj", NULLIF( TRIM( ARRAY_TO_STRING( @@ -107,12 +107,13 @@ final AS ( ARRAY[ 'personnes-en-situation-de-handicap' ] AS "profils", + 'personnes en situation de handicap' AS "profils_precisions", ARRAY( SELECT di_type_by_agefiph_type.type_ FROM di_type_by_agefiph_type WHERE services.relationships__field_type_aide_service__data__id = di_type_by_agefiph_type.agefiph_type ) AS "types", - CAST(NULL AS TEXT []) AS "frais" + NULL::TEXT [] AS "frais" FROM structures CROSS JOIN services diff --git a/pipeline/dbt/models/intermediate/sources/data_inclusion/int_data_inclusion__services.sql b/pipeline/dbt/models/intermediate/sources/data_inclusion/int_data_inclusion__services.sql index 520506751..0fb1e09f1 100644 --- a/pipeline/dbt/models/intermediate/sources/data_inclusion/int_data_inclusion__services.sql +++ b/pipeline/dbt/models/intermediate/sources/data_inclusion/int_data_inclusion__services.sql @@ -16,45 +16,46 @@ di_profil_by_dora_profil AS ( final AS ( SELECT - id AS "adresse_id", - contact_public AS "contact_public", - contact_nom AS "contact_nom_prenom", - courriel AS "courriel", - cumulable AS "cumulable", - date_creation::DATE AS "date_creation", - date_maj::DATE AS "date_maj", - date_suspension::DATE AS "date_suspension", - formulaire_en_ligne AS "formulaire_en_ligne", - frais_autres AS "frais_autres", - id AS "id", - justificatifs AS "justificatifs", - NULL AS "lien_source", -- ignored - modes_accueil AS "modes_accueil", - modes_orientation_accompagnateur AS "modes_orientation_accompagnateur", - modes_orientation_accompagnateur_autres AS "modes_orientation_accompagnateur_autres", - modes_orientation_beneficiaire AS "modes_orientation_beneficiaire", - modes_orientation_beneficiaire_autres AS "modes_orientation_beneficiaire_autres", - nom AS "nom", - presentation_resume AS "presentation_resume", - presentation_detail AS "presentation_detail", - prise_rdv AS "prise_rdv", + services.id AS "adresse_id", + services.contact_public AS "contact_public", + services.contact_nom AS "contact_nom_prenom", + services.courriel AS "courriel", + services.cumulable AS "cumulable", + services.date_creation::DATE AS "date_creation", + services.date_maj::DATE AS "date_maj", + services.date_suspension::DATE AS "date_suspension", + services.formulaire_en_ligne AS "formulaire_en_ligne", + services.frais_autres AS "frais_autres", + services.id AS "id", + services.justificatifs AS "justificatifs", + NULL AS "lien_source", -- ignored + services.modes_accueil AS "modes_accueil", + services.modes_orientation_accompagnateur AS "modes_orientation_accompagnateur", + services.modes_orientation_accompagnateur_autres AS "modes_orientation_accompagnateur_autres", + services.modes_orientation_beneficiaire AS "modes_orientation_beneficiaire", + services.modes_orientation_beneficiaire_autres AS "modes_orientation_beneficiaire_autres", + services.nom AS "nom", + services.presentation_resume AS "presentation_resume", + services.presentation_detail AS "presentation_detail", + services.prise_rdv AS "prise_rdv", ARRAY( SELECT di_profil_by_dora_profil.di_profil FROM di_profil_by_dora_profil WHERE di_profil_by_dora_profil.dora_profil = ANY(services.profils) - )::TEXT [] AS "profils", - recurrence AS "recurrence", - _di_source_id AS "source", - structure_id AS "structure_id", - telephone AS "telephone", - thematiques AS "thematiques", - types AS "types", - zone_diffusion_code AS "zone_diffusion_code", - zone_diffusion_nom AS "zone_diffusion_nom", - zone_diffusion_type AS "zone_diffusion_type", - pre_requis AS "pre_requis", - frais AS "frais", - NULL AS "page_web" + )::TEXT [] AS "profils", + ARRAY_TO_STRING(services.profils, ', ') AS "profils_precisions", + services.recurrence AS "recurrence", + services._di_source_id AS "source", + services.structure_id AS "structure_id", + services.telephone AS "telephone", + services.thematiques AS "thematiques", + services.types AS "types", + services.zone_diffusion_code AS "zone_diffusion_code", + services.zone_diffusion_nom AS "zone_diffusion_nom", + services.zone_diffusion_type AS "zone_diffusion_type", + services.pre_requis AS "pre_requis", + services.frais AS "frais", + NULL AS "page_web" FROM services ) diff --git a/pipeline/dbt/models/intermediate/sources/dora/int_dora__services.sql b/pipeline/dbt/models/intermediate/sources/dora/int_dora__services.sql index eab730ab7..99be14d57 100644 --- a/pipeline/dbt/models/intermediate/sources/dora/int_dora__services.sql +++ b/pipeline/dbt/models/intermediate/sources/dora/int_dora__services.sql @@ -46,6 +46,7 @@ final AS ( FROM di_profil_by_dora_profil WHERE di_profil_by_dora_profil.dora_profil = ANY(services.profils) )::TEXT [] AS "profils", + ARRAY_TO_STRING(services.profils, ', ') AS "profils_precisions", services.recurrence AS "recurrence", services._di_source_id AS "source", services.structure_id AS "structure_id", diff --git a/pipeline/dbt/models/intermediate/sources/france_travail/int_france_travail__services.sql b/pipeline/dbt/models/intermediate/sources/france_travail/int_france_travail__services.sql index dc9ea2e7a..794efa3dd 100644 --- a/pipeline/dbt/models/intermediate/sources/france_travail/int_france_travail__services.sql +++ b/pipeline/dbt/models/intermediate/sources/france_travail/int_france_travail__services.sql @@ -44,6 +44,7 @@ final AS ( services.presentation_resume AS "presentation_resume", services.prise_rdv AS "prise_rdv", services.profils AS "profils", + ARRAY_TO_STRING(services.profils, ', ') AS "profils_precisions", services.pre_requis AS "pre_requis", services.recurrence AS "recurrence", services.thematiques AS "thematiques", @@ -54,7 +55,7 @@ final AS ( structures.code_insee AS "zone_diffusion_code", structures.commune AS "zone_diffusion_nom", NULL AS "page_web", - CAST(NULL AS DATE) AS "date_suspension", + NULL::DATE AS "date_suspension", structures.id || '-' || services.id AS "id" FROM services CROSS JOIN structures_with_commune AS structures diff --git a/pipeline/dbt/models/intermediate/sources/fredo/int_fredo__services.sql b/pipeline/dbt/models/intermediate/sources/fredo/int_fredo__services.sql index 1d955b6cd..eda9f289e 100644 --- a/pipeline/dbt/models/intermediate/sources/fredo/int_fredo__services.sql +++ b/pipeline/dbt/models/intermediate/sources/fredo/int_fredo__services.sql @@ -94,7 +94,10 @@ frais_autres AS ( fredo_frais.structure_id, STRING_AGG(fredo_frais.value, ', ') AS frais_autres FROM fredo_frais - WHERE fredo_frais.value NOT IN (SELECT frais_fredo FROM di_frais_by_fredo_frais) + WHERE + fredo_frais.value NOT IN ( + SELECT di_frais_by_fredo_frais.frais_fredo FROM di_frais_by_fredo_frais + ) GROUP BY fredo_frais.structure_id ), @@ -119,7 +122,8 @@ thematiques AS ( profils AS ( SELECT fredo_publics.structure_id, - ARRAY_AGG(di_profils_by_fredo_public.profil) AS profils + ARRAY_AGG(di_profils_by_fredo_public.profil) AS profils, + STRING_AGG(fredo_publics.value, ', ') AS profils_precisions FROM fredo_publics INNER JOIN di_profils_by_fredo_public ON fredo_publics.value = di_profils_by_fredo_public.public GROUP BY fredo_publics.structure_id @@ -134,6 +138,7 @@ final AS ( NULL AS "prise_rdv", fredo_structures.site_web AS "page_web", profils.profils AS "profils", + profils.profils_precisions AS "profils_precisions", NULL AS "modes_orientation_accompagnateur_autres", NULL AS "modes_orientation_beneficiaire_autres", NULL AS "formulaire_en_ligne", @@ -144,13 +149,13 @@ final AS ( 'La Réunion' AS "zone_diffusion_nom", NULL AS "recurrence", fredo_structures.last_update AS "date_maj", - CAST(UUID(MD5(fredo_structures.id || COALESCE(fredo_services.value, ''))) AS TEXT) AS "id", - CAST(NULL AS TEXT []) AS "pre_requis", - CAST(NULL AS BOOLEAN) AS "cumulable", - CAST(NULL AS TEXT []) AS "justificatifs", - CAST(NULL AS DATE) AS "date_creation", - CAST(NULL AS DATE) AS "date_suspension", - CAST(NULL AS BOOLEAN) AS "contact_public", + (UUID(MD5(fredo_structures.id || COALESCE(fredo_services.value, ''))))::TEXT AS "id", + NULL::TEXT [] AS "pre_requis", + NULL::BOOLEAN AS "cumulable", + NULL::TEXT [] AS "justificatifs", + NULL::DATE AS "date_creation", + NULL::DATE AS "date_suspension", + NULL::BOOLEAN AS "contact_public", CASE WHEN fredo_structures.adresse IS NOT NULL diff --git a/pipeline/dbt/models/intermediate/sources/mediation_numerique/int_mediation_numerique__services.sql b/pipeline/dbt/models/intermediate/sources/mediation_numerique/int_mediation_numerique__services.sql index d5fc65be6..cc2e4d878 100644 --- a/pipeline/dbt/models/intermediate/sources/mediation_numerique/int_mediation_numerique__services.sql +++ b/pipeline/dbt/models/intermediate/sources/mediation_numerique/int_mediation_numerique__services.sql @@ -28,6 +28,7 @@ final AS ( services.prise_rdv AS "prise_rdv", services.frais AS "frais", services.profils AS "profils", + ARRAY_TO_STRING(services.profils, ', ') AS "profils_precisions", services.structure_id AS "structure_id", services.thematiques AS "thematiques", services._di_source_id AS "source", @@ -42,12 +43,12 @@ final AS ( NULL AS "modes_orientation_beneficiaire_autres", NULL AS "lien_source", 'departement' AS "zone_diffusion_type", - CAST(NULL AS TEXT []) AS "pre_requis", - CAST(NULL AS BOOLEAN) AS "cumulable", - CAST(NULL AS TEXT []) AS "justificatifs", - CAST(NULL AS DATE) AS "date_suspension", - CAST(structures.date_maj AS DATE) AS "date_maj", - CAST(NULL AS DATE) AS "date_creation", + NULL::TEXT [] AS "pre_requis", + NULL::BOOLEAN AS "cumulable", + NULL::TEXT [] AS "justificatifs", + NULL::DATE AS "date_suspension", + (structures.date_maj)::DATE AS "date_maj", + NULL::DATE AS "date_creation", CASE WHEN structures.code_insee LIKE '97%' THEN LEFT(structures.code_insee, 3) ELSE LEFT(structures.code_insee, 2) @@ -60,7 +61,7 @@ final AS ( NULL ) AS "modes_orientation_accompagnateur", ARRAY_REMOVE(ARRAY[CASE WHEN structures.telephone IS NOT NULL THEN 'telephoner' END], NULL) AS "modes_orientation_beneficiaire", - CAST(NULL AS TEXT) AS "frais_autres", + NULL::TEXT AS "frais_autres", CASE WHEN CARDINALITY(services.types) > 0 THEN services.types ELSE ARRAY['accompagnement'] END AS "types", ARRAY['en-presentiel'] AS "modes_accueil", {{ truncate_text(presentation) }} AS "presentation_resume", 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 index 4a553c138..a839bfcd4 100644 --- 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 @@ -61,6 +61,7 @@ final AS ( NULL AS "presentation_detail", NULL AS "prise_rdv", NULL::TEXT [] AS "profils", + garages.criteres_eligibilite_raw AS "profils_precisions", NULL AS "recurrence", garages._di_source_id AS "source", garages.id AS "structure_id", 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 index 7af2c58da..686327805 100644 --- 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 @@ -185,6 +185,7 @@ final AS ( || COALESCE(E'\n\n' || permis_velo.modalite_versement, '') AS "presentation_detail", NULL AS "prise_rdv", NULL::TEXT [] AS "profils", + permis_velo.autres_conditions AS "profils_precisions", NULL AS "recurrence", permis_velo._di_source_id AS "source", permis_velo.id AS "structure_id", diff --git a/pipeline/dbt/models/intermediate/sources/monenfant/int_monenfant__services.sql b/pipeline/dbt/models/intermediate/sources/monenfant/int_monenfant__services.sql index ed777f7b8..c937e2e5a 100644 --- a/pipeline/dbt/models/intermediate/sources/monenfant/int_monenfant__services.sql +++ b/pipeline/dbt/models/intermediate/sources/monenfant/int_monenfant__services.sql @@ -23,7 +23,8 @@ final AS ( id AS "adresse_id", NULL AS "prise_rdv", NULL AS "frais_autres", - NULL::TEXT [] AS "profils", + ARRAY['familles-enfants'] AS "profils", + 'famille enfant' AS "profils_precisions", id AS "structure_id", _di_source_id AS "source", TRUE AS "cumulable", diff --git a/pipeline/dbt/models/intermediate/sources/odspep/int_odspep__services.sql b/pipeline/dbt/models/intermediate/sources/odspep/int_odspep__services.sql index 0483b25ee..2a34db850 100644 --- a/pipeline/dbt/models/intermediate/sources/odspep/int_odspep__services.sql +++ b/pipeline/dbt/models/intermediate/sources/odspep/int_odspep__services.sql @@ -15,6 +15,26 @@ di_thematique_by_odspep_type_res_part AS ( ) AS x (type_res_part, thematique) ), +-- mapping_profils AS ( +-- SELECT x.* +-- FROM ( +-- VALUES +-- ('1', 'Bénéficiaires minima sociaux (hors RSA)', 'beneficiaires-rsa'), +-- ('2', 'Bénéficiaires RSA', 'beneficiaires-rsa'), +-- ('3', 'Cadre', 'salaries'), +-- ('4', 'Contrat de Sécurisation Professionel (CSP)', 'demandeurs-demploi'), +-- ('5', 'Eligible IAE', NULL), +-- ('6', 'Personne Sous Main de Justice', 'sortants-de-detention'), +-- ('7', 'Reconnaissance de la Qualité de Travailleur Handicapé (RQTH)', 'personnes-en-situation-de-handicap'), +-- ('8', 'Bénéficiaire de l''Obligation d''Emploi (BOE hors RQTH)', 'beneficiaires-rsa'), +-- ('9', 'Bénéficiaire de l''Allocation Adulte Handicapé (AAH)', 'personnes-en-situation-de-handicap'), +-- ('10', 'Créateur / Repreneur d''entreprise', 'salaries'), +-- ('11', 'Primo-arrivants', 'personnes-de-nationalite-etrangere'), +-- ('12', 'Mobilité internationale', NULL), +-- ('13', 'Retour congé parental', 'familles-enfants') +-- ) AS x (id_cri, profil_odspep, profil_di) +-- ) + final AS ( SELECT id_res AS "adresse_id", @@ -47,6 +67,7 @@ final AS ( zone_diffusion_libelle AS "zone_diffusion_nom", id_res AS "structure_id", NULL::TEXT [] AS "profils", + NULL AS "profils_precisions", ARRAY( SELECT di_thematique_by_odspep_type_res_part.thematique FROM di_thematique_by_odspep_type_res_part diff --git a/pipeline/dbt/models/intermediate/sources/reseau_alpha/int_reseau_alpha__services.sql b/pipeline/dbt/models/intermediate/sources/reseau_alpha/int_reseau_alpha__services.sql index 68e0712b9..17a2c4c27 100644 --- a/pipeline/dbt/models/intermediate/sources/reseau_alpha/int_reseau_alpha__services.sql +++ b/pipeline/dbt/models/intermediate/sources/reseau_alpha/int_reseau_alpha__services.sql @@ -58,10 +58,10 @@ final AS ( E'\n\n' ) AS "presentation_detail", 'service--' || formations.id AS "adresse_id", - CAST(NULL AS TEXT []) AS "justificatifs", - CAST(NULL AS TEXT []) AS "pre_requis", - CAST(NULL AS DATE) AS "date_suspension", - CAST(NULL AS DATE) AS "date_creation", + NULL::TEXT [] AS "justificatifs", + NULL::TEXT [] AS "pre_requis", + NULL::DATE AS "date_suspension", + NULL::DATE AS "date_creation", ARRAY_REMOVE( ARRAY[ 'apprendre-francais--suivre-formation', @@ -86,8 +86,9 @@ final AS ( NULL ) AS "modes_orientation_beneficiaire", ARRAY['public-langues-etrangeres'] AS "profils", + 'public langues etrangeres' AS "profils_precisions", ARRAY['formation'] AS "types", - CAST(NULL AS TEXT []) AS "frais" + NULL::TEXT [] AS "frais" FROM formations LEFT JOIN structures ON formations.structure_id = structures.id ) diff --git a/pipeline/dbt/models/intermediate/sources/soliguide/int_soliguide__services.sql b/pipeline/dbt/models/intermediate/sources/soliguide/int_soliguide__services.sql index 4753369a6..f9299527f 100644 --- a/pipeline/dbt/models/intermediate/sources/soliguide/int_soliguide__services.sql +++ b/pipeline/dbt/models/intermediate/sources/soliguide/int_soliguide__services.sql @@ -14,6 +14,18 @@ phones AS ( SELECT * FROM {{ ref('stg_soliguide__phones') }} ), +administrative AS ( + SELECT * FROM {{ ref('stg_soliguide__administrative') }} +), + +gender AS ( + SELECT * FROM {{ ref('stg_soliguide__gender') }} +), + +familliale AS ( + SELECT * FROM {{ ref('stg_soliguide__familliale') }} +), + thematiques AS ( SELECT * FROM {{ ref('thematiques') }} ), @@ -28,13 +40,13 @@ di_thematique_by_soliguide_category_code AS ( ('addiction', ARRAY['sante--faire-face-a-une-situation-daddiction']), ('administrative_assistance', ARRAY['acces-aux-droits-et-citoyennete--connaitre-ses-droits', 'acces-aux-droits-et-citoyennete--accompagnement-dans-les-demarches-administratives']), ('babysitting', ARRAY['famille--garde-denfants']), - ('budget_advice', ARRAY(SELECT value FROM thematiques WHERE value ~ '^gestion-financiere--')), + ('budget_advice', ARRAY(SELECT thematiques.value FROM thematiques WHERE thematiques.value ~ '^gestion-financiere--')), ('carpooling', ARRAY['mobilite--comprendre-et-utiliser-les-transports-en-commun']), ('chauffeur_driven_transport', ARRAY['mobilite--comprendre-et-utiliser-les-transports-en-commun']), ('clothing', ARRAY['equipement-et-alimentation--habillement']), ('computers_at_your_disposal', ARRAY['numerique--acceder-a-du-materiel']), ('day_hosting', ARRAY['remobilisation--lien-social']), - ('digital_tools_training', ARRAY(SELECT value FROM thematiques WHERE value ~ '^numerique--')), + ('digital_tools_training', ARRAY(SELECT thematiques.value FROM thematiques WHERE thematiques.value ~ '^numerique--')), ('emergency_accommodation', ARRAY['logement-hebergement--mal-loges-sans-logis']), ('family_area', ARRAY['famille--soutien-a-la-parentalite']), ('food_distribution', ARRAY['equipement-et-alimentation--alimentation']), @@ -62,6 +74,72 @@ di_thematique_by_soliguide_category_code AS ( ) AS x (category, thematique) ), +mapping_administrative AS ( + SELECT x.* + FROM ( + VALUES + ('regular', 'en situation reguliere', NULL), + ('asylum', 'demandeur asile', 'personnes-de-nationalite-etrangere'), + ('undocumented', 'sans papier', 'personnes-de-nationalite-etrangere') + ) AS x (category, traduction, profils) +), + +mapping_gender AS ( + SELECT x.* + FROM ( + VALUES + ('men', 'homme', 'adultes'), + ('women', 'femme', 'femmes') + ) AS x (category, traduction, profils) +), + +mapping_familliale AS ( + SELECT x.* + FROM ( + VALUES + ('isolated', 'isole', NULL), + ('family', 'famille', 'familles-enfants'), + ('couple', 'couple', 'familles-enfants'), + ('pregnent', 'enceinte', 'familles-enfants') + ) AS x (category, traduction, profils) +), + +profils_administrative AS ( + SELECT + administrative.lieu_id, + ARRAY_TO_STRING(ARRAY_AGG(mapping_administrative.traduction), ',') AS traduction, + ARRAY_AGG(mapping_administrative.profils) AS profils + FROM + administrative + LEFT JOIN mapping_administrative ON administrative.value = mapping_administrative.category + GROUP BY + administrative.lieu_id +), + +profils_familliale AS ( + SELECT + familliale.lieu_id, + ARRAY_TO_STRING(ARRAY_AGG(mapping_familliale.traduction), ',') AS traduction, + ARRAY_AGG(mapping_familliale.profils) AS profils + FROM + familliale + LEFT JOIN mapping_familliale ON familliale.value = mapping_familliale.category + GROUP BY + familliale.lieu_id +), + +profils_gender AS ( + SELECT + gender.lieu_id, + ARRAY_TO_STRING(ARRAY_AGG(mapping_gender.traduction), ',') AS traduction, + ARRAY_AGG(mapping_gender.profils) AS profils + FROM + gender + LEFT JOIN mapping_gender ON gender.value = mapping_gender.category + GROUP BY + gender.lieu_id +), + filtered_phones AS ( -- FIXME: di schema only allows a single phone number, but soliguide can have more SELECT DISTINCT ON (lieu_id) * @@ -72,7 +150,9 @@ filtered_phones AS ( relevant_services AS ( SELECT * FROM services - WHERE category IN (SELECT category FROM di_thematique_by_soliguide_category_code) + WHERE category IN ( + SELECT c.category FROM di_thematique_by_soliguide_category_code AS c + ) ), -- remove temporarily suspended services from downstream data @@ -111,7 +191,15 @@ final AS ( open_services._di_source_id AS "source", NULL::TEXT [] AS "types", NULL AS "prise_rdv", - NULL::TEXT [] AS "profils", + ARRAY_REMOVE( + profils_administrative.profils + || profils_familliale.profils + || profils_gender.profils, + NULL + ) AS "profils", + profils_administrative.traduction || ' ' + || profils_familliale.traduction || ' ' + || profils_gender.traduction AS "profils_precisions", NULL::TEXT [] AS "pre_requis", TRUE AS "cumulable", NULL::TEXT [] AS "justificatifs", @@ -204,7 +292,10 @@ final AS ( LEFT JOIN lieux ON open_services.lieu_id = lieux.id LEFT JOIN categories ON open_services.category = categories.code LEFT JOIN filtered_phones ON open_services.lieu_id = filtered_phones.lieu_id - ORDER BY 1 + LEFT JOIN profils_administrative ON open_services.lieu_id = profils_administrative.lieu_id + LEFT JOIN profils_familliale ON open_services.lieu_id = profils_familliale.lieu_id + LEFT JOIN profils_gender ON open_services.lieu_id = profils_gender.lieu_id + ORDER BY open_services.id ) SELECT * FROM final diff --git a/pipeline/dbt/models/marts/inclusion/_inclusion_models.yml b/pipeline/dbt/models/marts/inclusion/_inclusion_models.yml index dd3ed895e..241472d17 100644 --- a/pipeline/dbt/models/marts/inclusion/_inclusion_models.yml +++ b/pipeline/dbt/models/marts/inclusion/_inclusion_models.yml @@ -167,6 +167,8 @@ models: data_type: text - name: profils data_type: text[] + - name: profils_precisions + data_type: text - name: pre_requis data_type: text[] - name: cumulable 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 714ccb41d..195a69ed3 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 @@ -23,6 +23,7 @@ final AS ( -- else use the whole field ELSE ARRAY[data #>> '{fields,Critères d''éligibilité}'] END AS "criteres_eligibilite", + data #>> '{fields,Critères d''éligibilité}' AS "criteres_eligibilite_raw", data #>> '{fields,Département Nom}' AS "departement_nom", TRIM(data #>> '{fields,Email}') AS "email", (data #>> '{fields,En Ligne}')::BOOLEAN AS "en_ligne", diff --git a/pipeline/dbt/models/staging/sources/soliguide/_soliguide__models.yml b/pipeline/dbt/models/staging/sources/soliguide/_soliguide__models.yml index 35876bd95..96e962938 100644 --- a/pipeline/dbt/models/staging/sources/soliguide/_soliguide__models.yml +++ b/pipeline/dbt/models/staging/sources/soliguide/_soliguide__models.yml @@ -87,3 +87,47 @@ models: - relationships: to: ref('stg_soliguide__lieux') field: lieu_id + + + - name: stg_soliguide__familliale + columns: + - name: lieu_id + data_tests: + - not_null + - relationships: + to: ref('stg_fredo__lieux') + field: id + - name: value + data_tests: + - not_null + - dbt_utils.not_empty_string + - accepted_values: + values: ['isolated', 'family', 'pregnant', 'couple'] + - name: stg_soliguide__gender + columns: + - name: lieu_id + data_tests: + - not_null + - relationships: + to: ref('stg_fredo__lieux') + field: id + - name: value + data_tests: + - not_null + - dbt_utils.not_empty_string + - accepted_values: + values: ['men', 'women'] + - name: stg_soliguide__administrative + columns: + - name: lieu_id + data_tests: + - not_null + - relationships: + to: ref('stg_fredo__lieux') + field: id + - name: value + data_tests: + - not_null + - dbt_utils.not_empty_string + - accepted_values: + values: ['regular', 'asylum', 'refugee', 'undocumented'] \ No newline at end of file diff --git a/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__administrative.sql b/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__administrative.sql new file mode 100644 index 000000000..a001ac32c --- /dev/null +++ b/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__administrative.sql @@ -0,0 +1,13 @@ +WITH source AS ( + {{ stg_source_header('soliguide', 'lieux') }} +), + +final AS ( + SELECT + data ->> 'lieu_id' AS "lieu_id", + TRIM(JSONB_ARRAY_ELEMENTS_TEXT(data -> 'publics' -> 'administrative')) AS "value" + FROM source + WHERE data -> 'publics' -> 'administrative' IS NOT NULL +) + +SELECT * FROM final diff --git a/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__familliale.sql b/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__familliale.sql new file mode 100644 index 000000000..68363a6b3 --- /dev/null +++ b/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__familliale.sql @@ -0,0 +1,13 @@ +WITH source AS ( + {{ stg_source_header('soliguide', 'lieux') }} +), + +final AS ( + SELECT + data ->> 'lieu_id' AS "lieu_id", + TRIM(JSONB_ARRAY_ELEMENTS_TEXT(data -> 'publics' -> 'familliale')) AS "value" + FROM source + WHERE data -> 'publics' -> 'familliale' IS NOT NULL +) + +SELECT * FROM final diff --git a/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__gender.sql b/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__gender.sql new file mode 100644 index 000000000..4d11f0575 --- /dev/null +++ b/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__gender.sql @@ -0,0 +1,13 @@ +WITH source AS ( + {{ stg_source_header('soliguide', 'lieux') }} +), + +final AS ( + SELECT + data ->> 'lieu_id' AS "lieu_id", + TRIM(JSONB_ARRAY_ELEMENTS_TEXT(data -> 'publics' -> 'gender')) AS "value" + FROM source + WHERE data -> 'publics' -> 'gender' IS NOT NULL +) + +SELECT * FROM final diff --git a/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__lieux.sql b/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__lieux.sql index 26ea808f1..889893bd7 100644 --- a/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__lieux.sql +++ b/pipeline/dbt/models/staging/sources/soliguide/stg_soliguide__lieux.sql @@ -25,6 +25,14 @@ lieux AS ( data #>> '{position,address}' AS "position__address", NULLIF(TRIM(data #>> '{position,additionalInformation}'), '') AS "position__additional_information", data #>> '{position,department}' AS "position__department", + data #>> '{publics,age}' AS "publics__age", + ARRAY_TO_STRING( + ARRAY( + SELECT e.* FROM + JSONB_ARRAY_ELEMENTS_TEXT(source.data -> 'publics' -> 'other') AS e + ), + ',' + ) AS "publics__other", NULLIF(data #>> '{entity,mail}', '') AS "entity_mail", NULLIF(data #>> '{entity,website}', '') AS "entity_website", data -> 'newhours' AS "newhours",