From de7d85824caf4f4fcc20275dc2f06c039dd72320 Mon Sep 17 00:00:00 2001 From: Anikait Agrawal <54908236+Anikait143@users.noreply.github.com> Date: Wed, 8 Nov 2023 13:01:36 +0530 Subject: [PATCH] Implement Supported Geospatial CASTs (#1945) This commit contains Tests and Fixes for Supported and Unsupported CASTs for Geospatial Data Types. Added Casts which need to be supported for Geospatial Data Types. Disabled Casts which were being supported but weren't meant to be supported. Added proper CASTing Tests for JDBC driver in TestSpatialPoint-vu-* test files (for both IMPLICIT and EXPLICIT CASTs) Updated PostGIS and Proj versions according to gitfarm to remove any differences b/w github and gitfarm Task: BABEL- 4501 Signed-off-by: Anikait Agrawal agraani@amazon.com --- .../build-postgis-extension/action.yml | 17 +- .../setup-base-version/action.yml | 17 +- .github/workflows/major-version-upgrade.yml | 17 +- .github/workflows/minor-version-upgrade.yml | 17 +- .github/workflows/tap-tests.yml | 17 +- contrib/babelfishpg_common/sql/geography.sql | 183 +++++- contrib/babelfishpg_common/sql/geometry.sql | 153 ++++- .../upgrades/spatial_types--3.2.0--3.3.0.sql | 336 ++++++++-- .../expected/TestSpatialPoint-vu-cleanup.out | 20 + .../expected/TestSpatialPoint-vu-prepare.out | 100 +-- .../expected/TestSpatialPoint-vu-verify.out | 580 +++++++++++++++++- .../datatypes/TestSpatialPoint-vu-cleanup.txt | 20 + .../datatypes/TestSpatialPoint-vu-prepare.txt | 40 +- .../datatypes/TestSpatialPoint-vu-verify.sql | 176 ++++++ .../expected_dependency.out | 23 +- 15 files changed, 1546 insertions(+), 170 deletions(-) diff --git a/.github/composite-actions/build-postgis-extension/action.yml b/.github/composite-actions/build-postgis-extension/action.yml index e242936b75..1277685c40 100644 --- a/.github/composite-actions/build-postgis-extension/action.yml +++ b/.github/composite-actions/build-postgis-extension/action.yml @@ -12,20 +12,23 @@ runs: - name: Build PostGIS Extension run: | cd .. + export CC='ccache gcc' + export CMAKE_C_COMPILER_LAUNCHER=ccache + export CMAKE_CXX_COMPILER_LAUNCHER=ccache sudo apt-get install wget - wget http://postgis.net/stuff/postgis-3.3.3dev.tar.gz - tar -xvzf postgis-3.3.3dev.tar.gz - wget https://download.osgeo.org/proj/proj-4.9.1.tar.gz - tar -xvzf proj-4.9.1.tar.gz - cd proj-4.9.1 + wget http://postgis.net/stuff/postgis-3.4.0.tar.gz + tar -xvzf postgis-3.4.0.tar.gz + wget https://download.osgeo.org/proj/proj-9.2.1.tar.gz + tar -xvzf proj-9.2.1.tar.gz + cd proj-9.2.1 if [ ! -d "build" ]; then mkdir build fi cd build - cmake .. + cmake -DCMAKE_INSTALL_LIBDIR="lib/x86_64-linux-gnu" -DCMAKE_INSTALL_PREFIX="/usr" .. cmake --build . sudo cmake --build . --target install - cd ../../postgis-3.3.3dev + cd ../../postgis-3.4.0 ./configure --without-protobuf --without-raster --with-pgconfig=$HOME/${{ inputs.install_dir }}/bin/pg_config make USE_PGXS=1 PG_CONFIG=~/${{ inputs.install_dir }}/bin/pg_config sudo make USE_PGXS=1 PG_CONFIG=~/${{ inputs.install_dir }}/bin/pg_config install diff --git a/.github/composite-actions/setup-base-version/action.yml b/.github/composite-actions/setup-base-version/action.yml index c8b4a48844..b8eddf5918 100644 --- a/.github/composite-actions/setup-base-version/action.yml +++ b/.github/composite-actions/setup-base-version/action.yml @@ -62,20 +62,23 @@ runs: - name: Build PostGIS Extension run: | cd .. + export CC='ccache gcc' + export CMAKE_C_COMPILER_LAUNCHER=ccache + export CMAKE_CXX_COMPILER_LAUNCHER=ccache sudo apt-get install wget - wget http://postgis.net/stuff/postgis-3.3.3dev.tar.gz - tar -xvzf postgis-3.3.3dev.tar.gz - wget https://download.osgeo.org/proj/proj-4.9.1.tar.gz - tar -xvzf proj-4.9.1.tar.gz - cd proj-4.9.1 + wget http://postgis.net/stuff/postgis-3.4.0.tar.gz + tar -xvzf postgis-3.4.0.tar.gz + wget https://download.osgeo.org/proj/proj-9.2.1.tar.gz + tar -xvzf proj-9.2.1.tar.gz + cd proj-9.2.1 if [ ! -d "build" ]; then mkdir build fi cd build - cmake .. + cmake -DCMAKE_INSTALL_LIBDIR="lib/x86_64-linux-gnu" -DCMAKE_INSTALL_PREFIX="/usr" .. cmake --build . sudo cmake --build . --target install - cd ../../postgis-3.3.3dev + cd ../../postgis-3.4.0 ./configure --without-protobuf --without-raster --with-pgconfig=$HOME/${{ inputs.install_dir }}/bin/pg_config make USE_PGXS=1 PG_CONFIG=~/${{ inputs.install_dir }}/bin/pg_config sudo make USE_PGXS=1 PG_CONFIG=~/${{ inputs.install_dir }}/bin/pg_config install diff --git a/.github/workflows/major-version-upgrade.yml b/.github/workflows/major-version-upgrade.yml index 67a6cc8ef0..ed3deb3eaf 100644 --- a/.github/workflows/major-version-upgrade.yml +++ b/.github/workflows/major-version-upgrade.yml @@ -50,20 +50,23 @@ jobs: if: always() && steps.compile-antlr.outcome == 'success' run: | cd .. + export CC='ccache gcc' + export CMAKE_C_COMPILER_LAUNCHER=ccache + export CMAKE_CXX_COMPILER_LAUNCHER=ccache sudo apt-get install wget - wget http://postgis.net/stuff/postgis-3.3.3dev.tar.gz - tar -xvzf postgis-3.3.3dev.tar.gz - wget https://download.osgeo.org/proj/proj-4.9.1.tar.gz - tar -xvzf proj-4.9.1.tar.gz - cd proj-4.9.1 + wget http://postgis.net/stuff/postgis-3.4.0.tar.gz + tar -xvzf postgis-3.4.0.tar.gz + wget https://download.osgeo.org/proj/proj-9.2.1.tar.gz + tar -xvzf proj-9.2.1.tar.gz + cd proj-9.2.1 if [ ! -d "build" ]; then mkdir build fi cd build - cmake .. + cmake -DCMAKE_INSTALL_LIBDIR="lib/x86_64-linux-gnu" -DCMAKE_INSTALL_PREFIX="/usr" .. cmake --build . sudo cmake --build . --target install - cd ../../postgis-3.3.3dev + cd ../../postgis-3.4.0 ./configure --without-protobuf --without-raster --with-pgconfig=$HOME/psql_source/bin/pg_config make USE_PGXS=1 PG_CONFIG=~/psql_source/bin/pg_config sudo make USE_PGXS=1 PG_CONFIG=~/psql_source/bin/pg_config install diff --git a/.github/workflows/minor-version-upgrade.yml b/.github/workflows/minor-version-upgrade.yml index ed893b103d..7a5fe74e9d 100644 --- a/.github/workflows/minor-version-upgrade.yml +++ b/.github/workflows/minor-version-upgrade.yml @@ -40,20 +40,23 @@ jobs: if: always() && steps.compile-antlr.outcome == 'success' run: | cd .. + export CC='ccache gcc' + export CMAKE_C_COMPILER_LAUNCHER=ccache + export CMAKE_CXX_COMPILER_LAUNCHER=ccache sudo apt-get install wget - wget http://postgis.net/stuff/postgis-3.3.3dev.tar.gz - tar -xvzf postgis-3.3.3dev.tar.gz - wget https://download.osgeo.org/proj/proj-4.9.1.tar.gz - tar -xvzf proj-4.9.1.tar.gz - cd proj-4.9.1 + wget http://postgis.net/stuff/postgis-3.4.0.tar.gz + tar -xvzf postgis-3.4.0.tar.gz + wget https://download.osgeo.org/proj/proj-9.2.1.tar.gz + tar -xvzf proj-9.2.1.tar.gz + cd proj-9.2.1 if [ ! -d "build" ]; then mkdir build fi cd build - cmake .. + cmake -DCMAKE_INSTALL_LIBDIR="lib/x86_64-linux-gnu" -DCMAKE_INSTALL_PREFIX="/usr" .. cmake --build . sudo cmake --build . --target install - cd ../../postgis-3.3.3dev + cd ../../postgis-3.4.0 ./configure --without-protobuf --without-raster --with-pgconfig=$HOME/psql/bin/pg_config make USE_PGXS=1 PG_CONFIG=~/psql/bin/pg_config sudo make USE_PGXS=1 PG_CONFIG=~/psql/bin/pg_config install diff --git a/.github/workflows/tap-tests.yml b/.github/workflows/tap-tests.yml index ae78c001d2..ce5148305a 100644 --- a/.github/workflows/tap-tests.yml +++ b/.github/workflows/tap-tests.yml @@ -56,20 +56,23 @@ jobs: if: always() && steps.compile-antlr.outcome == 'success' run: | cd .. + export CC='ccache gcc' + export CMAKE_C_COMPILER_LAUNCHER=ccache + export CMAKE_CXX_COMPILER_LAUNCHER=ccache sudo apt-get install wget - wget http://postgis.net/stuff/postgis-3.3.3dev.tar.gz - tar -xvzf postgis-3.3.3dev.tar.gz - wget https://download.osgeo.org/proj/proj-4.9.1.tar.gz - tar -xvzf proj-4.9.1.tar.gz - cd proj-4.9.1 + wget http://postgis.net/stuff/postgis-3.4.0.tar.gz + tar -xvzf postgis-3.4.0.tar.gz + wget https://download.osgeo.org/proj/proj-9.2.1.tar.gz + tar -xvzf proj-9.2.1.tar.gz + cd proj-9.2.1 if [ ! -d "build" ]; then mkdir build fi cd build - cmake .. + cmake -DCMAKE_INSTALL_LIBDIR="lib/x86_64-linux-gnu" -DCMAKE_INSTALL_PREFIX="/usr" .. cmake --build . sudo cmake --build . --target install - cd ../../postgis-3.3.3dev + cd ../../postgis-3.4.0 ./configure --without-protobuf --without-raster --with-pgconfig=$HOME/psql_source/bin/pg_config make USE_PGXS=1 PG_CONFIG=~/psql_source/bin/pg_config sudo make USE_PGXS=1 PG_CONFIG=~/psql_source/bin/pg_config install diff --git a/contrib/babelfishpg_common/sql/geography.sql b/contrib/babelfishpg_common/sql/geography.sql index b79eb1493b..1da875688e 100644 --- a/contrib/babelfishpg_common/sql/geography.sql +++ b/contrib/babelfishpg_common/sql/geography.sql @@ -152,8 +152,22 @@ CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(bytea) CREATE OR REPLACE FUNCTION sys.bytea(sys.GEOGRAPHY) RETURNS bytea - AS '$libdir/postgis-3','LWGEOM_to_bytea' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + AS $$ + DECLARE + byte bytea; + BEGIN + -- Here the received bytes are -> 1 byte (endianness) + 4 bytes (type) + 4 bytes (SRID) + 16 bytes * npoints + byte := (SELECT sys.bytea_helper($1)); + -- Checking the Geometry type currently we support only POINT type -> type = 1 (01000020 [here last byte represents presence of SRID]) + IF encode(substring(byte from 2 for 4), 'hex') = encode(E'\\x01000020', 'hex') THEN + -- Here we are taking bytes from SRID only for driver expected format -> 4 bytes (SRID) + 16 bytes * npoints + byte := substring(byte from 6); + -- The drivers expected format is 4 bytes (SRID) + 2 bytes (type -> 010C for point) + 16 bytes * npoints + byte := substring(byte from 1 for 4) || E'\\x010c' || substring(byte from 5); + END IF; + RETURN byte; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.bbf_varbinary) RETURNS sys.GEOGRAPHY @@ -163,33 +177,110 @@ CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.bbf_varbinary) BEGIN varBin := (SELECT CAST ($1 AS bytea)); -- Call the underlying function after preprocessing - RETURN (SELECT CAST (varBin AS GEOGRAPHY)); + RETURN (SELECT sys.GEOGRAPHY(varBin)); END; $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.bbf_varbinary(sys.GEOGRAPHY) RETURNS sys.bbf_varbinary - AS '$libdir/postgis-3','LWGEOM_to_bytea' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + AS $$ + DECLARE + byte bytea; + BEGIN + byte := (SELECT sys.bytea($1)); + RETURN (SELECT CAST (byte AS sys.bbf_varbinary)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE CAST (bytea AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(bytea) AS IMPLICIT; -CREATE CAST (sys.GEOGRAPHY AS bytea) WITH FUNCTION sys.bytea(sys.GEOGRAPHY) AS IMPLICIT; -CREATE CAST (sys.bbf_varbinary AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.bbf_varbinary) AS IMPLICIT; -CREATE CAST (sys.GEOGRAPHY AS sys.bbf_varbinary) WITH FUNCTION sys.bbf_varbinary(sys.GEOGRAPHY) AS IMPLICIT; +CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.bbf_binary) + RETURNS sys.GEOGRAPHY + AS $$ + DECLARE + varBin sys.bbf_varbinary; + BEGIN + varBin := (SELECT CAST (CAST ($1 AS sys.VARCHAR) AS sys.bbf_varbinary)); + -- Call the underlying function after preprocessing + RETURN (SELECT sys.GEOGRAPHY(varBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.GEOMETRY) +CREATE OR REPLACE FUNCTION sys.text(sys.GEOGRAPHY) + RETURNS text + AS $$ + BEGIN + RAISE EXCEPTION 'Explicit Conversion from data type sys.Geography to Text is not allowed.'; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(text, integer, boolean) RETURNS sys.GEOGRAPHY - AS '$libdir/postgis-3','geography_from_geometry' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + AS $$ + BEGIN + IF $3 = true THEN + RAISE EXCEPTION 'Explicit Conversion from data type Text to sys.Geography is not allowed.'; + ELSE + RAISE EXCEPTION 'Implicit Conversion from data type Text to sys.Geography is not allowed.'; + END IF; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE CAST (sys.GEOMETRY AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.GEOMETRY) AS ASSIGNMENT; +CREATE OR REPLACE FUNCTION sys.bpchar(sys.GEOGRAPHY) + RETURNS sys.bpchar + AS $$ + BEGIN + -- Call the underlying function after preprocessing + -- Here we are flipping the coordinates since Geography Datatype stores the point from STGeomFromText and STPointFromText in Reverse Order i.e. (long, lat) + RETURN sys.bpchar((SELECT sys.STAsText_helper(sys.Geography__STFlipCoordinates($1)))); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.GEOGRAPHY) - RETURNS sys.GEOMETRY - AS '$libdir/postgis-3','geometry_from_geography' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.bpchar) + RETURNS sys.GEOGRAPHY + AS $$ + DECLARE + geog sys.GEOGRAPHY; + BEGIN + geog := (SELECT sys.bpcharToGeography_helper($1)); + -- Call the underlying function after preprocessing + -- Here we are flipping the coordinates since Geography Datatype stores the point from STGeomFromText and STPointFromText in Reverse Order i.e. (long, lat) + RETURN (SELECT sys.Geography__STFlipCoordinates(geog)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.varchar(sys.GEOGRAPHY) + RETURNS sys.varchar + AS $$ + BEGIN + -- Call the underlying function after preprocessing + -- Here we are flipping the coordinates since Geography Datatype stores the point from STGeomFromText and STPointFromText in Reverse Order i.e. (long, lat) + RETURN sys.varchar((SELECT sys.STAsText_helper(sys.Geography__STFlipCoordinates($1)))); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.varchar) + RETURNS sys.GEOGRAPHY + AS $$ + DECLARE + geog sys.GEOGRAPHY; + BEGIN + geog := (SELECT sys.varcharToGeography_helper($1)); + -- Call the underlying function after preprocessing + -- Here we are flipping the coordinates since Geography Datatype stores the point from STGeomFromText and STPointFromText in Reverse Order i.e. (long, lat) + RETURN (SELECT sys.Geography__STFlipCoordinates(geog)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE CAST (sys.GEOGRAPHY AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.GEOGRAPHY) AS ASSIGNMENT; +CREATE CAST (text AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(text, integer, boolean) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS text) WITH FUNCTION sys.text(sys.GEOGRAPHY); +CREATE CAST (sys.bpchar AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.bpchar) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS sys.bpchar) WITH FUNCTION sys.bpchar(sys.GEOGRAPHY); +CREATE CAST (sys.varchar AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.varchar) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS sys.varchar) WITH FUNCTION sys.varchar(sys.GEOGRAPHY); +CREATE CAST (sys.bbf_binary AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.bbf_binary) AS IMPLICIT; +CREATE CAST (bytea AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(bytea) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS bytea) WITH FUNCTION sys.bytea(sys.GEOGRAPHY); +CREATE CAST (sys.bbf_varbinary AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.bbf_varbinary) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS sys.bbf_varbinary) WITH FUNCTION sys.bbf_varbinary(sys.GEOGRAPHY); -- This Function Flips the Coordinates of the Point (x, y) -> (y, x) CREATE OR REPLACE FUNCTION sys.Geography__STFlipCoordinates(sys.GEOGRAPHY) @@ -329,6 +420,47 @@ CREATE OR REPLACE FUNCTION sys.ST_zmflag(sys.GEOGRAPHY) AS '$libdir/postgis-3', 'LWGEOM_zmflag' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE FUNCTION sys.ST_Equals(leftarg sys.GEOGRAPHY, rightarg sys.GEOGRAPHY) + RETURNS boolean + AS $$ + DECLARE + leftvarBin sys.bbf_varbinary; + rightvarBin sys.bbf_varbinary; + BEGIN + leftvarBin := (SELECT sys.bbf_varbinary($1)); + rightvarBin := (SELECT sys.bbf_varbinary($2)); + RETURN (SELECT sys.varbinary_eq(leftvarBin, rightvarBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OPERATOR sys.= ( + LEFTARG = sys.GEOGRAPHY, + RIGHTARG = sys.GEOGRAPHY, + FUNCTION = sys.ST_Equals, + COMMUTATOR = =, + RESTRICT = eqsel +); + +CREATE FUNCTION sys.ST_NotEquals(leftarg sys.GEOGRAPHY, rightarg sys.GEOGRAPHY) + RETURNS boolean + AS $$ + DECLARE + leftvarBin sys.bbf_varbinary; + rightvarBin sys.bbf_varbinary; + BEGIN + leftvarBin := (SELECT sys.bbf_varbinary($1)); + rightvarBin := (SELECT sys.bbf_varbinary($2)); + RETURN (SELECT sys.varbinary_neq(leftvarBin, rightvarBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OPERATOR sys.<> ( + LEFTARG = sys.GEOGRAPHY, + RIGHTARG = sys.GEOGRAPHY, + FUNCTION = sys.ST_NotEquals, + COMMUTATOR = <> +); + -- Minimum distance CREATE OR REPLACE FUNCTION sys.STDistance(geog1 sys.GEOGRAPHY, geog2 sys.GEOGRAPHY) RETURNS float8 @@ -386,3 +518,18 @@ CREATE OR REPLACE FUNCTION sys.GEOGRAPHY_helper(bytea) AS '$libdir/postgis-3','geography_from_binary' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE OR REPLACE FUNCTION sys.bpcharToGeography_helper(sys.bpchar) + RETURNS sys.GEOGRAPHY + AS '$libdir/postgis-3','geography_from_text' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.varcharToGeography_helper(sys.varchar) + RETURNS sys.GEOGRAPHY + AS '$libdir/postgis-3','geography_from_text' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.bytea_helper(sys.GEOGRAPHY) + RETURNS bytea + AS '$libdir/postgis-3','LWGEOM_to_bytea' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + diff --git a/contrib/babelfishpg_common/sql/geometry.sql b/contrib/babelfishpg_common/sql/geometry.sql index 1f7772b3ed..f87fe16744 100644 --- a/contrib/babelfishpg_common/sql/geometry.sql +++ b/contrib/babelfishpg_common/sql/geometry.sql @@ -104,7 +104,30 @@ CREATE OR REPLACE FUNCTION sys.STAsText(sys.GEOMETRY) CREATE OR REPLACE FUNCTION sys.text(sys.GEOMETRY) RETURNS text - AS '$libdir/postgis-3','LWGEOM_to_text' + AS $$ + BEGIN + RAISE EXCEPTION 'Explicit Conversion from data type sys.Geometry to Text is not allowed.'; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.bpchar(sys.GEOMETRY) + RETURNS sys.bpchar + AS '$libdir/postgis-3','LWGEOM_asText' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.bpchar) + RETURNS sys.GEOMETRY + AS '$libdir/postgis-3','parse_WKT_lwgeom' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.varchar(sys.GEOMETRY) + RETURNS sys.varchar + AS '$libdir/postgis-3','LWGEOM_asText' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.varchar) + RETURNS sys.GEOMETRY + AS '$libdir/postgis-3','parse_WKT_lwgeom' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.GEOMETRY(bytea) @@ -155,38 +178,76 @@ CREATE OR REPLACE FUNCTION sys.GEOMETRY(bytea) $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.bytea(sys.GEOMETRY) - RETURNS bytea - AS '$libdir/postgis-3','LWGEOM_to_bytea' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + RETURNS bytea + AS $$ + DECLARE + byte bytea; + BEGIN + byte := (SELECT sys.bytea_helper($1)); + byte := substring(byte from 6); + byte := substring(byte from 1 for 4) || E'\\x010c' || substring(byte from 5); + RETURN byte; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.bbf_varbinary) - RETURNS sys.GEOMETRY - AS $$ - DECLARE + RETURNS sys.GEOMETRY + AS $$ + DECLARE varBin bytea; - BEGIN - varBin := (SELECT CAST ($1 AS bytea)); - -- Call the underlying function after preprocessing - RETURN (SELECT CAST (varBin AS GEOMETRY)); - END; - $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + BEGIN + varBin := (SELECT CAST ($1 AS bytea)); + -- Call the underlying function after preprocessing + RETURN (SELECT sys.GEOMETRY(varBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.bbf_varbinary(sys.GEOMETRY) - RETURNS sys.bbf_varbinary - AS '$libdir/postgis-3','LWGEOM_to_bytea' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + RETURNS sys.bbf_varbinary + AS $$ + DECLARE + byte bytea; + BEGIN + byte := (SELECT sys.bytea($1)); + RETURN (SELECT CAST (byte AS sys.bbf_varbinary)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.bbf_binary) + RETURNS sys.GEOMETRY + AS $$ + DECLARE + varBin sys.bbf_varbinary; + BEGIN + varBin := (SELECT CAST (CAST ($1 AS sys.VARCHAR) AS sys.bbf_varbinary)); + -- Call the underlying function after preprocessing + RETURN (SELECT sys.GEOMETRY(varBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE OR REPLACE FUNCTION sys.GEOMETRY(text) +CREATE OR REPLACE FUNCTION sys.GEOMETRY(text, integer, boolean) RETURNS sys.GEOMETRY - AS '$libdir/postgis-3','parse_WKT_lwgeom' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + AS $$ + BEGIN + IF $3 = true THEN + RAISE EXCEPTION 'Explicit Conversion from data type Text to sys.Geometry is not allowed.'; + ELSE + RAISE EXCEPTION 'Implicit Conversion from data type Text to sys.Geometry is not allowed.'; + END IF; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE CAST (text AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(text) AS IMPLICIT; -CREATE CAST (sys.GEOMETRY AS text) WITH FUNCTION sys.text(sys.GEOMETRY) AS IMPLICIT; +CREATE CAST (text AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(text, integer, boolean) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS text) WITH FUNCTION sys.text(sys.GEOMETRY); +CREATE CAST (sys.bpchar AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.bpchar) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS sys.bpchar) WITH FUNCTION sys.bpchar(sys.GEOMETRY); +CREATE CAST (sys.varchar AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.varchar) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS sys.varchar) WITH FUNCTION sys.varchar(sys.GEOMETRY); CREATE CAST (bytea AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(bytea) AS IMPLICIT; -CREATE CAST (sys.GEOMETRY AS bytea) WITH FUNCTION sys.bytea(sys.GEOMETRY) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS bytea) WITH FUNCTION sys.bytea(sys.GEOMETRY); CREATE CAST (sys.bbf_varbinary AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.bbf_varbinary) AS IMPLICIT; -CREATE CAST (sys.GEOMETRY AS sys.bbf_varbinary) WITH FUNCTION sys.bbf_varbinary(sys.GEOMETRY) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS sys.bbf_varbinary) WITH FUNCTION sys.bbf_varbinary(sys.GEOMETRY); +CREATE CAST (sys.bbf_binary AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.bbf_binary) AS IMPLICIT; -- Availability: 3.2.0 current supported in APG CREATE OR REPLACE FUNCTION sys.Geometry__Point(float8, float8, srid integer) @@ -248,6 +309,47 @@ CREATE OR REPLACE FUNCTION sys.ST_zmflag(sys.GEOMETRY) AS '$libdir/postgis-3', 'LWGEOM_zmflag' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE FUNCTION sys.ST_Equals(leftarg sys.GEOMETRY, rightarg sys.GEOMETRY) + RETURNS boolean + AS $$ + DECLARE + leftvarBin sys.bbf_varbinary; + rightvarBin sys.bbf_varbinary; + BEGIN + leftvarBin := (SELECT sys.bbf_varbinary($1)); + rightvarBin := (SELECT sys.bbf_varbinary($2)); + RETURN (SELECT sys.varbinary_eq(leftvarBin, rightvarBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OPERATOR sys.= ( + LEFTARG = sys.GEOMETRY, + RIGHTARG = sys.GEOMETRY, + FUNCTION = sys.ST_Equals, + COMMUTATOR = =, + RESTRICT = eqsel +); + +CREATE FUNCTION sys.ST_NotEquals(leftarg sys.GEOMETRY, rightarg sys.GEOMETRY) + RETURNS boolean + AS $$ + DECLARE + leftvarBin sys.bbf_varbinary; + rightvarBin sys.bbf_varbinary; + BEGIN + leftvarBin := (SELECT sys.bbf_varbinary($1)); + rightvarBin := (SELECT sys.bbf_varbinary($2)); + RETURN (SELECT sys.varbinary_neq(leftvarBin, rightvarBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OPERATOR sys.<> ( + LEFTARG = sys.GEOMETRY, + RIGHTARG = sys.GEOMETRY, + FUNCTION = sys.ST_NotEquals, + COMMUTATOR = <> +); + -- Minimum distance. 2D only. CREATE OR REPLACE FUNCTION sys.STDistance(geom1 sys.GEOMETRY, geom2 sys.GEOMETRY) RETURNS float8 @@ -280,3 +382,8 @@ CREATE OR REPLACE FUNCTION sys.GEOMETRY_helper(bytea) AS '$libdir/postgis-3','LWGEOM_from_bytea' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE OR REPLACE FUNCTION sys.bytea_helper(sys.GEOMETRY) + RETURNS bytea + AS '$libdir/postgis-3','LWGEOM_to_bytea' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + diff --git a/contrib/babelfishpg_common/sql/upgrades/spatial_types--3.2.0--3.3.0.sql b/contrib/babelfishpg_common/sql/upgrades/spatial_types--3.2.0--3.3.0.sql index d50f098ab9..f4b1fdcfec 100644 --- a/contrib/babelfishpg_common/sql/upgrades/spatial_types--3.2.0--3.3.0.sql +++ b/contrib/babelfishpg_common/sql/upgrades/spatial_types--3.2.0--3.3.0.sql @@ -108,7 +108,30 @@ CREATE OR REPLACE FUNCTION sys.STAsText(sys.GEOMETRY) CREATE OR REPLACE FUNCTION sys.text(sys.GEOMETRY) RETURNS text - AS '$libdir/postgis-3','LWGEOM_to_text' + AS $$ + BEGIN + RAISE EXCEPTION 'Explicit Conversion from data type sys.Geometry to Text is not allowed.'; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.bpchar(sys.GEOMETRY) + RETURNS sys.bpchar + AS '$libdir/postgis-3','LWGEOM_asText' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.bpchar) + RETURNS sys.GEOMETRY + AS '$libdir/postgis-3','parse_WKT_lwgeom' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.varchar(sys.GEOMETRY) + RETURNS sys.varchar + AS '$libdir/postgis-3','LWGEOM_asText' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.varchar) + RETURNS sys.GEOMETRY + AS '$libdir/postgis-3','parse_WKT_lwgeom' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.GEOMETRY(bytea) @@ -159,38 +182,76 @@ CREATE OR REPLACE FUNCTION sys.GEOMETRY(bytea) $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.bytea(sys.GEOMETRY) - RETURNS bytea - AS '$libdir/postgis-3','LWGEOM_to_bytea' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + RETURNS bytea + AS $$ + DECLARE + byte bytea; + BEGIN + byte := (SELECT sys.bytea_helper($1)); + byte := substring(byte from 6); + byte := substring(byte from 1 for 4) || E'\\x010c' || substring(byte from 5); + RETURN byte; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.bbf_varbinary) - RETURNS sys.GEOMETRY - AS $$ - DECLARE + RETURNS sys.GEOMETRY + AS $$ + DECLARE varBin bytea; - BEGIN - varBin := (SELECT CAST ($1 AS bytea)); - -- Call the underlying function after preprocessing - RETURN (SELECT CAST (varBin AS GEOMETRY)); - END; - $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + BEGIN + varBin := (SELECT CAST ($1 AS bytea)); + -- Call the underlying function after preprocessing + RETURN (SELECT sys.GEOMETRY(varBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.bbf_varbinary(sys.GEOMETRY) - RETURNS sys.bbf_varbinary - AS '$libdir/postgis-3','LWGEOM_to_bytea' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + RETURNS sys.bbf_varbinary + AS $$ + DECLARE + byte bytea; + BEGIN + byte := (SELECT sys.bytea($1)); + RETURN (SELECT CAST (byte AS sys.bbf_varbinary)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.bbf_binary) + RETURNS sys.GEOMETRY + AS $$ + DECLARE + varBin sys.bbf_varbinary; + BEGIN + varBin := (SELECT CAST (CAST ($1 AS sys.VARCHAR) AS sys.bbf_varbinary)); + -- Call the underlying function after preprocessing + RETURN (SELECT sys.GEOMETRY(varBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE OR REPLACE FUNCTION sys.GEOMETRY(text) +CREATE OR REPLACE FUNCTION sys.GEOMETRY(text, integer, boolean) RETURNS sys.GEOMETRY - AS '$libdir/postgis-3','parse_WKT_lwgeom' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + AS $$ + BEGIN + IF $3 = true THEN + RAISE EXCEPTION 'Explicit Conversion from data type Text to sys.Geometry is not allowed.'; + ELSE + RAISE EXCEPTION 'Implicit Conversion from data type Text to sys.Geometry is not allowed.'; + END IF; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE CAST (text AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(text) AS IMPLICIT; -CREATE CAST (sys.GEOMETRY AS text) WITH FUNCTION sys.text(sys.GEOMETRY) AS IMPLICIT; +CREATE CAST (text AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(text, integer, boolean) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS text) WITH FUNCTION sys.text(sys.GEOMETRY); +CREATE CAST (sys.bpchar AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.bpchar) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS sys.bpchar) WITH FUNCTION sys.bpchar(sys.GEOMETRY); +CREATE CAST (sys.varchar AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.varchar) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS sys.varchar) WITH FUNCTION sys.varchar(sys.GEOMETRY); CREATE CAST (bytea AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(bytea) AS IMPLICIT; -CREATE CAST (sys.GEOMETRY AS bytea) WITH FUNCTION sys.bytea(sys.GEOMETRY) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS bytea) WITH FUNCTION sys.bytea(sys.GEOMETRY); CREATE CAST (sys.bbf_varbinary AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.bbf_varbinary) AS IMPLICIT; -CREATE CAST (sys.GEOMETRY AS sys.bbf_varbinary) WITH FUNCTION sys.bbf_varbinary(sys.GEOMETRY) AS IMPLICIT; +CREATE CAST (sys.GEOMETRY AS sys.bbf_varbinary) WITH FUNCTION sys.bbf_varbinary(sys.GEOMETRY); +CREATE CAST (sys.bbf_binary AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.bbf_binary) AS IMPLICIT; -- Availability: 3.2.0 current supported in APG CREATE OR REPLACE FUNCTION sys.Geometry__Point(float8, float8, srid integer) @@ -252,6 +313,47 @@ CREATE OR REPLACE FUNCTION sys.ST_zmflag(sys.GEOMETRY) AS '$libdir/postgis-3', 'LWGEOM_zmflag' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE FUNCTION sys.ST_Equals(leftarg sys.GEOMETRY, rightarg sys.GEOMETRY) + RETURNS boolean + AS $$ + DECLARE + leftvarBin sys.bbf_varbinary; + rightvarBin sys.bbf_varbinary; + BEGIN + leftvarBin := (SELECT sys.bbf_varbinary($1)); + rightvarBin := (SELECT sys.bbf_varbinary($2)); + RETURN (SELECT sys.varbinary_eq(leftvarBin, rightvarBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OPERATOR sys.= ( + LEFTARG = sys.GEOMETRY, + RIGHTARG = sys.GEOMETRY, + FUNCTION = sys.ST_Equals, + COMMUTATOR = =, + RESTRICT = eqsel +); + +CREATE FUNCTION sys.ST_NotEquals(leftarg sys.GEOMETRY, rightarg sys.GEOMETRY) + RETURNS boolean + AS $$ + DECLARE + leftvarBin sys.bbf_varbinary; + rightvarBin sys.bbf_varbinary; + BEGIN + leftvarBin := (SELECT sys.bbf_varbinary($1)); + rightvarBin := (SELECT sys.bbf_varbinary($2)); + RETURN (SELECT sys.varbinary_neq(leftvarBin, rightvarBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OPERATOR sys.<> ( + LEFTARG = sys.GEOMETRY, + RIGHTARG = sys.GEOMETRY, + FUNCTION = sys.ST_NotEquals, + COMMUTATOR = <> +); + -- Minimum distance. 2D only. CREATE OR REPLACE FUNCTION sys.STDistance(geom1 sys.GEOMETRY, geom2 sys.GEOMETRY) RETURNS float8 @@ -284,6 +386,11 @@ CREATE OR REPLACE FUNCTION sys.GEOMETRY_helper(bytea) AS '$libdir/postgis-3','LWGEOM_from_bytea' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE OR REPLACE FUNCTION sys.bytea_helper(sys.GEOMETRY) + RETURNS bytea + AS '$libdir/postgis-3','LWGEOM_to_bytea' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + CREATE OR REPLACE FUNCTION sys.geographyin(cstring, oid, integer) RETURNS sys.GEOGRAPHY AS '$libdir/postgis-3','geography_in' @@ -438,8 +545,22 @@ CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(bytea) CREATE OR REPLACE FUNCTION sys.bytea(sys.GEOGRAPHY) RETURNS bytea - AS '$libdir/postgis-3','LWGEOM_to_bytea' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + AS $$ + DECLARE + byte bytea; + BEGIN + -- Here the received bytes are -> 1 byte (endianness) + 4 bytes (type) + 4 bytes (SRID) + 16 bytes * npoints + byte := (SELECT sys.bytea_helper($1)); + -- Checking the Geometry type currently we support only POINT type -> type = 1 (01000020 [here last byte represents presence of SRID]) + IF encode(substring(byte from 2 for 4), 'hex') = encode(E'\\x01000020', 'hex') THEN + -- Here we are taking bytes from SRID only for driver expected format -> 4 bytes (SRID) + 16 bytes * npoints + byte := substring(byte from 6); + -- The drivers expected format is 4 bytes (SRID) + 2 bytes (type -> 010C for point) + 16 bytes * npoints + byte := substring(byte from 1 for 4) || E'\\x010c' || substring(byte from 5); + END IF; + RETURN byte; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.bbf_varbinary) RETURNS sys.GEOGRAPHY @@ -449,33 +570,110 @@ CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.bbf_varbinary) BEGIN varBin := (SELECT CAST ($1 AS bytea)); -- Call the underlying function after preprocessing - RETURN (SELECT CAST (varBin AS GEOGRAPHY)); + RETURN (SELECT sys.GEOGRAPHY(varBin)); END; $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; CREATE OR REPLACE FUNCTION sys.bbf_varbinary(sys.GEOGRAPHY) RETURNS sys.bbf_varbinary - AS '$libdir/postgis-3','LWGEOM_to_bytea' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + AS $$ + DECLARE + byte bytea; + BEGIN + byte := (SELECT sys.bytea($1)); + RETURN (SELECT CAST (byte AS sys.bbf_varbinary)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE CAST (bytea AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(bytea) AS IMPLICIT; -CREATE CAST (sys.GEOGRAPHY AS bytea) WITH FUNCTION sys.bytea(sys.GEOGRAPHY) AS IMPLICIT; -CREATE CAST (sys.bbf_varbinary AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.bbf_varbinary) AS IMPLICIT; -CREATE CAST (sys.GEOGRAPHY AS sys.bbf_varbinary) WITH FUNCTION sys.bbf_varbinary(sys.GEOGRAPHY) AS IMPLICIT; +CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.bbf_binary) + RETURNS sys.GEOGRAPHY + AS $$ + DECLARE + varBin sys.bbf_varbinary; + BEGIN + varBin := (SELECT CAST (CAST ($1 AS sys.VARCHAR) AS sys.bbf_varbinary)); + -- Call the underlying function after preprocessing + RETURN (SELECT sys.GEOGRAPHY(varBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.text(sys.GEOGRAPHY) + RETURNS text + AS $$ + BEGIN + RAISE EXCEPTION 'Explicit Conversion from data type sys.Geography to Text is not allowed.'; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.GEOMETRY) +CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(text, integer, boolean) RETURNS sys.GEOGRAPHY - AS '$libdir/postgis-3','geography_from_geometry' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + AS $$ + BEGIN + IF $3 = true THEN + RAISE EXCEPTION 'Explicit Conversion from data type Text to sys.Geography is not allowed.'; + ELSE + RAISE EXCEPTION 'Implicit Conversion from data type Text to sys.Geography is not allowed.'; + END IF; + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE CAST (sys.GEOMETRY AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.GEOMETRY) AS ASSIGNMENT; +CREATE OR REPLACE FUNCTION sys.bpchar(sys.GEOGRAPHY) + RETURNS sys.bpchar + AS $$ + BEGIN + -- Call the underlying function after preprocessing + -- Here we are flipping the coordinates since Geography Datatype stores the point from STGeomFromText and STPointFromText in Reverse Order i.e. (long, lat) + RETURN sys.bpchar((SELECT sys.STAsText_helper(sys.Geography__STFlipCoordinates($1)))); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE OR REPLACE FUNCTION sys.GEOMETRY(sys.GEOGRAPHY) - RETURNS sys.GEOMETRY - AS '$libdir/postgis-3','geometry_from_geography' - LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.bpchar) + RETURNS sys.GEOGRAPHY + AS $$ + DECLARE + geog sys.GEOGRAPHY; + BEGIN + geog := (SELECT sys.bpcharToGeography_helper($1)); + -- Call the underlying function after preprocessing + -- Here we are flipping the coordinates since Geography Datatype stores the point from STGeomFromText and STPointFromText in Reverse Order i.e. (long, lat) + RETURN (SELECT sys.Geography__STFlipCoordinates(geog)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; -CREATE CAST (sys.GEOGRAPHY AS sys.GEOMETRY) WITH FUNCTION sys.GEOMETRY(sys.GEOGRAPHY) AS ASSIGNMENT; +CREATE OR REPLACE FUNCTION sys.varchar(sys.GEOGRAPHY) + RETURNS sys.varchar + AS $$ + BEGIN + -- Call the underlying function after preprocessing + -- Here we are flipping the coordinates since Geography Datatype stores the point from STGeomFromText and STPointFromText in Reverse Order i.e. (long, lat) + RETURN sys.varchar((SELECT sys.STAsText_helper(sys.Geography__STFlipCoordinates($1)))); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.GEOGRAPHY(sys.varchar) + RETURNS sys.GEOGRAPHY + AS $$ + DECLARE + geog sys.GEOGRAPHY; + BEGIN + geog := (SELECT sys.varcharToGeography_helper($1)); + -- Call the underlying function after preprocessing + -- Here we are flipping the coordinates since Geography Datatype stores the point from STGeomFromText and STPointFromText in Reverse Order i.e. (long, lat) + RETURN (SELECT sys.Geography__STFlipCoordinates(geog)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE CAST (text AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(text, integer, boolean) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS text) WITH FUNCTION sys.text(sys.GEOGRAPHY); +CREATE CAST (sys.bpchar AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.bpchar) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS sys.bpchar) WITH FUNCTION sys.bpchar(sys.GEOGRAPHY); +CREATE CAST (sys.varchar AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.varchar) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS sys.varchar) WITH FUNCTION sys.varchar(sys.GEOGRAPHY); +CREATE CAST (sys.bbf_binary AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.bbf_binary) AS IMPLICIT; +CREATE CAST (bytea AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(bytea) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS bytea) WITH FUNCTION sys.bytea(sys.GEOGRAPHY); +CREATE CAST (sys.bbf_varbinary AS sys.GEOGRAPHY) WITH FUNCTION sys.GEOGRAPHY(sys.bbf_varbinary) AS IMPLICIT; +CREATE CAST (sys.GEOGRAPHY AS sys.bbf_varbinary) WITH FUNCTION sys.bbf_varbinary(sys.GEOGRAPHY); -- This Function Flips the Coordinates of the Point (x, y) -> (y, x) CREATE OR REPLACE FUNCTION sys.Geography__STFlipCoordinates(sys.GEOGRAPHY) @@ -615,6 +813,47 @@ CREATE OR REPLACE FUNCTION sys.ST_zmflag(sys.GEOGRAPHY) AS '$libdir/postgis-3', 'LWGEOM_zmflag' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; +CREATE FUNCTION sys.ST_Equals(leftarg sys.GEOGRAPHY, rightarg sys.GEOGRAPHY) + RETURNS boolean + AS $$ + DECLARE + leftvarBin sys.bbf_varbinary; + rightvarBin sys.bbf_varbinary; + BEGIN + leftvarBin := (SELECT sys.bbf_varbinary($1)); + rightvarBin := (SELECT sys.bbf_varbinary($2)); + RETURN (SELECT sys.varbinary_eq(leftvarBin, rightvarBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OPERATOR sys.= ( + LEFTARG = sys.GEOGRAPHY, + RIGHTARG = sys.GEOGRAPHY, + FUNCTION = sys.ST_Equals, + COMMUTATOR = =, + RESTRICT = eqsel +); + +CREATE FUNCTION sys.ST_NotEquals(leftarg sys.GEOGRAPHY, rightarg sys.GEOGRAPHY) + RETURNS boolean + AS $$ + DECLARE + leftvarBin sys.bbf_varbinary; + rightvarBin sys.bbf_varbinary; + BEGIN + leftvarBin := (SELECT sys.bbf_varbinary($1)); + rightvarBin := (SELECT sys.bbf_varbinary($2)); + RETURN (SELECT sys.varbinary_neq(leftvarBin, rightvarBin)); + END; + $$ LANGUAGE plpgsql IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OPERATOR sys.<> ( + LEFTARG = sys.GEOGRAPHY, + RIGHTARG = sys.GEOGRAPHY, + FUNCTION = sys.ST_NotEquals, + COMMUTATOR = <> +); + -- Minimum distance CREATE OR REPLACE FUNCTION sys.STDistance(geog1 sys.GEOGRAPHY, geog2 sys.GEOGRAPHY) RETURNS float8 @@ -671,3 +910,18 @@ CREATE OR REPLACE FUNCTION sys.GEOGRAPHY_helper(bytea) RETURNS sys.GEOGRAPHY AS '$libdir/postgis-3','geography_from_binary' LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.bpcharToGeography_helper(sys.bpchar) + RETURNS sys.GEOGRAPHY + AS '$libdir/postgis-3','geography_from_text' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.varcharToGeography_helper(sys.varchar) + RETURNS sys.GEOGRAPHY + AS '$libdir/postgis-3','geography_from_text' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; + +CREATE OR REPLACE FUNCTION sys.bytea_helper(sys.GEOGRAPHY) + RETURNS bytea + AS '$libdir/postgis-3','LWGEOM_to_bytea' + LANGUAGE 'c' IMMUTABLE STRICT PARALLEL SAFE; diff --git a/test/JDBC/expected/TestSpatialPoint-vu-cleanup.out b/test/JDBC/expected/TestSpatialPoint-vu-cleanup.out index 5ad69e2c46..cfd1c8615f 100644 --- a/test/JDBC/expected/TestSpatialPoint-vu-cleanup.out +++ b/test/JDBC/expected/TestSpatialPoint-vu-cleanup.out @@ -4,6 +4,8 @@ DROP VIEW IF EXISTS BinaryFromGeom DROP VIEW IF EXISTS CoordsFromGeom +DROP VIEW IF EXISTS equal_geom + DROP VIEW IF EXISTS point_distances_geom DROP VIEW IF EXISTS TextFromGeog @@ -14,14 +16,32 @@ DROP VIEW IF EXISTS CoordsFromGeog DROP VIEW IF EXISTS TransformFromGeog +DROP VIEW IF EXISTS equal_geog + DROP VIEW IF EXISTS point_distances_geog DROP TABLE IF EXISTS SPATIALPOINTGEOM_dt +DROP TABLE IF EXISTS GeomToVarbinary + +DROP TABLE IF EXISTS GeomTochar + +DROP TABLE IF EXISTS GeomToVarchar + +DROP TABLE IF EXISTS TypeToGeom + DROP TABLE IF EXISTS TypeTable DROP TYPE IF EXISTS geom DROP TABLE IF EXISTS SPATIALPOINTGEOG_dt +DROP TABLE IF EXISTS GeogToVarbinary + +DROP TABLE IF EXISTS GeogTochar + +DROP TABLE IF EXISTS GeogToVarchar + +DROP TABLE IF EXISTS TypeToGeog + DROP TABLE IF EXISTS SPATIALPOINT_dt diff --git a/test/JDBC/expected/TestSpatialPoint-vu-prepare.out b/test/JDBC/expected/TestSpatialPoint-vu-prepare.out index d3c1cda6a0..e644e6d4de 100644 --- a/test/JDBC/expected/TestSpatialPoint-vu-prepare.out +++ b/test/JDBC/expected/TestSpatialPoint-vu-prepare.out @@ -121,26 +121,6 @@ prepst#!#exec#!#GEOMETRY|-|location|-|LINESTRING(1 2, 3 4):4326 ~~ERROR (Message: Unsupported geometry type)~~ -#Negative Test for STGeomFromText when invalid type is provided -prepst#!#exec#!#GEOMETRY|-|location|-|Pnt:4326 -~~ERROR (Code: 0)~~ - -~~ERROR (Message: Illegal character in Well-Known text at position 3.)~~ - -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: Unsupported geometry type)~~ - -#Negative Test for STGeomFromText when Null geometry is provided -prepst#!#exec#!#GEOMETRY|-|location|-|:4326 -~~ERROR (Code: 0)~~ - -~~ERROR (Message: Illegal character in Well-Known text at position 0.)~~ - -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: Unsupported geometry type)~~ - CREATE VIEW TextFromGeom AS SELECT STAsText(location) AS TextRepresentation FROM SPATIALPOINTGEOM_dt; @@ -148,6 +128,8 @@ CREATE VIEW BinaryFromGeom AS SELECT STAsBinary(location) AS BinaryRepresentatio CREATE VIEW CoordsFromGeom AS SELECT STX(location), STY(location) AS Coordinates FROM SPATIALPOINTGEOM_dt; +CREATE VIEW equal_geom AS SELECT p1.location AS point FROM SPATIALPOINTGEOM_dt p1 CROSS JOIN SPATIALPOINTGEOM_dt p2 WHERE p1.location = p2.location; + CREATE VIEW point_distances_geom AS SELECT p1.location AS point1, p2.location AS point2, STDistance( p1.location, p2.location ) AS distance FROM SPATIALPOINTGEOM_dt p1 CROSS JOIN SPATIALPOINTGEOM_dt p2 WHERE p1.location <> p2.location; CREATE TABLE SPATIALPOINTGEOG_dt (location geography) @@ -162,6 +144,38 @@ INSERT INTO TypeTable(ID, Shape) VALUES(1, geometry::Point(1, 2, 4326)); ~~ROW COUNT: 1~~ +#Testing Implicit CASTs to and from Geometry data type for supported Explicit CASTs +#UnSupported CASTs to and from Geometry data type +CREATE TABLE GeomToVarbinary(p varbinary) +INSERT INTO GeomToVarbinary(p) VALUES(geometry::Point(1, 2, 4326)); +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: column "p" is of type varbinary but expression is of type geometry)~~ + +CREATE TABLE GeomTochar(p char) +INSERT INTO GeomTochar(p) VALUES(geometry::Point(1, 2, 4326)); +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: column "p" is of type bpchar but expression is of type geometry)~~ + +CREATE TABLE GeomToVarchar(p varchar) +INSERT INTO GeomToVarchar(p) VALUES(geometry::Point(1, 2, 4326)); +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: column "p" is of type "varchar" but expression is of type geometry)~~ + +#Supported CASTs to and from Geometry data type +CREATE TABLE TypeToGeom(p geometry) +INSERT INTO TypeToGeom(p) VALUES(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS varbinary(MAX))); +~~ROW COUNT: 1~~ + +INSERT INTO TypeToGeom(p) VALUES(CAST ('POINT(1 2)' AS char)); +~~ROW COUNT: 1~~ + +INSERT INTO TypeToGeom(p) VALUES(CAST ('POINT(1 2)' AS varchar)); +~~ROW COUNT: 1~~ + + #Geography Test Cases #Positive Test for STGeomFromText with SRID 4326 @@ -319,37 +333,51 @@ prepst#!#exec#!#GEOGRAPHY|-|location|-|LINESTRING(1 2, 3 4):4326 ~~ERROR (Message: Unsupported geometry type)~~ -#Negative Test for STGeomFromText when invalid type is provided -prepst#!#exec#!#GEOGRAPHY|-|location|-|Pnt:4326 -~~ERROR (Code: 0)~~ -~~ERROR (Message: Illegal character in Well-Known text at position 3.)~~ +CREATE VIEW TextFromGeog AS SELECT STAsText(location) AS TextRepresentation FROM SPATIALPOINTGEOG_dt; -~~ERROR (Code: 33557097)~~ +CREATE VIEW BinaryFromGeog AS SELECT STAsBinary(location) AS BinaryRepresentation FROM SPATIALPOINTGEOG_dt; -~~ERROR (Message: Unsupported geometry type)~~ +CREATE VIEW CoordsFromGeog AS SELECT long(location), lat(location) AS Coordinates FROM SPATIALPOINTGEOG_dt; + + +CREATE VIEW TransformFromGeog AS SELECT ST_Transform(location, 4326) AS Modified_points FROM SPATIALPOINTGEOG_dt; -#Negative Test for STGeomFromText when Null geography is provided -prepst#!#exec#!#GEOGRAPHY|-|location|-|:4326 -~~ERROR (Code: 0)~~ +CREATE VIEW equal_geog AS SELECT p1.location AS point FROM SPATIALPOINTGEOG_dt p1 CROSS JOIN SPATIALPOINTGEOG_dt p2 WHERE p1.location = p2.location; -~~ERROR (Message: Illegal character in Well-Known text at position 0.)~~ +CREATE VIEW point_distances_geog AS SELECT p1.location AS point1, p2.location AS point2, STDistance( p1.location, p2.location ) AS distance FROM SPATIALPOINTGEOG_dt p1 CROSS JOIN SPATIALPOINTGEOG_dt p2 WHERE p1.location <> p2.location; +#Testing Implicit CASTs to and from Geography data type for supported Explicit CASTs +#UnSupported CASTs to and from Geography data type +CREATE TABLE GeogToVarbinary(p varbinary) +INSERT INTO GeogToVarbinary(p) VALUES(geography::Point(1, 2, 4326)); ~~ERROR (Code: 33557097)~~ -~~ERROR (Message: Unsupported geometry type)~~ +~~ERROR (Message: column "p" is of type varbinary but expression is of type geography)~~ +CREATE TABLE GeogTochar(p char) +INSERT INTO GeogTochar(p) VALUES(geography::Point(1, 2, 4326)); +~~ERROR (Code: 33557097)~~ -CREATE VIEW TextFromGeog AS SELECT STAsText(location) AS TextRepresentation FROM SPATIALPOINTGEOG_dt; +~~ERROR (Message: column "p" is of type bpchar but expression is of type geography)~~ -CREATE VIEW BinaryFromGeog AS SELECT STAsBinary(location) AS BinaryRepresentation FROM SPATIALPOINTGEOG_dt; +CREATE TABLE GeogToVarchar(p varchar) +INSERT INTO GeogToVarchar(p) VALUES(geography::Point(1, 2, 4326)); +~~ERROR (Code: 33557097)~~ -CREATE VIEW CoordsFromGeog AS SELECT long(location), lat(location) AS Coordinates FROM SPATIALPOINTGEOG_dt; +~~ERROR (Message: column "p" is of type "varchar" but expression is of type geography)~~ +#Supported CASTs to and from Geography data type +CREATE TABLE TypeToGeog(p geography) +INSERT INTO TypeToGeog(p) VALUES(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS varbinary(MAX))); +~~ROW COUNT: 1~~ -CREATE VIEW TransformFromGeog AS SELECT ST_Transform(location, 4326) AS Modified_points FROM SPATIALPOINTGEOG_dt; +INSERT INTO TypeToGeog(p) VALUES(CAST ('POINT(1 2)' AS char)); +~~ROW COUNT: 1~~ + +INSERT INTO TypeToGeog(p) VALUES(CAST ('POINT(1 2)' AS varchar)); +~~ROW COUNT: 1~~ -CREATE VIEW point_distances_geog AS SELECT p1.location AS point1, p2.location AS point2, STDistance( p1.location, p2.location ) AS distance FROM SPATIALPOINTGEOG_dt p1 CROSS JOIN SPATIALPOINTGEOG_dt p2 WHERE p1.location <> p2.location; CREATE TABLE SPATIALPOINT_dt (PrimaryKey int, GeomColumn geometry, GeogColumn geography) diff --git a/test/JDBC/expected/TestSpatialPoint-vu-verify.out b/test/JDBC/expected/TestSpatialPoint-vu-verify.out index effe3902e8..9521a1164e 100644 --- a/test/JDBC/expected/TestSpatialPoint-vu-verify.out +++ b/test/JDBC/expected/TestSpatialPoint-vu-verify.out @@ -112,6 +112,42 @@ float#!#float ~~END~~ +SELECT * FROM equal_geom; +GO +~~START~~ +geometry +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C000000000000F03F0000000000000040 +E6100000010C000000000000F03F0000000000000040 +E6100000010C000000000000F03F0000000000000040 +00000000010C17D9CEF753D34740D34D6210585936C0 +00000000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C000000000000F03F0000000000000040 +E6100000010C000000000000F03F0000000000000040 +E6100000010C000000000000F03F0000000000000040 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C000000000000F03F0000000000000040 +E6100000010C000000000000F03F0000000000000040 +E6100000010C000000000000F03F0000000000000040 +00000000010C17D9CEF753D34740D34D6210585936C0 +00000000010C17D9CEF753D34740D34D6210585936C0 +~~END~~ + + SELECT * FROM point_distances_geom; GO ~~START~~ @@ -149,6 +185,265 @@ int#!#geometry ~~END~~ +SELECT * FROM GeomToVarbinary; +GO +~~START~~ +varbinary +~~END~~ + +SELECT * FROM GeomTochar; +GO +~~START~~ +char +~~END~~ + +SELECT * FROM GeomToVarchar; +GO +~~START~~ +varchar +~~END~~ + +SELECT * FROM TypeToGeom; +GO +~~START~~ +geometry +E6100000010C17D9CEF753D34740D34D6210585936C0 +00000000010C000000000000F03F0000000000000040 +00000000010C000000000000F03F0000000000000040 +~~END~~ + + +-- Testing Explicit CASTs to and from Geometry data type +-- Supported CASTs to and from Geometry data type +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS binary) as geometry) +GO +~~START~~ +geometry +E6100000010C17D9CEF753D34740D34D6210585936C0 +~~END~~ + +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS varbinary(MAX)) as geometry) +GO +~~START~~ +geometry +E6100000010C17D9CEF753D34740D34D6210585936C0 +~~END~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS varbinary(MAX)) +GO +~~START~~ +varbinary +E6100000010C000000000000F03F0000000000000040 +~~END~~ + +Select CAST(CAST ('POINT(1 2)' AS char) as geometry) +GO +~~START~~ +geometry +00000000010C000000000000F03F0000000000000040 +~~END~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS char) +GO +~~START~~ +char +POINT(1 2) +~~END~~ + +Select CAST(CAST ('POINT(1 2)' AS nchar) as geometry) +GO +~~START~~ +geometry +00000000010C000000000000F03F0000000000000040 +~~END~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS nchar) +GO +~~START~~ +nchar +POINT(1 2) +~~END~~ + +Select CAST(CAST ('POINT(1 2)' AS varchar) as geometry) +GO +~~START~~ +geometry +00000000010C000000000000F03F0000000000000040 +~~END~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS varchar) +GO +~~START~~ +varchar +POINT(1 2) +~~END~~ + +Select CAST(CAST ('POINT(1 2)' AS nvarchar) as geometry) +GO +~~START~~ +geometry +00000000010C000000000000F03F0000000000000040 +~~END~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS nvarchar) +GO +~~START~~ +nvarchar +POINT(1 2) +~~END~~ + + +-- UnSupported CASTs to and from Geometry data type +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS datetime) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to datetime)~~ + +Select CAST(CAST (0001-01-01 AS datetime) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type datetime to geometry)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS decimal) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to "decimal")~~ + +Select CAST(CAST (20.0 AS decimal) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type "decimal" to geometry)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS bigInt) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to bigint)~~ + +Select CAST(CAST (20 AS bigInt) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type bigint to geometry)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS bigInt) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to bigint)~~ + +Select CAST(CAST (20 AS bigInt) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type bigint to geometry)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS money) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to money)~~ + +Select CAST(CAST ($1 AS money) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type money to geometry)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS bit) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to "bit")~~ + +Select CAST(CAST (1 AS bit) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type "bit" to geometry)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS uniqueidentifier) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to uniqueidentifier)~~ + +Select CAST(CAST ('6F9619FF-8B86-D011-B42D-00C04FC964FF' AS uniqueidentifier) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type uniqueidentifier to geometry)~~ + +Select CAST(CAST ('POINT(1 2)' AS text) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Explicit Conversion from data type Text to sys.Geometry is not allowed.)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS text) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Explicit Conversion from data type sys.Geometry to Text is not allowed.)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS sql_variant) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to sql_variant)~~ + +Select CAST(CAST ('POINT(1 2)' AS sql_variant) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type sql_variant to geometry)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS xml) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to xml)~~ + +Select CAST(CAST ('point(1 2)' AS xml) as geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type xml to geometry)~~ + +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geometry to geography)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS geometry) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to geometry)~~ + + +-- UnSupported CASTs which are currently supported for geometry +-- This is because Image type is created as -> CREATE DOMAIN sys.IMAGE AS sys.BBF_VARBINARY; so it is always converted to it's baseType i.e. varbinary +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS image) +GO +~~START~~ +image +E6100000010C000000000000F03F0000000000000040 +~~END~~ + +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS image) as geometry) +GO +~~START~~ +geometry +E6100000010C17D9CEF753D34740D34D6210585936C0 +~~END~~ + + DECLARE @point geography; SET @point = geography::STGeomFromText('POINT(-122.34900 47.65100)', 4326); SELECT STAsText(@point); @@ -272,13 +567,39 @@ E6100000010C0000000000000040000000000000F03F ~~END~~ +SELECT * FROM equal_geog; +GO +~~START~~ +geography +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010C0000000000000040000000000000F03F +E6100000010C0000000000000040000000000000F03F +E6100000010C0000000000000040000000000000F03F +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010C0000000000000040000000000000F03F +E6100000010C0000000000000040000000000000F03F +E6100000010C0000000000000040000000000000F03F +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010CD34D6210585936C017D9CEF753D34740 +E6100000010C0000000000000040000000000000F03F +E6100000010C0000000000000040000000000000F03F +E6100000010C0000000000000040000000000000F03F +~~END~~ + + SELECT * FROM point_distances_geog; GO ~~START~~ geography#!#geography#!#float E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 -E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C17D9CEF753D34740D34D6210585936C0#!#1.0424362254827898E7 +E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C17D9CEF753D34740D34D6210585936C0#!#1.04243622548279E7 E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 E6100000010C0000000000000040000000000000F03F#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#5736178.674863189 E6100000010C0000000000000040000000000000F03F#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#5736178.674863189 @@ -286,21 +607,21 @@ E6100000010C0000000000000040000000000000F03F#!#E6100000010C17D9CEF753D34740D34D6 E6100000010C0000000000000040000000000000F03F#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#5736178.674863189 E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 -E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C17D9CEF753D34740D34D6210585936C0#!#1.0424362254827898E7 +E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C17D9CEF753D34740D34D6210585936C0#!#1.04243622548279E7 E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 E6100000010C0000000000000040000000000000F03F#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#5736178.674863189 E6100000010C0000000000000040000000000000F03F#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#5736178.674863189 E6100000010C0000000000000040000000000000F03F#!#E6100000010C17D9CEF753D34740D34D6210585936C0#!#5535965.307328846 E6100000010C0000000000000040000000000000F03F#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#5736178.674863189 -E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#1.0424362254827898E7 +E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#1.04243622548279E7 E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010C0000000000000040000000000000F03F#!#5535965.307328846 -E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#1.0424362254827898E7 +E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#1.04243622548279E7 E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010C0000000000000040000000000000F03F#!#5535965.307328846 -E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#1.0424362254827898E7 +E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#1.04243622548279E7 E6100000010C17D9CEF753D34740D34D6210585936C0#!#E6100000010C0000000000000040000000000000F03F#!#5535965.307328846 E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 -E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C17D9CEF753D34740D34D6210585936C0#!#1.0424362254827898E7 +E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C17D9CEF753D34740D34D6210585936C0#!#1.04243622548279E7 E6100000010CD34D6210585936C017D9CEF753D34740#!#E6100000010C0000000000000040000000000000F03F#!#5736178.674863189 E6100000010C0000000000000040000000000000F03F#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#5736178.674863189 E6100000010C0000000000000040000000000000F03F#!#E6100000010CD34D6210585936C017D9CEF753D34740#!#5736178.674863189 @@ -324,6 +645,253 @@ E6100000010C0000000000000040000000000000F03F ~~END~~ +SELECT * FROM GeogToVarbinary; +GO +~~START~~ +varbinary +~~END~~ + +SELECT * FROM GeogTochar; +GO +~~START~~ +char +~~END~~ + +SELECT * FROM GeogToVarchar; +GO +~~START~~ +varchar +~~END~~ + +SELECT * FROM TypeToGeog; +GO +~~START~~ +geography +E6100000010C17D9CEF753D34740D34D6210585936C0 +E6100000010C0000000000000040000000000000F03F +E6100000010C0000000000000040000000000000F03F +~~END~~ + + +-- Testing Explicit CASTs to and from Geography data type +-- Supported CASTs to and from Geography data type +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS binary) as geography) +GO +~~START~~ +geography +E6100000010C17D9CEF753D34740D34D6210585936C0 +~~END~~ + +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS varbinary(MAX)) as geography) +GO +~~START~~ +geography +E6100000010C17D9CEF753D34740D34D6210585936C0 +~~END~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS varbinary(MAX)) +GO +~~START~~ +varbinary +E6100000010C0000000000000040000000000000F03F +~~END~~ + +Select CAST(CAST ('POINT(1 2)' AS char) as geography) +GO +~~START~~ +geography +E6100000010C0000000000000040000000000000F03F +~~END~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS char) +GO +~~START~~ +char +POINT(1 2) +~~END~~ + +Select CAST(CAST ('POINT(1 2)' AS nchar) as geography) +GO +~~START~~ +geography +E6100000010C0000000000000040000000000000F03F +~~END~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS nchar) +GO +~~START~~ +nchar +POINT(1 2) +~~END~~ + +Select CAST(CAST ('POINT(1 2)' AS varchar) as geography) +GO +~~START~~ +geography +E6100000010C0000000000000040000000000000F03F +~~END~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS varchar) +GO +~~START~~ +varchar +POINT(1 2) +~~END~~ + +Select CAST(CAST ('POINT(1 2)' AS nvarchar) as geography) +GO +~~START~~ +geography +E6100000010C0000000000000040000000000000F03F +~~END~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS nvarchar) +GO +~~START~~ +nvarchar +POINT(1 2) +~~END~~ + + +-- UnSupported CASTs to and from Geography data type +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS datetime) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to datetime)~~ + +Select CAST(CAST (0001-01-01 AS datetime) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type datetime to geography)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS decimal) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to "decimal")~~ + +Select CAST(CAST (20.0 AS decimal) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type "decimal" to geography)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS bigInt) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to bigint)~~ + +Select CAST(CAST (20 AS bigInt) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type bigint to geography)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS bigInt) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to bigint)~~ + +Select CAST(CAST (20 AS bigInt) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type bigint to geography)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS money) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to money)~~ + +Select CAST(CAST ($1 AS money) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type money to geography)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS bit) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to "bit")~~ + +Select CAST(CAST (1 AS bit) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type "bit" to geography)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS uniqueidentifier) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to uniqueidentifier)~~ + +Select CAST(CAST ('6F9619FF-8B86-D011-B42D-00C04FC964FF' AS uniqueidentifier) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type uniqueidentifier to geography)~~ + +Select CAST(CAST ('POINT(1 2)' AS text) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Explicit Conversion from data type Text to sys.Geography is not allowed.)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS text) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Explicit Conversion from data type sys.Geography to Text is not allowed.)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS sql_variant) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to sql_variant)~~ + +Select CAST(CAST ('POINT(1 2)' AS sql_variant) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type sql_variant to geography)~~ + +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS xml) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type geography to xml)~~ + +Select CAST(CAST ('point(1 2)' AS xml) as geography) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: cannot cast type xml to geography)~~ + + +-- UnSupported CASTs which are currently supported for geography +-- This is because Image type is created as -> CREATE DOMAIN sys.IMAGE AS sys.BBF_VARBINARY; so it is always converted to it's baseType i.e. varbinary +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS image) +GO +~~START~~ +image +E6100000010C0000000000000040000000000000F03F +~~END~~ + +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS image) as geography) +GO +~~START~~ +geography +E6100000010C17D9CEF753D34740D34D6210585936C0 +~~END~~ + + SELECT * FROM SPATIALPOINT_dt; GO ~~START~~ diff --git a/test/JDBC/input/datatypes/TestSpatialPoint-vu-cleanup.txt b/test/JDBC/input/datatypes/TestSpatialPoint-vu-cleanup.txt index 5ad69e2c46..cfd1c8615f 100644 --- a/test/JDBC/input/datatypes/TestSpatialPoint-vu-cleanup.txt +++ b/test/JDBC/input/datatypes/TestSpatialPoint-vu-cleanup.txt @@ -4,6 +4,8 @@ DROP VIEW IF EXISTS BinaryFromGeom DROP VIEW IF EXISTS CoordsFromGeom +DROP VIEW IF EXISTS equal_geom + DROP VIEW IF EXISTS point_distances_geom DROP VIEW IF EXISTS TextFromGeog @@ -14,14 +16,32 @@ DROP VIEW IF EXISTS CoordsFromGeog DROP VIEW IF EXISTS TransformFromGeog +DROP VIEW IF EXISTS equal_geog + DROP VIEW IF EXISTS point_distances_geog DROP TABLE IF EXISTS SPATIALPOINTGEOM_dt +DROP TABLE IF EXISTS GeomToVarbinary + +DROP TABLE IF EXISTS GeomTochar + +DROP TABLE IF EXISTS GeomToVarchar + +DROP TABLE IF EXISTS TypeToGeom + DROP TABLE IF EXISTS TypeTable DROP TYPE IF EXISTS geom DROP TABLE IF EXISTS SPATIALPOINTGEOG_dt +DROP TABLE IF EXISTS GeogToVarbinary + +DROP TABLE IF EXISTS GeogTochar + +DROP TABLE IF EXISTS GeogToVarchar + +DROP TABLE IF EXISTS TypeToGeog + DROP TABLE IF EXISTS SPATIALPOINT_dt diff --git a/test/JDBC/input/datatypes/TestSpatialPoint-vu-prepare.txt b/test/JDBC/input/datatypes/TestSpatialPoint-vu-prepare.txt index 2f21076b80..67f3e3419f 100644 --- a/test/JDBC/input/datatypes/TestSpatialPoint-vu-prepare.txt +++ b/test/JDBC/input/datatypes/TestSpatialPoint-vu-prepare.txt @@ -57,10 +57,6 @@ prepst#!#exec#!#GEOMETRY|-|location|-|Point(1.0 ):4326 #Negative Test when an unsupported feature in queried prepst#!#exec#!#GEOMETRY|-|location|-|Point(1.0 2.0 3.0 4.0):4326 prepst#!#exec#!#GEOMETRY|-|location|-|LINESTRING(1 2, 3 4):4326 -#Negative Test for STGeomFromText when invalid type is provided -prepst#!#exec#!#GEOMETRY|-|location|-|Pnt:4326 -#Negative Test for STGeomFromText when Null geometry is provided -prepst#!#exec#!#GEOMETRY|-|location|-|:4326 CREATE VIEW TextFromGeom AS SELECT STAsText(location) AS TextRepresentation FROM SPATIALPOINTGEOM_dt; @@ -68,6 +64,8 @@ CREATE VIEW BinaryFromGeom AS SELECT STAsBinary(location) AS BinaryRepresentatio CREATE VIEW CoordsFromGeom AS SELECT STX(location), STY(location) AS Coordinates FROM SPATIALPOINTGEOM_dt; +CREATE VIEW equal_geom AS SELECT p1.location AS point FROM SPATIALPOINTGEOM_dt p1 CROSS JOIN SPATIALPOINTGEOM_dt p2 WHERE p1.location = p2.location; + CREATE VIEW point_distances_geom AS SELECT p1.location AS point1, p2.location AS point2, STDistance( p1.location, p2.location ) AS distance FROM SPATIALPOINTGEOM_dt p1 CROSS JOIN SPATIALPOINTGEOM_dt p2 WHERE p1.location <> p2.location; CREATE TABLE SPATIALPOINTGEOG_dt (location geography) @@ -80,6 +78,20 @@ CREATE TABLE TypeTable(ID INT PRIMARY KEY, Shape geom) INSERT INTO TypeTable(ID, Shape) VALUES(1, geometry::Point(1, 2, 4326)); +#Testing Implicit CASTs to and from Geometry data type for supported Explicit CASTs +#UnSupported CASTs to and from Geometry data type +CREATE TABLE GeomToVarbinary(p varbinary) +INSERT INTO GeomToVarbinary(p) VALUES(geometry::Point(1, 2, 4326)); +CREATE TABLE GeomTochar(p char) +INSERT INTO GeomTochar(p) VALUES(geometry::Point(1, 2, 4326)); +CREATE TABLE GeomToVarchar(p varchar) +INSERT INTO GeomToVarchar(p) VALUES(geometry::Point(1, 2, 4326)); +#Supported CASTs to and from Geometry data type +CREATE TABLE TypeToGeom(p geometry) +INSERT INTO TypeToGeom(p) VALUES(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS varbinary(MAX))); +INSERT INTO TypeToGeom(p) VALUES(CAST ('POINT(1 2)' AS char)); +INSERT INTO TypeToGeom(p) VALUES(CAST ('POINT(1 2)' AS varchar)); + #Geography Test Cases #Positive Test for STGeomFromText with SRID 4326 @@ -149,10 +161,6 @@ prepst#!#exec#!#GEOGRAPHY|-|location|-|Point(1.0 ):4326 #Negative Test when an unsupported feature in queried prepst#!#exec#!#GEOGRAPHY|-|location|-|Point(1.0 2.0 3.0 4.0):4326 prepst#!#exec#!#GEOGRAPHY|-|location|-|LINESTRING(1 2, 3 4):4326 -#Negative Test for STGeomFromText when invalid type is provided -prepst#!#exec#!#GEOGRAPHY|-|location|-|Pnt:4326 -#Negative Test for STGeomFromText when Null geography is provided -prepst#!#exec#!#GEOGRAPHY|-|location|-|:4326 CREATE VIEW TextFromGeog AS SELECT STAsText(location) AS TextRepresentation FROM SPATIALPOINTGEOG_dt; @@ -163,8 +171,24 @@ CREATE VIEW CoordsFromGeog AS SELECT long(location), lat(location) AS Coordinat CREATE VIEW TransformFromGeog AS SELECT ST_Transform(location, 4326) AS Modified_points FROM SPATIALPOINTGEOG_dt; +CREATE VIEW equal_geog AS SELECT p1.location AS point FROM SPATIALPOINTGEOG_dt p1 CROSS JOIN SPATIALPOINTGEOG_dt p2 WHERE p1.location = p2.location; + CREATE VIEW point_distances_geog AS SELECT p1.location AS point1, p2.location AS point2, STDistance( p1.location, p2.location ) AS distance FROM SPATIALPOINTGEOG_dt p1 CROSS JOIN SPATIALPOINTGEOG_dt p2 WHERE p1.location <> p2.location; +#Testing Implicit CASTs to and from Geography data type for supported Explicit CASTs +#UnSupported CASTs to and from Geography data type +CREATE TABLE GeogToVarbinary(p varbinary) +INSERT INTO GeogToVarbinary(p) VALUES(geography::Point(1, 2, 4326)); +CREATE TABLE GeogTochar(p char) +INSERT INTO GeogTochar(p) VALUES(geography::Point(1, 2, 4326)); +CREATE TABLE GeogToVarchar(p varchar) +INSERT INTO GeogToVarchar(p) VALUES(geography::Point(1, 2, 4326)); +#Supported CASTs to and from Geography data type +CREATE TABLE TypeToGeog(p geography) +INSERT INTO TypeToGeog(p) VALUES(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS varbinary(MAX))); +INSERT INTO TypeToGeog(p) VALUES(CAST ('POINT(1 2)' AS char)); +INSERT INTO TypeToGeog(p) VALUES(CAST ('POINT(1 2)' AS varchar)); + CREATE TABLE SPATIALPOINT_dt (PrimaryKey int, GeomColumn geometry, GeogColumn geography) INSERT INTO SPATIALPOINT_dt (PrimaryKey, GeomColumn) VALUES ( 1, geometry::STGeomFromText('Point(47.65100 -22.34900)', 4326) ) diff --git a/test/JDBC/input/datatypes/TestSpatialPoint-vu-verify.sql b/test/JDBC/input/datatypes/TestSpatialPoint-vu-verify.sql index e40ec893fd..239f4e93ad 100644 --- a/test/JDBC/input/datatypes/TestSpatialPoint-vu-verify.sql +++ b/test/JDBC/input/datatypes/TestSpatialPoint-vu-verify.sql @@ -35,6 +35,9 @@ GO SELECT * FROM CoordsFromGeom; GO +SELECT * FROM equal_geom; +GO + SELECT * FROM point_distances_geom; GO @@ -46,6 +49,93 @@ GO SELECT * FROM TypeTable; GO +SELECT * FROM GeomToVarbinary; +GO +SELECT * FROM GeomTochar; +GO +SELECT * FROM GeomToVarchar; +GO +SELECT * FROM TypeToGeom; +GO + +-- Testing Explicit CASTs to and from Geometry data type +-- Supported CASTs to and from Geometry data type +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS binary) as geometry) +GO +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS varbinary(MAX)) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS varbinary(MAX)) +GO +Select CAST(CAST ('POINT(1 2)' AS char) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS char) +GO +Select CAST(CAST ('POINT(1 2)' AS nchar) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS nchar) +GO +Select CAST(CAST ('POINT(1 2)' AS varchar) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS varchar) +GO +Select CAST(CAST ('POINT(1 2)' AS nvarchar) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS nvarchar) +GO + +-- UnSupported CASTs to and from Geometry data type +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS datetime) +GO +Select CAST(CAST (0001-01-01 AS datetime) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS decimal) +GO +Select CAST(CAST (20.0 AS decimal) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS bigInt) +GO +Select CAST(CAST (20 AS bigInt) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS bigInt) +GO +Select CAST(CAST (20 AS bigInt) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS money) +GO +Select CAST(CAST ($1 AS money) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS bit) +GO +Select CAST(CAST (1 AS bit) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS uniqueidentifier) +GO +Select CAST(CAST ('6F9619FF-8B86-D011-B42D-00C04FC964FF' AS uniqueidentifier) as geometry) +GO +Select CAST(CAST ('POINT(1 2)' AS text) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS text) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS sql_variant) +GO +Select CAST(CAST ('POINT(1 2)' AS sql_variant) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS xml) +GO +Select CAST(CAST ('point(1 2)' AS xml) as geometry) +GO +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS geometry) +GO + +-- UnSupported CASTs which are currently supported for geometry +-- This is because Image type is created as -> CREATE DOMAIN sys.IMAGE AS sys.BBF_VARBINARY; so it is always converted to it's baseType i.e. varbinary +Select CAST (geometry::STGeomFromText('POINT(1.0 2.0)', 4326) AS image) +GO +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS image) as geometry) +GO + DECLARE @point geography; SET @point = geography::STGeomFromText('POINT(-122.34900 47.65100)', 4326); SELECT STAsText(@point); @@ -86,11 +176,97 @@ GO SELECT * FROM TransformFromGeog; GO +SELECT * FROM equal_geog; +GO + SELECT * FROM point_distances_geog; GO SELECT location FROM SPATIALPOINTGEOG_dt; GO +SELECT * FROM GeogToVarbinary; +GO +SELECT * FROM GeogTochar; +GO +SELECT * FROM GeogToVarchar; +GO +SELECT * FROM TypeToGeog; +GO + +-- Testing Explicit CASTs to and from Geography data type +-- Supported CASTs to and from Geography data type +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS binary) as geography) +GO +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS varbinary(MAX)) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS varbinary(MAX)) +GO +Select CAST(CAST ('POINT(1 2)' AS char) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS char) +GO +Select CAST(CAST ('POINT(1 2)' AS nchar) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS nchar) +GO +Select CAST(CAST ('POINT(1 2)' AS varchar) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS varchar) +GO +Select CAST(CAST ('POINT(1 2)' AS nvarchar) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS nvarchar) +GO + +-- UnSupported CASTs to and from Geography data type +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS datetime) +GO +Select CAST(CAST (0001-01-01 AS datetime) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS decimal) +GO +Select CAST(CAST (20.0 AS decimal) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS bigInt) +GO +Select CAST(CAST (20 AS bigInt) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS bigInt) +GO +Select CAST(CAST (20 AS bigInt) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS money) +GO +Select CAST(CAST ($1 AS money) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS bit) +GO +Select CAST(CAST (1 AS bit) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS uniqueidentifier) +GO +Select CAST(CAST ('6F9619FF-8B86-D011-B42D-00C04FC964FF' AS uniqueidentifier) as geography) +GO +Select CAST(CAST ('POINT(1 2)' AS text) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS text) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS sql_variant) +GO +Select CAST(CAST ('POINT(1 2)' AS sql_variant) as geography) +GO +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS xml) +GO +Select CAST(CAST ('point(1 2)' AS xml) as geography) +GO + +-- UnSupported CASTs which are currently supported for geography +-- This is because Image type is created as -> CREATE DOMAIN sys.IMAGE AS sys.BBF_VARBINARY; so it is always converted to it's baseType i.e. varbinary +Select CAST (geography::STGeomFromText('POINT(1.0 2.0)', 4326) AS image) +GO +Select CAST(CAST (0xE6100000010C17D9CEF753D34740D34D6210585936C0 AS image) as geography) +GO + SELECT * FROM SPATIALPOINT_dt; GO diff --git a/test/python/expected/upgrade_validation/expected_dependency.out b/test/python/expected/upgrade_validation/expected_dependency.out index 487f94cb9c..8f9713bff5 100644 --- a/test/python/expected/upgrade_validation/expected_dependency.out +++ b/test/python/expected/upgrade_validation/expected_dependency.out @@ -90,6 +90,8 @@ Function sys."nchar"(sys.varbinary) Function sys."session_user"() Function sys."substring"(sys."nchar",integer,integer) Function sys."substring"(text,integer,integer) +Function sys."varchar"(sys.geography) +Function sys."varchar"(sys.geometry) Function sys.abs(sys.fixeddecimal) Function sys.applock_mode(character varying,character varying,character varying) Function sys.applock_test(character varying,character varying,character varying,character varying) @@ -223,6 +225,7 @@ Function sys.bbf_get_context_info() Function sys.bbf_get_current_physical_schema_name(text) Function sys.bbf_is_shared_schema(text) Function sys.bbf_pivot() +Function sys.bbf_varbinary(sys.geography) Function sys.bbf_varbinary(sys.geometry) Function sys.bbf_varbinary_binary_cmp(sys.bbf_varbinary,sys.bbf_binary) Function sys.bbf_varbinary_cmp(sys.bbf_varbinary,sys.bbf_varbinary) @@ -253,6 +256,8 @@ Function sys.bit_unsupported_max(sys."bit",sys."bit") Function sys.bit_unsupported_min(sys."bit",sys."bit") Function sys.bit_unsupported_sum(sys."bit",sys."bit") Function sys.bitxor(bit,bit) +Function sys.bpchar(sys.geography) +Function sys.bpchar(sys.geometry) Function sys.bpchar2datetime2(sys.bpchar) Function sys.bpchar2float4(sys.bpchar) Function sys.bpchar2int2(sys.bpchar) @@ -266,10 +271,13 @@ Function sys.bpcharbinary(sys.bpchar,integer,boolean) Function sys.bpcharcmp(sys.bpchar,sys.bpchar) Function sys.bpcharrowversion(character,integer,boolean) Function sys.bpcharrowversion(sys.bpchar,integer,boolean) +Function sys.bpchartogeography_helper(sys.bpchar) Function sys.bpcharvarbinary(character,integer,boolean) Function sys.bpcharvarbinary(sys.bpchar,integer,boolean) Function sys.bytea(sys.geography) Function sys.bytea(sys.geometry) +Function sys.bytea_helper(sys.geography) +Function sys.bytea_helper(sys.geometry) Function sys.byteavarbinary(bytea,integer,boolean) Function sys.ceiling(bigint) Function sys.ceiling(integer) @@ -430,9 +438,12 @@ Function sys.ftrunci8(real) Function sys.fulltextserviceproperty(text) Function sys.geogpoint_helper(double precision,double precision,integer) Function sys.geography(bytea) +Function sys.geography(sys."varchar") +Function sys.geography(sys.bbf_binary) Function sys.geography(sys.bbf_varbinary) +Function sys.geography(sys.bpchar) Function sys.geography(sys.geography,integer,boolean) -Function sys.geography(sys.geometry) +Function sys.geography(text,integer,boolean) Function sys.geography__point(double precision,double precision,integer) Function sys.geography__stflipcoordinates(sys.geography) Function sys.geography__stgeomfromtext(text,integer) @@ -440,10 +451,12 @@ Function sys.geography__stpointfromtext(text,integer) Function sys.geography_helper(bytea) Function sys.geometry(bytea) Function sys.geometry(point) +Function sys.geometry(sys."varchar") +Function sys.geometry(sys.bbf_binary) Function sys.geometry(sys.bbf_varbinary) -Function sys.geometry(sys.geography) +Function sys.geometry(sys.bpchar) Function sys.geometry(sys.geometry,integer,boolean) -Function sys.geometry(text) +Function sys.geometry(text,integer,boolean) Function sys.geometry__point(double precision,double precision,integer) Function sys.geometry__stgeomfromtext(text,integer) Function sys.geometry__stpointfromtext(text,integer) @@ -667,6 +680,8 @@ Function sys.sysdatetimeoffset() Function sys.system_user() Function sys.systypes_precision_helper(text,smallint) Function sys.sysutcdatetime() +Function sys.text(sys.geography) +Function sys.text(sys.geometry) Function sys.text_to_name(text) Function sys.time2datetime(time without time zone) Function sys.time2datetime2(time without time zone) @@ -745,6 +760,7 @@ Function sys.varcharbinary(sys."varchar",integer,boolean) Function sys.varcharcmp(sys."varchar",sys."varchar") Function sys.varcharrowversion(character varying,integer,boolean) Function sys.varcharrowversion(sys."varchar",integer,boolean) +Function sys.varchartogeography_helper(sys."varchar") Function sys.varcharvarbinary(character varying,integer,boolean) Function sys.varcharvarbinary(sys."varchar",integer,boolean) Function sys.version() @@ -897,6 +913,7 @@ Operator sys.<>(smallint,sys.fixeddecimal) Operator sys.<>(sys."bit",integer) Operator sys.<>(sys."bit",sys."bit") Operator sys.<>(sys.bbf_binary,sys.bbf_binary) +Operator sys.<>(sys.bbf_varbinary,sys.bbf_varbinary) Operator sys.<>(sys.datetime,sys.datetime) Operator sys.<>(sys.datetime2,sys.datetime2) Operator sys.<>(sys.datetimeoffset,sys.datetimeoffset)