From aaf0e930e1a93baf70ec682b421018df120f9ae4 Mon Sep 17 00:00:00 2001 From: Chris Behrens Date: Thu, 14 Mar 2024 19:21:34 -0700 Subject: [PATCH] Another attempt at overlap query fix It appears this is a problem on mysql because ST_Area() bombs on non-2D objects while MariaDB just returns 0. What we actually care about is ST_Contains() and not ST_Intersects(). ST_Intersects() will return true if only an edge intersects, but ST_Contains() will ensure there's at least some amount of containment/area. I've kept ST_Intersects() in front of ST_Contains() because the query was super slow without it. Keeping it reduces calls to ST_Contains(). --- db_store/sql/3_overlap_fix.up.sql | 24 ++++++++++++++++++++++++ 1 file changed, 24 insertions(+) create mode 100644 db_store/sql/3_overlap_fix.up.sql diff --git a/db_store/sql/3_overlap_fix.up.sql b/db_store/sql/3_overlap_fix.up.sql new file mode 100644 index 0000000..7008e45 --- /dev/null +++ b/db_store/sql/3_overlap_fix.up.sql @@ -0,0 +1,24 @@ +-- Fix procedure for overlap disablement +-- mysql (at least old 8.0.x)'s ST_Area throws an +-- error on non-poly/mpoly (2D objects). (MariaDB's +-- ST_Area will return 0 for non-poly/mpoly.) +-- It looks like ST_Overlaps would work as a replacement +-- for ST_Intersects which gives us what we want. However, +-- that is very slow. Keeping the ST_Intersects in front +-- of ST_Overlaps keeps it fast. +DROP PROCEDURE IF EXISTS fl_nest_filter_overlap; +CREATE PROCEDURE fl_nest_filter_overlap (IN maximum_overlap double) +BEGIN + DROP TEMPORARY TABLE IF EXISTS overlapNest; + CREATE TEMPORARY TABLE overlapNest AS ( + SELECT b.nest_id + FROM nests a, nests b + WHERE a.active = 1 AND b.active = 1 AND + a.m2 > b.m2 AND + ST_Intersects(a.polygon, b.polygon) AND + ST_Overlaps(a.polygon, b.polygon) AND + (100 * ST_Area(ST_Intersection(a.polygon,b.polygon)) / ST_Area(b.polygon)) > maximum_overlap + ); + UPDATE nests a, overlapNest b SET a.active=0, discarded = 'overlap' WHERE a.nest_id=b.nest_id; + DROP TEMPORARY TABLE overlapNest; +END