Skip to content

Commit b07cf47

Browse files
StefanoPetrillitorjeSteinar H. Gunderson
authored andcommitted
MDEV-34278: Implement the GIS function ST_Collect
The GIS function ST_Collect takes as input multiple geometries and returns the aggregation of the distinct geometry arguments. The resulting value type is choosen using the following policy: - If all arguments are Point values, the result is a MultiPoint value. - If all arguments are LineString values, the result is a MultiLineString value. - If all arguments are Polygon values, the result is a MultiPolygon value. - Otherwise, the result is a GeometryCollection value. If there are multiple geometry arguments and those arguments are in the same SRS, the return value is in that SRS. If those arguments are not in the same SRS, an ER_GIS_DIFFERENT_SRIDS_AGGREGATION error occurs. Author: StefanoPetrilli <stefanop_1999@hotmail.it> Co-authored-by: Torje Digernes <torje.digernes@oracle.com> Co-authored-by: Steinar H. Gunderson <steinar.gunderson@oracle.com>
1 parent b503666 commit b07cf47

File tree

8 files changed

+535
-3
lines changed

8 files changed

+535
-3
lines changed
Lines changed: 126 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,126 @@
1+
# setup of data for tests involving simple aggregations and group by
2+
CREATE TABLE table_simple_aggregation ( running_number INTEGER NOT NULL
3+
AUTO_INCREMENT, grouping_condition INTEGER, location GEOMETRY , PRIMARY KEY (
4+
running_number));
5+
INSERT INTO table_simple_aggregation ( grouping_condition, location ) VALUES
6+
( 0,ST_GEOMFROMTEXT('POINT(0 0)',4326)),
7+
( 1,ST_GEOMFROMTEXT('POINT(0 0)',4326)),
8+
( 0,ST_GEOMFROMTEXT('POINT(1 0)',4326)),
9+
( 1,ST_GEOMFROMTEXT('POINT(2 0)',4326)),
10+
( 0,ST_GEOMFROMTEXT('POINT(3 0)',4326));
11+
# Functional requirement F-4: ST_COLLECT shall support simple table
12+
# aggregations
13+
# result shall be 1
14+
SELECT ST_EQUALS( (SELECT ST_COLLECT( location ) AS t FROM
15+
table_simple_aggregation) , ST_GEOMFROMTEXT('MULTIPOINT(0 0,0 0,1 0,2
16+
0,3 0) ',4326));
17+
ST_EQUALS( (SELECT ST_COLLECT( location ) AS t FROM
18+
table_simple_aggregation) , ST_GEOMFROMTEXT('MULTIPOINT(0 0,0 0,1 0,2
19+
0,3 0) ',4326))
20+
1
21+
INSERT INTO table_simple_aggregation (location) VALUES
22+
( ST_GEOMFROMTEXT('POINT(0 -0)' ,4326)),
23+
( NULL);
24+
# F-7 Aggregations with Nulls inside will just miss an element for each
25+
# Null
26+
# the result here shall be 1
27+
SELECT ST_EQUALS((SELECT ST_COLLECT(LOCATION) AS T FROM
28+
table_simple_aggregation), ST_GEOMFROMTEXT('GEOMETRYCOLLECTION( MULTIPOINT(0
29+
0,1 0,3 0), MULTIPOINT(2 0,0 0), POINT(0 0))',4326));
30+
ST_EQUALS((SELECT ST_COLLECT(LOCATION) AS T FROM
31+
table_simple_aggregation), ST_GEOMFROMTEXT('GEOMETRYCOLLECTION( MULTIPOINT(0
32+
0,1 0,3 0), MULTIPOINT(2 0,0 0), POINT(0 0))',4326))
33+
1
34+
# F-1 ST_COLLECT SHALL only return NULL if all elements are NULL or the
35+
# aggregate is empty.
36+
# as only a null is aggregated the result of the subquery shall be NULL
37+
# and the result of the whole query shall be 1
38+
SELECT (SELECT ST_COLLECT(location) AS t FROM table_simple_aggregation WHERE
39+
location = NULL) IS NULL;
40+
(SELECT ST_COLLECT(location) AS t FROM table_simple_aggregation WHERE
41+
location = NULL) IS NULL
42+
1
43+
# as no element is aggregated the result of the subquery shall be NULL
44+
# and the result of the whole query shall be 1
45+
SELECT (SELECT ST_COLLECT(location) AS t FROM table_simple_aggregation WHERE
46+
st_srid(location)=2110) IS NULL;
47+
(SELECT ST_COLLECT(location) AS t FROM table_simple_aggregation WHERE
48+
st_srid(location)=2110) IS NULL
49+
1
50+
INSERT INTO table_simple_aggregation (location) VALUES
51+
( ST_GEOMFROMTEXT('POINT(0 -0)' ,4326)),
52+
( NULL),
53+
( NULL);
54+
SELECT ST_ASTEXT(ST_COLLECT(location) OVER ( ROWS BETWEEN 1 PRECEDING AND
55+
CURRENT ROW)) FROM table_simple_aggregation;
56+
ST_ASTEXT(ST_COLLECT(location) OVER ( ROWS BETWEEN 1 PRECEDING AND
57+
CURRENT ROW))
58+
MULTIPOINT(0 0)
59+
MULTIPOINT(0 0,0 0)
60+
MULTIPOINT(0 0,1 0)
61+
MULTIPOINT(1 0,2 0)
62+
MULTIPOINT(2 0,3 0)
63+
MULTIPOINT(3 0,0 -0)
64+
MULTIPOINT(0 -0)
65+
MULTIPOINT(0 -0)
66+
MULTIPOINT(0 -0)
67+
NULL
68+
set session group_concat_max_len= 10;
69+
SELECT ST_COLLECT( location ) AS t FROM table_simple_aggregation;
70+
t
71+
NULL
72+
Warnings:
73+
Warning 1260 Row 1 was cut by st_collect()
74+
set session group_concat_max_len= 1048576;
75+
# Teardown of testing NULL data
76+
DROP TABLE table_simple_aggregation;
77+
# Setup for testing handling of multiple SRS
78+
CREATE TABLE multi_srs_table ( running_number INTEGER NOT NULL AUTO_INCREMENT,
79+
geometry GEOMETRY , PRIMARY KEY ( running_number ));
80+
INSERT INTO multi_srs_table( geometry ) VALUES
81+
(ST_GEOMFROMTEXT('POINT(60 -24)' ,4326)),
82+
(ST_GEOMFROMTEXT('POINT(61 -24)' ,4326)),
83+
(ST_GEOMFROMTEXT('POINT(38 77)'));
84+
# F-2 a) If the elements in an aggregate is of different SRSs,
85+
# ST_COLLECT MUST raise ER_GIS_DIFFERENT_SRIDS.
86+
SELECT ST_ASTEXT(ST_COLLECT(geometry)) AS t FROM multi_srs_table;
87+
ERROR HY000: Arguments to function st_collect( contains geometries with different SRIDs: 4326 and 0. All geometries must have the same SRID.
88+
#teardown of testing handling of multiple SRS
89+
DROP TABLE multi_srs_table;
90+
# setup of testing handling different geometry types
91+
CREATE TABLE simple_table ( running_number INTEGER NOT NULL AUTO_INCREMENT ,
92+
geo GEOMETRY, PRIMARY KEY ( RUNNING_NUMBER));
93+
INSERT INTO simple_table ( geo) VALUES
94+
(ST_GEOMFROMTEXT('POINT(0 0)')),
95+
(ST_GEOMFROMTEXT('LINESTRING(1 0, 1 1)')),
96+
(ST_GEOMFROMTEXT('LINESTRING(2 0, 2 1)')),
97+
(ST_GEOMFROMTEXT('POLYGON((3 0, 0 0, 0 3, 3 3, 3 0))')),
98+
(ST_GEOMFROMTEXT('POLYGON((4 0, 0 0, 0 4, 4 4, 4 0))')),
99+
(ST_GEOMFROMTEXT('MULTIPOINT(5 0)')),
100+
(ST_GEOMFROMTEXT('MULTIPOINT(6 0)')),
101+
(ST_GEOMFROMTEXT('GEOMETRYCOLLECTION EMPTY')),
102+
(ST_GEOMFROMTEXT('GEOMETRYCOLLECTION EMPTY'));
103+
# Functional requirement F-9 a, b, and c ) An aggregation containing
104+
# more than one type of geometry or any MULTI is GEOMETRYCOLLECTION, if
105+
# it only contains a single type of POINTS, LINESTRINGS or POLYGONS it
106+
# will be a MULTI of the same kind.
107+
# MP: Multipoint
108+
# MPoly: Multipolygon
109+
# MLS: Multilinestring
110+
# GC: geometrycollection
111+
# Functional requirement F-6 shall support window functions
112+
# result is expected for come in this order: MP, GC, MLS, GC, MPpoly,
113+
# GC, GC, GC, GC
114+
SELECT ST_ASTEXT(ST_COLLECT(geo) OVER( ORDER BY running_number ROWS BETWEEN 1
115+
PRECEDING AND CURRENT ROW)) AS geocollect FROM simple_table;
116+
geocollect
117+
MULTIPOINT(0 0)
118+
GEOMETRYCOLLECTION(POINT(0 0),LINESTRING(1 0,1 1))
119+
MULTILINESTRING((1 0,1 1),(2 0,2 1))
120+
GEOMETRYCOLLECTION(LINESTRING(2 0,2 1),POLYGON((3 0,0 0,0 3,3 3,3 0)))
121+
MULTIPOLYGON(((3 0,0 0,0 3,3 3,3 0)),((4 0,0 0,0 4,4 4,4 0)))
122+
GEOMETRYCOLLECTION(POLYGON((4 0,0 0,0 4,4 4,4 0)),MULTIPOINT(5 0))
123+
GEOMETRYCOLLECTION(MULTIPOINT(5 0),MULTIPOINT(6 0))
124+
GEOMETRYCOLLECTION(MULTIPOINT(6 0),GEOMETRYCOLLECTION EMPTY)
125+
GEOMETRYCOLLECTION(GEOMETRYCOLLECTION EMPTY,GEOMETRYCOLLECTION EMPTY)
126+
DROP TABLE simple_table;
Lines changed: 191 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,191 @@
1+
# Copyright (c) 2021, Oracle and/or its affiliates
2+
# Copyright (c) 2024, MariaDB Corporation.
3+
#
4+
# This program is free software; you can redistribute it and/or modify
5+
# it under the terms of the GNU General Public License as published by
6+
# the Free Software Foundation; version 2 of the License.
7+
#
8+
# This program is distributed in the hope that it will be useful,
9+
# but WITHOUT ANY WARRANTY; without even the implied warranty of
10+
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
11+
# GNU General Public License for more details.
12+
#
13+
# You should have received a copy of the GNU General Public License
14+
# along with this program; if not, write to the Free Software
15+
# Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA
16+
17+
# This test is for the ST_COLLECT aggregation function, introduced in WL#13454
18+
19+
--echo # setup of data for tests involving simple aggregations and group by
20+
CREATE TABLE table_simple_aggregation ( running_number INTEGER NOT NULL
21+
AUTO_INCREMENT, grouping_condition INTEGER, location GEOMETRY , PRIMARY KEY (
22+
running_number));
23+
INSERT INTO table_simple_aggregation ( grouping_condition, location ) VALUES
24+
( 0,ST_GEOMFROMTEXT('POINT(0 0)',4326)),
25+
( 1,ST_GEOMFROMTEXT('POINT(0 0)',4326)),
26+
( 0,ST_GEOMFROMTEXT('POINT(1 0)',4326)),
27+
( 1,ST_GEOMFROMTEXT('POINT(2 0)',4326)),
28+
( 0,ST_GEOMFROMTEXT('POINT(3 0)',4326));
29+
30+
--echo # Functional requirement F-4: ST_COLLECT shall support simple table
31+
--echo # aggregations
32+
--echo # result shall be 1
33+
SELECT ST_EQUALS( (SELECT ST_COLLECT( location ) AS t FROM
34+
table_simple_aggregation) , ST_GEOMFROMTEXT('MULTIPOINT(0 0,0 0,1 0,2
35+
0,3 0) ',4326));
36+
# --echo # Functional requirement F-8 Shall support DISTINCT in aggregates
37+
# --echo # result shall be 1
38+
# SELECT ST_EQUALS( (SELECT ST_COLLECT( DISTINCT location ) AS t FROM
39+
# table_simple_aggregation) , ST_GEOMFROMTEXT('MULTIPOINT(0 0,1 0,2 0,3
40+
# 0) ',4326));
41+
# --echo # Functional requirement F-5: ST_COLLECT shall support group by, which
42+
# --echo # is given by aggregation machinery
43+
# --echo # result shall be
44+
# --echo # MULTIPOINT(0 0,1 0,3 0)
45+
# --echo # MULTIPOINT(2 0,0 0)
46+
# --sorted_result
47+
# SELECT ST_ASTEXT(ST_COLLECT( DISTINCT location )) AS t FROM
48+
# table_simple_aggregation GROUP BY grouping_condition;
49+
50+
# --echo # Distinct with rollup
51+
# SELECT st_astext(ST_COLLECT( distinct location )) AS t from
52+
# table_simple_aggregation group by st_latitude(location) with rollup;
53+
54+
55+
INSERT INTO table_simple_aggregation (location) VALUES
56+
( ST_GEOMFROMTEXT('POINT(0 -0)' ,4326)),
57+
( NULL);
58+
59+
--echo # F-7 Aggregations with Nulls inside will just miss an element for each
60+
--echo # Null
61+
--echo # the result here shall be 1
62+
SELECT ST_EQUALS((SELECT ST_COLLECT(LOCATION) AS T FROM
63+
table_simple_aggregation), ST_GEOMFROMTEXT('GEOMETRYCOLLECTION( MULTIPOINT(0
64+
0,1 0,3 0), MULTIPOINT(2 0,0 0), POINT(0 0))',4326));
65+
--echo # F-1 ST_COLLECT SHALL only return NULL if all elements are NULL or the
66+
--echo # aggregate is empty.
67+
--echo # as only a null is aggregated the result of the subquery shall be NULL
68+
--echo # and the result of the whole query shall be 1
69+
SELECT (SELECT ST_COLLECT(location) AS t FROM table_simple_aggregation WHERE
70+
location = NULL) IS NULL;
71+
--echo # as no element is aggregated the result of the subquery shall be NULL
72+
--echo # and the result of the whole query shall be 1
73+
SELECT (SELECT ST_COLLECT(location) AS t FROM table_simple_aggregation WHERE
74+
st_srid(location)=2110) IS NULL;
75+
76+
INSERT INTO table_simple_aggregation (location) VALUES
77+
( ST_GEOMFROMTEXT('POINT(0 -0)' ,4326)),
78+
( NULL),
79+
( NULL);
80+
SELECT ST_ASTEXT(ST_COLLECT(location) OVER ( ROWS BETWEEN 1 PRECEDING AND
81+
CURRENT ROW)) FROM table_simple_aggregation;
82+
83+
84+
# --echo Excercising multiple code paths.
85+
# --sorted_result
86+
# SELECT ST_ASTEXT(ST_COLLECT(DISTINCT location)) AS geo, SUM(running_number)
87+
# OVER() FROM table_simple_aggregation GROUP BY running_number;
88+
# --sorted_result
89+
# SELECT ST_ASTEXT(ST_COLLECT(DISTINCT location)) AS geo, SUM(grouping_condition)
90+
# OVER(), grouping_condition FROM table_simple_aggregation GROUP BY
91+
# grouping_condition;
92+
# --sorted_result
93+
# SELECT ST_ASTEXT(ST_COLLECT(location)) AS geo, SUM(grouping_condition) OVER(),
94+
# grouping_condition FROM table_simple_aggregation GROUP BY grouping_condition;
95+
# --sorted_result
96+
# SELECT ST_ASTEXT(ST_COLLECT(location)) AS geo, SUM(running_number) OVER() FROM
97+
# table_simple_aggregation GROUP BY running_number;
98+
99+
--enable_warnings
100+
set session group_concat_max_len= 10;
101+
102+
SELECT ST_COLLECT( location ) AS t FROM table_simple_aggregation;
103+
104+
set session group_concat_max_len= 1048576;
105+
--disable_warnings
106+
107+
--echo # Teardown of testing NULL data
108+
DROP TABLE table_simple_aggregation;
109+
110+
111+
--echo # Setup for testing handling of multiple SRS
112+
CREATE TABLE multi_srs_table ( running_number INTEGER NOT NULL AUTO_INCREMENT,
113+
geometry GEOMETRY , PRIMARY KEY ( running_number ));
114+
INSERT INTO multi_srs_table( geometry ) VALUES
115+
(ST_GEOMFROMTEXT('POINT(60 -24)' ,4326)),
116+
(ST_GEOMFROMTEXT('POINT(61 -24)' ,4326)),
117+
(ST_GEOMFROMTEXT('POINT(38 77)'));
118+
119+
--echo # F-2 a) If the elements in an aggregate is of different SRSs,
120+
--echo # ST_COLLECT MUST raise ER_GIS_DIFFERENT_SRIDS.
121+
--error ER_GIS_DIFFERENT_SRIDS_AGGREGATION
122+
SELECT ST_ASTEXT(ST_COLLECT(geometry)) AS t FROM multi_srs_table;
123+
# TODO fix this
124+
# --echo # F-2 b) If all the elements in an aggregate is of same SRS, ST_COLLECT
125+
# --echo # MUST return a result in that SRS.
126+
# --echo # result shall be one MULTIPOINT((60 -24),(61 -24)) with SRID 4326 and
127+
# --echo # one
128+
# --echo # Multipoint((38 77)) with SRID 0. There is some rounding issue on the
129+
# --echo # result, bug #31535105
130+
# --sorted_result
131+
# SELECT st_srid(geometry),ST_ASTEXT(ST_COLLECT( geometry )) AS t FROM
132+
# multi_srs_table GROUP BY ST_SRID(geometry);
133+
134+
# --echo Rollup needs all SRIDs to be the same.
135+
# --error ER_GIS_DIFFERENT_SRIDS_AGGREGATION
136+
# SELECT st_srid(geometry),ST_ASTEXT(ST_COLLECT( geometry )) AS t FROM
137+
# multi_srs_table GROUP BY ST_SRID(geometry) WITH ROLLUP;
138+
139+
# --echo # Triggering a codepath for geometrycollection in temp tables
140+
# INSERT INTO multi_srs_table( geometry ) VALUES
141+
# (ST_GEOMFROMTEXT('GEOMETRYCOLLECTION(POINT(60 -24))' ,4326));
142+
# --sorted_result
143+
# SELECT st_srid(geometry),ST_ASTEXT(ST_COLLECT( geometry )) AS t FROM
144+
# multi_srs_table GROUP BY ST_SRID(geometry);
145+
146+
147+
--echo #teardown of testing handling of multiple SRS
148+
DROP TABLE multi_srs_table;
149+
150+
--echo # setup of testing handling different geometry types
151+
CREATE TABLE simple_table ( running_number INTEGER NOT NULL AUTO_INCREMENT ,
152+
geo GEOMETRY, PRIMARY KEY ( RUNNING_NUMBER));
153+
INSERT INTO simple_table ( geo) VALUES
154+
(ST_GEOMFROMTEXT('POINT(0 0)')),
155+
(ST_GEOMFROMTEXT('LINESTRING(1 0, 1 1)')),
156+
(ST_GEOMFROMTEXT('LINESTRING(2 0, 2 1)')),
157+
(ST_GEOMFROMTEXT('POLYGON((3 0, 0 0, 0 3, 3 3, 3 0))')),
158+
(ST_GEOMFROMTEXT('POLYGON((4 0, 0 0, 0 4, 4 4, 4 0))')),
159+
(ST_GEOMFROMTEXT('MULTIPOINT(5 0)')),
160+
(ST_GEOMFROMTEXT('MULTIPOINT(6 0)')),
161+
(ST_GEOMFROMTEXT('GEOMETRYCOLLECTION EMPTY')),
162+
(ST_GEOMFROMTEXT('GEOMETRYCOLLECTION EMPTY'));
163+
164+
165+
--echo # Functional requirement F-9 a, b, and c ) An aggregation containing
166+
--echo # more than one type of geometry or any MULTI is GEOMETRYCOLLECTION, if
167+
--echo # it only contains a single type of POINTS, LINESTRINGS or POLYGONS it
168+
--echo # will be a MULTI of the same kind.
169+
--echo # MP: Multipoint
170+
--echo # MPoly: Multipolygon
171+
--echo # MLS: Multilinestring
172+
--echo # GC: geometrycollection
173+
--echo # Functional requirement F-6 shall support window functions
174+
--echo # result is expected for come in this order: MP, GC, MLS, GC, MPpoly,
175+
--echo # GC, GC, GC, GC
176+
SELECT ST_ASTEXT(ST_COLLECT(geo) OVER( ORDER BY running_number ROWS BETWEEN 1
177+
PRECEDING AND CURRENT ROW)) AS geocollect FROM simple_table;
178+
# --echo # with DISTINCT this result is expected to be:
179+
# --echo # GEMETRYCOLLECTION(GEOMETRYCOLLECTION EMPTY)
180+
# --echo # GEMETRYCOLLECTION(GEOMETRYCOLLECTION EMPTY)
181+
# SELECT ST_ASTEXT(ST_COLLECT( DISTINCT geo) OVER( ORDER BY running_number ROWS
182+
# BETWEEN 1 PRECEDING AND CURRENT ROW)) AS geocollect FROM simple_table WHERE
183+
# ST_EQUALS(geo,ST_GEOMFROMTEXT('GEOMETRYCOLLECTION EMPTY'));
184+
185+
# --echo # Exercising the "copy" constructor
186+
# SELECT ST_ASTEXT(ST_COLLECT(geo)) FROM simple_table GROUP BY geo WITH ROLLUP;
187+
188+
# --echo # Casting Geometry as decimal invokes val_decimal()
189+
# SELECT CAST(ST_COLLECT(geo) AS DECIMAL ) FROM simple_table;
190+
191+
DROP TABLE simple_table;

0 commit comments

Comments
 (0)