|
| 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