Skip to content

Commit

Permalink
Merge pull request #3888 from GeotrekCE/mfu-perf-qgis-view-intersection
Browse files Browse the repository at this point in the history
Improve perfs for spatial intersection for sql views (refs : #3600)
  • Loading branch information
bruhnild committed Jan 25, 2024
2 parents 326b23e + 663e4ed commit 95bedd3
Show file tree
Hide file tree
Showing 10 changed files with 139 additions and 203 deletions.
6 changes: 5 additions & 1 deletion docs/changelog.rst
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,10 @@ CHANGELOG
2.101.5+dev (XXXX-XX-XX)
------------------------

**Documentation**

- Improve performance in spatial intersection (zoning district and zoning city) for sql views (#3600)

2.101.5 (2024-01-11)
--------------------

Expand Down Expand Up @@ -5525,4 +5529,4 @@ Installation script
* Fix regex for RAISE NOTICE (fixes #673)
* Initial public version

See project history in `docs/history.rst` (French).
See project history in `docs/history.rst` (French).
36 changes: 12 additions & 24 deletions geotrek/core/templates/core/sql/post_60_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -30,28 +30,16 @@ SELECT a.id,
a.geom
FROM v_trails a
LEFT JOIN authent_structure d ON a.structure_id = d.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM
(SELECT core_topology.geom,
core_topology.id
FROM core_trail,
core_topology
WHERE core_trail.topo_object_id = core_topology.id
AND core_topology.deleted = FALSE) a
JOIN zoning_city b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) f ON a.id = f.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM
(SELECT core_topology.geom,
core_topology.id
FROM core_trail,
core_topology
WHERE core_trail.topo_object_id = core_topology.id
AND core_topology.deleted = FALSE) a
JOIN zoning_district b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) g ON a.id = g.id
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) f ON true
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) g ON true
;
22 changes: 12 additions & 10 deletions geotrek/feedback/templates/feedback/sql/post_10_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,15 +23,17 @@ LEFT JOIN public.feedback_reportactivity b ON a.activity_id = b.id
LEFT JOIN public.feedback_reportcategory c ON a.category_id = c.id
LEFT JOIN public.feedback_reportstatus d ON a.status_id = d.id
LEFT JOIN public.feedback_reportproblemmagnitude e ON a.problem_magnitude_id = e.id
LEFT JOIN (SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM feedback_report a
JOIN zoning_city b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) f ON a.id = f.id
LEFT JOIN (SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM feedback_report a
JOIN zoning_district b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) g ON a.id = g.id
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) f ON true
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) g ON true
WHERE deleted IS FALSE
;
Original file line number Diff line number Diff line change
Expand Up @@ -75,33 +75,17 @@ LEFT JOIN infrastructure_infrastructurecondition c ON a.condition_id = c.id
LEFT JOIN infrastructure_infrastructureusagedifficultylevel d ON a.usage_difficulty_id = d.id
LEFT JOIN infrastructure_infrastructuremaintenancedifficultylevel e ON a.maintenance_difficulty_id = e.id
LEFT JOIN common_accessmean j ON a.access_id = j.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM
(SELECT e.geom,
e.id
FROM infrastructure_infrastructure t,
infrastructure_infrastructuretype b,
core_topology e
WHERE t.topo_object_id = e.id
AND t.type_id = b.id
AND e.deleted = FALSE) a
JOIN zoning_city b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) f ON a.id = f.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM
(SELECT e.geom,
e.id
FROM infrastructure_infrastructure t,
infrastructure_infrastructuretype b,
core_topology e
WHERE t.topo_object_id = e.id
AND t.type_id = b.id
AND e.deleted = FALSE) a
JOIN zoning_district b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) g ON a.id = g.id
LEFT JOIN authent_structure i ON a.structure_id = i.id
LEFT JOIN LATERAL
( SELECT array_to_string(array_agg(b_1.name
ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id ) f ON TRUE
LEFT JOIN LATERAL
( SELECT array_to_string(array_agg(b_1.name
ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id ) g ON TRUE
LEFT JOIN authent_structure i ON a.structure_id = i.id
;
24 changes: 12 additions & 12 deletions geotrek/maintenance/templates/maintenance/sql/post_20_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -44,18 +44,18 @@ LEFT JOIN core_stake d ON a.stake_id = d.id
LEFT JOIN authent_structure e ON a.structure_id = e.id
LEFT JOIN maintenance_project h ON a.project_id = h.id
LEFT JOIN common_accessmean accessmean ON a.access_id = accessmean.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM maintenance_intervention a
JOIN zoning_city b ON ST_INTERSECTS (st_pointonsurface(a.geom_3d), b.geom)
GROUP BY a.id) f ON a.id = f.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM maintenance_intervention a
JOIN zoning_district b ON ST_INTERSECTS (st_pointonsurface(a.geom_3d), b.geom)
GROUP BY a.id) g ON a.id = g.id
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom_3d, b_1.geom)
GROUP BY a.id
) f ON true
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom_3d, b_1.geom)
GROUP BY a.id
) g ON true
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (disorder ORDER BY a.id), ', ', '_') disorder,
c.id
Expand Down
26 changes: 12 additions & 14 deletions geotrek/outdoor/templates/outdoor/sql/post_20_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -215,20 +215,18 @@ SELECT a.id,
FROM public.outdoor_site a
JOIN outdoor_site_geom sg ON a.id = sg.id AND NOT ST_IsEmpty(sg.geom)
LEFT JOIN authent_structure b ON a.structure_id = b.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM
outdoor_site a
JOIN zoning_city b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) c ON a.id = c.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM
outdoor_site a
JOIN zoning_district b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) d ON a.id = d.id
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) c ON true
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) d ON true
LEFT JOIN outdoor_sitetype e ON a.type_id = e.id
LEFT JOIN outdoor_practice f ON a.practice_id = f.id
LEFT JOIN
Expand Down
24 changes: 12 additions & 12 deletions geotrek/sensitivity/templates/sensitivity/sql/post_10_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -99,18 +99,18 @@ LEFT JOIN (
) r ON r.sensitivearea_id = a.id
LEFT JOIN sensitivity_species h ON a.species_id = h.id
LEFT JOIN authent_structure d ON a.structure_id = d.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM sensitivity_sensitivearea a
JOIN zoning_city b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) f ON a.id = f.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM sensitivity_sensitivearea a
JOIN zoning_district b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) g ON a.id = g.id
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) f ON true
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) g ON true
WHERE deleted IS FALSE
;

