1
+ WITH deduplicated_opened_sources AS (
2
+ SELECT
3
+ da .uuid ,
4
+ string_agg(DISTINCT source .libelle , ' |' ORDER BY source .libelle ) as sources_list
5
+ FROM {{ ref(' opendata_acteur' ) }} AS da
6
+ LEFT JOIN {{ ref(' opendata_acteur_sources' ) }} AS das
7
+ ON da .identifiant_unique = das .acteur_id
8
+ LEFT JOIN qfdmo_source AS source
9
+ ON das .source_id = source .id
10
+ GROUP BY da .uuid
11
+ ),
12
+ proposition_services AS (
13
+ SELECT
14
+ da .uuid ,
15
+ jsonb_agg(
16
+ jsonb_build_object(
17
+ ' action' , a .code ,
18
+ ' sous_categories' , (
19
+ SELECT jsonb_agg(sco .code )
20
+ FROM {{ ref(' opendata_propositionservice_sous_categories' ) }} AS pssc
21
+ JOIN qfdmo_souscategorieobjet AS sco ON pssc .souscategorieobjet_id = sco .id
22
+ WHERE pssc .propositionservice_id = ps .id
23
+ )
24
+ )
25
+ ) as services
26
+ FROM {{ ref(' opendata_acteur' ) }} AS da
27
+ JOIN {{ ref(' opendata_propositionservice' ) }} AS ps ON ps .acteur_id = da .identifiant_unique
28
+ JOIN qfdmo_action AS a ON ps .action_id = a .id
29
+ GROUP BY da .uuid
30
+ ),
31
+ acteur_labels AS (
32
+ SELECT
33
+ da .uuid ,
34
+ string_agg(DISTINCT lq .code , ' |' ORDER BY lq .code ) as labels
35
+ FROM {{ ref(' opendata_acteur' ) }} AS da
36
+ LEFT JOIN {{ ref(' opendata_acteur_labels' ) }} AS dal
37
+ ON da .identifiant_unique = dal .acteur_id
38
+ LEFT JOIN qfdmo_labelqualite AS lq ON dal .labelqualite_id = lq .id
39
+ GROUP BY da .uuid
40
+ ),
41
+ acteur_services AS (
42
+ SELECT
43
+ da .uuid ,
44
+ string_agg(DISTINCT as2 .code , ' |' ORDER BY as2 .code ) as services
45
+ FROM {{ ref(' opendata_acteur' ) }} AS da
46
+ LEFT JOIN {{ ref(' opendata_acteur_acteur_services' ) }} AS daas
47
+ ON da .identifiant_unique = daas .acteur_id
48
+ LEFT JOIN qfdmo_acteurservice AS as2 ON daas .acteurservice_id = as2 .id
49
+ GROUP BY da .uuid
50
+ )
51
+ SELECT
52
+ da .uuid as " Identifiant" ,
53
+ CASE
54
+ WHEN ds .sources_list IS NOT NULL
55
+ THEN ' Longue Vie Aux Objets|ADEME|' || ds .sources_list
56
+ ELSE ' Longue Vie Aux Objets|ADEME'
57
+ END as " Paternité" ,
58
+ da .nom as " Nom" ,
59
+ da .nom_commercial as " Nom commercial" ,
60
+ da .siren as " SIREN" ,
61
+ da .siret as " SIRET" ,
62
+ da .description as " Description" ,
63
+ at .code as " Type d'acteur" ,
64
+ da .url as " Site web" ,
65
+ CASE
66
+ WHEN da .telephone ~ ' ^0[67]' THEN NULL
67
+ WHEN EXISTS (
68
+ SELECT 1
69
+ FROM {{ ref(' opendata_acteur_sources' ) }} das2
70
+ JOIN qfdmo_source s ON das2 .source_id = s .id
71
+ WHERE das2 .acteur_id = da .identifiant_unique
72
+ AND s .code = ' carteco'
73
+ ) THEN NULL
74
+ ELSE da .telephone
75
+ END as " Téléphone" ,
76
+ da .adresse as " Adresse" ,
77
+ da .adresse_complement as " Complément d'adresse" ,
78
+ da .code_postal as " Code postal" ,
79
+ da .ville as " Ville" ,
80
+ ST_Y(da .location ::geometry) as " latitude" ,
81
+ ST_X(da .location ::geometry) as " longitude" ,
82
+ al .labels as " Qualités et labels" ,
83
+ da .public_accueilli as " Public accueilli" ,
84
+ da .reprise as " Reprise" ,
85
+ da .exclusivite_de_reprisereparation as " Exclusivité de reprise/réparation" ,
86
+ da .uniquement_sur_rdv as " Uniquement sur RDV" ,
87
+ acs .services as " Type de services" ,
88
+ ps .services ::text as " Propositions de services" ,
89
+ to_char(da .modifie_le , ' YYYY-MM-DD' ) as " Date de dernière modification"
90
+ FROM {{ ref(' opendata_acteur' ) }} AS da
91
+ LEFT JOIN qfdmo_acteurtype AS at ON da .acteur_type_id = at .id
92
+ -- INNER JOIN : Only open lisense
93
+ INNER JOIN deduplicated_opened_sources AS ds ON da .uuid = ds .uuid
94
+ LEFT JOIN proposition_services AS ps ON da .uuid = ps .uuid
95
+ LEFT JOIN acteur_labels AS al ON da .uuid = al .uuid
96
+ LEFT JOIN acteur_services AS acs ON da .uuid = acs .uuid
97
+ WHERE da .statut = ' ACTIF'
98
+ AND da .public_accueilli NOT IN (' AUCUN' , ' PROFESSIONNELS' )
99
+ AND da .identifiant_unique NOT LIKE ' %_reparation_%'
100
+ ORDER BY da .uuid
0 commit comments