From c0460146b8d6349abe0f1d5b3c2d76e5c19ddda7 Mon Sep 17 00:00:00 2001 From: Chris Behrens Date: Sun, 28 Jul 2024 12:18:56 -0700 Subject: [PATCH] Fix overlap disablement for mysql 8.0 (#55) mysql 8.0 can only deal with SRID 0, so when the server is 8.0*, this does hacky conversions into temp tables first and then runs the existing query using those temp tables. --- db_store/sql/6_mysql8.up.sql | 37 ++++++++++++++++++++++++++++++++++++ 1 file changed, 37 insertions(+) create mode 100644 db_store/sql/6_mysql8.up.sql diff --git a/db_store/sql/6_mysql8.up.sql b/db_store/sql/6_mysql8.up.sql new file mode 100644 index 0000000..e3b915c --- /dev/null +++ b/db_store/sql/6_mysql8.up.sql @@ -0,0 +1,37 @@ +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; + IF (SELECT VERSION() LIKE '8.0%') THEN + DROP TEMPORARY TABLE IF EXISTS convertedGeosA; + DROP TEMPORARY TABLE IF EXISTS convertedGeosB; + CREATE TEMPORARY TABLE convertedGeosA AS ( + SELECT nest_id, m2, ST_GeomFromText(ST_ASTEXT(polygon), 0) as polygon FROM nests WHERE active=1 + ); + CREATE TEMPORARY TABLE convertedGeosB AS ( + SELECT nest_id, m2, ST_GeomFromText(ST_ASTEXT(polygon), 0) as polygon FROM nests WHERE active=1 + ); + CREATE TEMPORARY TABLE overlapNest AS ( + SELECT b.nest_id + FROM convertedGeosA a, convertedGeosB b + WHERE a.m2 > b.m2 AND + ST_Intersects(a.polygon, b.polygon) AND + ST_GeometryType(ST_Intersection(a.polygon, b.polygon)) IN ('Polygon', 'MultiPolygon') AND + (100 * ST_Area(ST_Intersection(a.polygon,b.polygon)) / ST_Area(b.polygon)) > maximum_overlap + ); + ELSE + 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_GeometryType(ST_Intersection(a.polygon, b.polygon)) IN ('Polygon', 'MultiPolygon') AND + (100 * ST_Area(ST_Intersection(a.polygon,b.polygon)) / ST_Area(b.polygon)) > maximum_overlap + ); + END IF; + UPDATE nests a, overlapNest b SET a.active=0,a.discarded='overlap',a.pokemon_id=NULL,a.pokemon_form=NULL,a.pokemon_avg=NULL,a.pokemon_count=NULL,a.pokemon_ratio=NULL,a.pokemon_avg=NULL WHERE a.nest_id=b.nest_id; + DROP TEMPORARY TABLE overlapNest; + DROP TEMPORARY TABLE IF EXISTS convertedGeosA; + DROP TEMPORARY TABLE IF EXISTS convertedGeosB; +END