42 changes: 13 additions & 29 deletions geotrek/signage/templates/signage/sql/post_10_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -86,37 +86,21 @@ LEFT JOIN ( WITH signage_condition AS (
LEFT JOIN signage_sealing d ON a.sealing_id = d.id
LEFT JOIN authent_structure e ON a.structure_id = e.id
LEFT JOIN common_accessmean i ON a.access_id = i.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM
(SELECT e.id,
e.geom
FROM signage_signage t,
signage_signagetype b,
core_topology e
WHERE t.topo_object_id = e.id
AND t.type_id = b.id
AND e.deleted = FALSE ) a
JOIN zoning_city b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) f ON a.id = f.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM
(SELECT e.id,
e.geom
FROM signage_signage t,
signage_signagetype b,
core_topology e
WHERE t.topo_object_id = e.id
AND t.type_id = b.id
AND e.deleted = FALSE ) a
JOIN zoning_district b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) g ON a.id = g.id
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) f ON true
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) g ON true
LEFT JOIN
(SELECT organism,
b.topo_object_id
FROM common_organism a
JOIN signage_signage b ON a.id = b.manager_id) h ON a.topo_object_id = h.topo_object_id
JOIN signage_signage b ON a.id = b.manager_id) h ON a.topo_object_id = h.topo_object_id
;
48 changes: 24 additions & 24 deletions geotrek/tourism/templates/tourism/sql/post_20_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -137,18 +137,18 @@ LEFT JOIN
GROUP BY c.id) p ON a.id = p.id
LEFT JOIN authent_structure c ON a.structure_id = c.id
LEFT JOIN common_reservationsystem d ON a.reservation_system_id = d.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM tourism_touristiccontent a
JOIN zoning_city b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) f ON a.id = f.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM tourism_touristiccontent a
JOIN zoning_district b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) g ON a.id = g.id
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) f ON true
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) g ON true
WHERE deleted IS FALSE
;

Expand Down Expand Up @@ -221,18 +221,18 @@ LEFT JOIN public.authent_structure c ON a.structure_id = c.id
LEFT JOIN public.tourism_touristiceventorganizer d ON a.organizer_id = d.id
LEFT JOIN public.tourism_cancellationreason cr ON a.cancellation_reason_id = cr.id
LEFT JOIN public.tourism_touristiceventplace p ON a.place_id = p.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_city,
a.id
FROM tourism_touristicevent a
JOIN zoning_city b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) f ON a.id = f.id
LEFT JOIN
(SELECT array_to_string(ARRAY_AGG (b.name ORDER BY b.name), ', ', '_') zoning_district,
a.id
FROM tourism_touristicevent a
JOIN zoning_district b ON ST_INTERSECTS (a.geom, b.geom)
GROUP BY a.id) g ON a.id = g.id
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_city
FROM zoning_city b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) f ON true
LEFT JOIN LATERAL (
SELECT array_to_string(array_agg(b_1.name ORDER BY b_1.name), ', '::text, '_'::text) AS zoning_district
FROM zoning_district b_1
WHERE st_intersects(a.geom, b_1.geom)
GROUP BY a.id
) g ON true
LEFT JOIN
(SELECT c.id,
array_to_string(ARRAY_AGG (a.label ORDER BY a.id), ', ', '_') labels
Expand Down

0 comments on commit 95bedd3

Please sign in to comment.