Skip to content

Commit

Permalink
Implement Supported Geospatial CASTs (babelfish-for-postgresql#1945)
Browse files Browse the repository at this point in the history
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 [email protected]
  • Loading branch information
Anikait143 authored Nov 8, 2023
1 parent cee66be commit de7d858
Show file tree
Hide file tree
Showing 15 changed files with 1,546 additions and 170 deletions.
17 changes: 10 additions & 7 deletions .github/composite-actions/build-postgis-extension/action.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
17 changes: 10 additions & 7 deletions .github/composite-actions/setup-base-version/action.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
17 changes: 10 additions & 7 deletions .github/workflows/major-version-upgrade.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
17 changes: 10 additions & 7 deletions .github/workflows/minor-version-upgrade.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
17 changes: 10 additions & 7 deletions .github/workflows/tap-tests.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
183 changes: 165 additions & 18 deletions contrib/babelfishpg_common/sql/geography.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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)
Expand Down Expand Up @@ -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
Expand Down Expand Up @@ -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;

Loading

0 comments on commit de7d858

Please sign in to comment.