changeset 4019:da3ab68875e1

Fixed duplicates for historized bottlenecks in search. Only find bottlenecks currently valid.
author Sascha Wilde <wilde@intevation.de>
date Fri, 19 Jul 2019 17:16:29 +0200
parents 639bdb17c3f2
children e9fc97a29bd6
files schema/search_functions.sql schema/updates/1005/01.search-only-valid-bottleneck.sql schema/version.sql
diffstat 3 files changed, 20 insertions(+), 1 deletions(-) [+]
line wrap: on
line diff
--- a/schema/search_functions.sql	Fri Jul 19 16:59:25 2019 +0200
+++ b/schema/search_functions.sql	Fri Jul 19 17:16:29 2019 +0200
@@ -55,6 +55,7 @@
                  'bottleneck' AS type
             FROM waterway.bottlenecks
             WHERE objnam ILIKE '%' || search_string || '%'
+              AND validity @> 'now'::timestamptz
           ORDER BY name) r;
   RETURN _result;
 END;
--- /dev/null	Thu Jan 01 00:00:00 1970 +0000
+++ b/schema/updates/1005/01.search-only-valid-bottleneck.sql	Fri Jul 19 17:16:29 2019 +0200
@@ -0,0 +1,18 @@
+CREATE OR REPLACE FUNCTION search_bottlenecks(search_string text) RETURNS jsonb
+  LANGUAGE plpgsql STABLE PARALLEL SAFE
+  AS $$
+DECLARE
+  _result jsonb;
+BEGIN
+  SELECT COALESCE(json_agg(r),'[]')
+    INTO _result
+    FROM (SELECT objnam AS name,
+                 ST_AsGeoJSON(ST_Envelope(area::geometry))::json AS geom,
+                 'bottleneck' AS type
+            FROM waterway.bottlenecks
+            WHERE objnam ILIKE '%' || search_string || '%'
+              AND validity @> 'now'::timestamptz
+          ORDER BY name) r;
+  RETURN _result;
+END;
+$$;
--- a/schema/version.sql	Fri Jul 19 16:59:25 2019 +0200
+++ b/schema/version.sql	Fri Jul 19 17:16:29 2019 +0200
@@ -1,1 +1,1 @@
-INSERT INTO gemma_schema_version(version) VALUES (1004);
+INSERT INTO gemma_schema_version(version) VALUES (1005);