From 98de70eac3bfea0fc2e02abc42df5541093bd3e8 Mon Sep 17 00:00:00 2001 From: Andreas Kosubek Date: Tue, 5 Dec 2023 16:39:16 +0100 Subject: [PATCH 1/4] Oracle SQL backend first draft --- pygeofilter/backends/oraclesql/__init__.py | 3 + pygeofilter/backends/oraclesql/evaluate.py | 209 +++++++++++++++++++++ tests/backends/oraclesql/__init__.py | 0 tests/backends/oraclesql/test_evaluate.py | 95 ++++++++++ 4 files changed, 307 insertions(+) create mode 100644 pygeofilter/backends/oraclesql/__init__.py create mode 100644 pygeofilter/backends/oraclesql/evaluate.py create mode 100644 tests/backends/oraclesql/__init__.py create mode 100644 tests/backends/oraclesql/test_evaluate.py diff --git a/pygeofilter/backends/oraclesql/__init__.py b/pygeofilter/backends/oraclesql/__init__.py new file mode 100644 index 0000000..f1f500c --- /dev/null +++ b/pygeofilter/backends/oraclesql/__init__.py @@ -0,0 +1,3 @@ +from .evaluate import to_sql_where, to_sql_where_with_binds + +__all__ = ["to_sql_where","to_sql_where_with_binds"] diff --git a/pygeofilter/backends/oraclesql/evaluate.py b/pygeofilter/backends/oraclesql/evaluate.py new file mode 100644 index 0000000..57b17cb --- /dev/null +++ b/pygeofilter/backends/oraclesql/evaluate.py @@ -0,0 +1,209 @@ +# ------------------------------------------------------------------------------ +# +# Project: pygeofilter +# Authors: Andreas Kosubek +# +# ------------------------------------------------------------------------------ +# Copyright (C) 2023 Agrar Markt Austria +# +# Permission is hereby granted, free of charge, to any person obtaining a copy +# of this software and associated documentation files (the "Software"), to deal +# in the Software without restriction, including without limitation the rights +# to use, copy, modify, merge, publish, distribute, sublicense, and/or sell +# copies of the Software, and to permit persons to whom the Software is +# furnished to do so, subject to the following conditions: +# +# The above copyright notice and this permission notice shall be included in +# all copies of this Software or works derived from this Software. +# +# THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +# IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +# FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +# AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +# LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +# OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN +# THE SOFTWARE. +# ------------------------------------------------------------------------------ + +from typing import Dict, Optional + +import shapely.geometry + +from ... import ast, values +from ..evaluator import Evaluator, handle + +COMPARISON_OP_MAP = { + ast.ComparisonOp.EQ: "=", + ast.ComparisonOp.NE: "<>", + ast.ComparisonOp.LT: "<", + ast.ComparisonOp.LE: "<=", + ast.ComparisonOp.GT: ">", + ast.ComparisonOp.GE: ">=", +} + + +ARITHMETIC_OP_MAP = { + ast.ArithmeticOp.ADD: "+", + ast.ArithmeticOp.SUB: "-", + ast.ArithmeticOp.MUL: "*", + ast.ArithmeticOp.DIV: "/", +} + +SPATIAL_COMPARISON_OP_MAP = { + ast.SpatialComparisonOp.INTERSECTS: "ANYINTERACT", + ast.SpatialComparisonOp.DISJOINT: "DISJOINT", + ast.SpatialComparisonOp.CONTAINS: "CONTAINS", + ast.SpatialComparisonOp.WITHIN: "INSIDE", + ast.SpatialComparisonOp.TOUCHES: "TOUCH", + ast.SpatialComparisonOp.CROSSES: "OVERLAPBDYDISJOINT", + ast.SpatialComparisonOp.OVERLAPS: "OVERLAPBDYINTERSECT", + ast.SpatialComparisonOp.EQUALS: "EQUAL", +} + +WITH_BINDS = False + +BIND_VARIABLES = {} + + +class OracleSQLEvaluator(Evaluator): + def __init__( + self, attribute_map: Dict[str, str], function_map: Dict[str, str] + ): + self.attribute_map = attribute_map + self.function_map = function_map + + @handle(ast.Not) + def not_(self, node, sub): + return f"NOT {sub}" + + @handle(ast.And, ast.Or) + def combination(self, node, lhs, rhs): + return f"({lhs} {node.op.value} {rhs})" + + @handle(ast.Comparison, subclasses=True) + def comparison(self, node, lhs, rhs): + if WITH_BINDS: + BIND_VARIABLES[f"{lhs}"] = rhs + sql = f"({lhs} {COMPARISON_OP_MAP[node.op]} :{lhs})" + else: + sql = f"({lhs} {COMPARISON_OP_MAP[node.op]} {rhs})" + return sql + + @handle(ast.Between) + def between(self, node, lhs, low, high): + if WITH_BINDS: + BIND_VARIABLES[f"{lhs}_high"] = high + BIND_VARIABLES[f"{lhs}_low"] = low + sql = f"({lhs} {'NOT ' if node.not_ else ''}BETWEEN :{lhs}_low AND :{lhs}_high)" + else: + sql = f"({lhs} {'NOT ' if node.not_ else ''}BETWEEN {low} AND {high})" + return sql + + @handle(ast.Like) + def like(self, node, lhs): + pattern = node.pattern + if node.wildcard != "%": + # TODO: not preceded by escapechar + pattern = pattern.replace(node.wildcard, "%") + if node.singlechar != "_": + # TODO: not preceded by escapechar + pattern = pattern.replace(node.singlechar, "_") + + if WITH_BINDS: + BIND_VARIABLES[f"{lhs}"] = pattern + sql = f"{lhs} {'NOT ' if node.not_ else ''}LIKE " + sql += f":{lhs} ESCAPE '{node.escapechar}'" + + else: + sql = f"{lhs} {'NOT ' if node.not_ else ''}LIKE " + sql += f"'{pattern}' ESCAPE '{node.escapechar}'" + + # TODO: handle node.nocase + return sql + + @handle(ast.In) + def in_(self, node, lhs, *options): + return f"{lhs} {'NOT ' if node.not_ else ''}IN ({', '.join(options)})" + + @handle(ast.IsNull) + def null(self, node, lhs): + return f"{lhs} IS {'NOT ' if node.not_ else ''}NULL" + + @handle(ast.SpatialComparisonPredicate, subclasses=True) + def spatial_operation(self, node, lhs, rhs): + param = f"mask={SPATIAL_COMPARISON_OP_MAP[node.op]}" + func = f"SDO_RELATE({lhs}, {rhs}, '{param}') = 'TRUE'" + return func + + @handle(ast.BBox) + def bbox(self, node, lhs): + bbox = "SDO_GEOMETRY()" + param = f"mask={ast.SpatialComparisonOp.INTERSECTS}" + func = f"SDO_RELATE({lhs}, {bbox}, '{param}') = 'TRUE'" + return func + + @handle(ast.Attribute) + def attribute(self, node: ast.Attribute): + return f"{self.attribute_map[node.name]}" + + @handle(ast.Arithmetic, subclasses=True) + def arithmetic(self, node: ast.Arithmetic, lhs, rhs): + op = ARITHMETIC_OP_MAP[node.op] + return f"({lhs} {op} {rhs})" + + @handle(ast.Function) + def function(self, node, *arguments): + func = self.function_map[node.name] + return f"{func}({','.join(arguments)})" + + @handle(*values.LITERALS) + def literal(self, node): + if isinstance(node, str): + return f"'{node}'" + else: + return node + + @handle(values.Geometry) + def geometry(self, node: values.Geometry): + wkb_hex = shapely.geometry.shape(node).wkb_hex + if WITH_BINDS: + BIND_VARIABLES["wkb"] = wkb_hex + sql = "SDO_UTIL.FROM_WKBGEOMETRY(:wkb)" + else: + sql = f"SDO_UTIL.FROM_WKBGEOMETRY('{wkb_hex}')" + return sql + + @handle(values.Envelope) + def envelope(self, node: values.Envelope): + wkb_hex = shapely.geometry.box( + node.x1, node.y1, node.x2, node.y2 + ).wkb_hex + if WITH_BINDS: + BIND_VARIABLES["wkb"] = wkb_hex + sql = "SDO_UTIL.FROM_WKBGEOMETRY(:wkb)" + else: + sql = f"SDO_UTIL.FROM_WKBGEOMETRY('{wkb_hex}')" + return sql + + +def to_sql_where( + root: ast.Node, + field_mapping: Dict[str, str], + function_map: Optional[Dict[str, str]] = None, +) -> str: + global WITH_BINDS + WITH_BINDS = False + return OracleSQLEvaluator(field_mapping, function_map or {}).evaluate(root) + + +def to_sql_where_with_binds( + root: ast.Node, + field_mapping: Dict[str, str], + function_map: Optional[Dict[str, str]] = None, +) -> str: + orcle = OracleSQLEvaluator(field_mapping, function_map or {}) + global WITH_BINDS + WITH_BINDS = True + global BIND_VARIABLES + BIND_VARIABLES = {} + return orcle.evaluate(root), BIND_VARIABLES diff --git a/tests/backends/oraclesql/__init__.py b/tests/backends/oraclesql/__init__.py new file mode 100644 index 0000000..e69de29 diff --git a/tests/backends/oraclesql/test_evaluate.py b/tests/backends/oraclesql/test_evaluate.py new file mode 100644 index 0000000..dd3014a --- /dev/null +++ b/tests/backends/oraclesql/test_evaluate.py @@ -0,0 +1,95 @@ +import pytest + +from pygeofilter.backends.oraclesql import ( + to_sql_where, + to_sql_where_with_binds, +) +from pygeofilter.parsers.ecql import parse + +FIELD_MAPPING = { + "str_attr": "str_attr", + "maybe_str_attr": "maybe_str_attr", + "int_attr": "int_attr", + "float_attr": "float_attr", + "date_attr": "date_attr", + "datetime_attr": "datetime_attr", + "point_attr": "geometry_attr", +} + +FUNCTION_MAP = {} + + +def test_between(): + where = to_sql_where( + parse("int_attr NOT BETWEEN 4 AND 6"), FIELD_MAPPING, FUNCTION_MAP + ) + assert where == "(int_attr NOT BETWEEN 4 AND 6)" + + +def test_between_with_binds(): + where, binds = to_sql_where_with_binds( + parse("int_attr NOT BETWEEN 4 AND 6"), FIELD_MAPPING, FUNCTION_MAP + ) + assert where == "(int_attr NOT BETWEEN :int_attr_low AND :int_attr_high)" + assert binds == {"int_attr_low": 4, "int_attr_high": 6} + + +def test_like(): + where = to_sql_where( + parse("str_attr LIKE 'foo%'"), FIELD_MAPPING, FUNCTION_MAP + ) + assert where == "str_attr LIKE 'foo%' ESCAPE '\\'" + + +def test_like_with_binds(): + where, binds = to_sql_where_with_binds( + parse("str_attr LIKE 'foo%'"), FIELD_MAPPING, FUNCTION_MAP + ) + assert where == "str_attr LIKE :str_attr ESCAPE '\\'" + assert binds == {"str_attr": "foo%"} + + +def test_combination(): + where = to_sql_where( + parse("int_attr = 5 AND float_attr < 6.0"), FIELD_MAPPING, FUNCTION_MAP + ) + assert where == "((int_attr = 5) AND (float_attr < 6.0))" + + +def test_combination_with_binds(): + where, binds = to_sql_where_with_binds( + parse("int_attr = 5 AND float_attr < 6.0"), FIELD_MAPPING, FUNCTION_MAP + ) + assert where == "((int_attr = :int_attr) AND (float_attr < :float_attr))" + assert binds == {"int_attr": 5, "float_attr": 6.0} + + +def test_spatial(): + where = to_sql_where( + parse("INTERSECTS(point_attr, ENVELOPE (0 1 0 1))"), + FIELD_MAPPING, + FUNCTION_MAP, + ) + wkb = "01030000000100000005000000000000000000F03F0000000000000000000000000000" + wkb += "F03F000000000000F03F0000000000000000000000000000F03F000000000000000000" + wkb += "00000000000000000000000000F03F0000000000000000" + assert ( + where + == f"SDO_RELATE(geometry_attr, SDO_UTIL.FROM_WKBGEOMETRY('{wkb}'), 'mask=ANYINTERACT') = 'TRUE'" + ) + + +def test_spatial_with_binds(): + where, binds = to_sql_where_with_binds( + parse("INTERSECTS(point_attr, ENVELOPE (0 1 0 1))"), + FIELD_MAPPING, + FUNCTION_MAP, + ) + wkb = "01030000000100000005000000000000000000F03F0000000000000000000000000000" + wkb += "F03F000000000000F03F0000000000000000000000000000F03F000000000000000000" + wkb += "00000000000000000000000000F03F0000000000000000" + assert ( + where + == "SDO_RELATE(geometry_attr, SDO_UTIL.FROM_WKBGEOMETRY(:wkb), 'mask=ANYINTERACT') = 'TRUE'" + ) + assert binds == {"wkb": wkb} From 51741ab19bcafc5df39d7b4e42936ab2db02af92 Mon Sep 17 00:00:00 2001 From: Andreas Kosubek Date: Wed, 6 Dec 2023 20:36:45 +0100 Subject: [PATCH 2/4] Added spatial support --- pygeofilter/backends/oraclesql/__init__.py | 2 +- pygeofilter/backends/oraclesql/evaluate.py | 58 ++++++++---- tests/backends/oraclesql/test_evaluate.py | 102 ++++++++++++++++----- 3 files changed, 119 insertions(+), 43 deletions(-) diff --git a/pygeofilter/backends/oraclesql/__init__.py b/pygeofilter/backends/oraclesql/__init__.py index f1f500c..55305df 100644 --- a/pygeofilter/backends/oraclesql/__init__.py +++ b/pygeofilter/backends/oraclesql/__init__.py @@ -1,3 +1,3 @@ from .evaluate import to_sql_where, to_sql_where_with_binds -__all__ = ["to_sql_where","to_sql_where_with_binds"] +__all__ = ["to_sql_where", "to_sql_where_with_binds"] diff --git a/pygeofilter/backends/oraclesql/evaluate.py b/pygeofilter/backends/oraclesql/evaluate.py index 57b17cb..b0168f8 100644 --- a/pygeofilter/backends/oraclesql/evaluate.py +++ b/pygeofilter/backends/oraclesql/evaluate.py @@ -27,7 +27,7 @@ from typing import Dict, Optional -import shapely.geometry +import json from ... import ast, values from ..evaluator import Evaluator, handle @@ -103,10 +103,8 @@ def between(self, node, lhs, low, high): def like(self, node, lhs): pattern = node.pattern if node.wildcard != "%": - # TODO: not preceded by escapechar pattern = pattern.replace(node.wildcard, "%") if node.singlechar != "_": - # TODO: not preceded by escapechar pattern = pattern.replace(node.singlechar, "_") if WITH_BINDS: @@ -118,7 +116,6 @@ def like(self, node, lhs): sql = f"{lhs} {'NOT ' if node.not_ else ''}LIKE " sql += f"'{pattern}' ESCAPE '{node.escapechar}'" - # TODO: handle node.nocase return sql @handle(ast.In) @@ -137,10 +134,28 @@ def spatial_operation(self, node, lhs, rhs): @handle(ast.BBox) def bbox(self, node, lhs): - bbox = "SDO_GEOMETRY()" - param = f"mask={ast.SpatialComparisonOp.INTERSECTS}" - func = f"SDO_RELATE({lhs}, {bbox}, '{param}') = 'TRUE'" - return func + geo_json = json.dumps({ + "type": "Polygon", + "coordinates": [[ + [node.minx, node.miny], + [node.minx, node.maxy], + [node.maxx, node.maxy], + [node.maxx, node.miny], + [node.minx, node.miny] + ]] + }) + srid = 4326 + param = "mask=ANYINTERACT" + + if WITH_BINDS: + BIND_VARIABLES["geo_json"] = geo_json + BIND_VARIABLES["srid"] = srid + geom_sql = "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid)" + else: + geom_sql = f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', srid => {srid})" + + sql = f"SDO_RELATE({lhs}, {geom_sql}, '{param}') = 'TRUE'" + return sql @handle(ast.Attribute) def attribute(self, node: ast.Attribute): @@ -165,24 +180,31 @@ def literal(self, node): @handle(values.Geometry) def geometry(self, node: values.Geometry): - wkb_hex = shapely.geometry.shape(node).wkb_hex + # TODO Read CRS information from + # node and translate to SRID + srid = 4326 + geo_json = json.dumps(node.geometry) + print(geo_json) if WITH_BINDS: - BIND_VARIABLES["wkb"] = wkb_hex - sql = "SDO_UTIL.FROM_WKBGEOMETRY(:wkb)" + BIND_VARIABLES["geo_json"] = geo_json + BIND_VARIABLES["srid"] = srid + sql = "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid)" else: - sql = f"SDO_UTIL.FROM_WKBGEOMETRY('{wkb_hex}')" + sql = f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', srid => {srid})" return sql @handle(values.Envelope) def envelope(self, node: values.Envelope): - wkb_hex = shapely.geometry.box( - node.x1, node.y1, node.x2, node.y2 - ).wkb_hex + # TODO Read CRS information from + # node and translate to SRID + srid = 4326 + geo_json = json.dumps(node.geometry) if WITH_BINDS: - BIND_VARIABLES["wkb"] = wkb_hex - sql = "SDO_UTIL.FROM_WKBGEOMETRY(:wkb)" + BIND_VARIABLES["geo_json"] = geo_json + BIND_VARIABLES["srid"] = srid + sql = "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid)" else: - sql = f"SDO_UTIL.FROM_WKBGEOMETRY('{wkb_hex}')" + sql = f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', srid => {srid})" return sql diff --git a/tests/backends/oraclesql/test_evaluate.py b/tests/backends/oraclesql/test_evaluate.py index dd3014a..fa8a27f 100644 --- a/tests/backends/oraclesql/test_evaluate.py +++ b/tests/backends/oraclesql/test_evaluate.py @@ -1,5 +1,3 @@ -import pytest - from pygeofilter.backends.oraclesql import ( to_sql_where, to_sql_where_with_binds, @@ -8,11 +6,8 @@ FIELD_MAPPING = { "str_attr": "str_attr", - "maybe_str_attr": "maybe_str_attr", "int_attr": "int_attr", "float_attr": "float_attr", - "date_attr": "date_attr", - "datetime_attr": "datetime_attr", "point_attr": "geometry_attr", } @@ -21,14 +16,18 @@ def test_between(): where = to_sql_where( - parse("int_attr NOT BETWEEN 4 AND 6"), FIELD_MAPPING, FUNCTION_MAP + parse("int_attr NOT BETWEEN 4 AND 6"), + FIELD_MAPPING, + FUNCTION_MAP ) assert where == "(int_attr NOT BETWEEN 4 AND 6)" def test_between_with_binds(): where, binds = to_sql_where_with_binds( - parse("int_attr NOT BETWEEN 4 AND 6"), FIELD_MAPPING, FUNCTION_MAP + parse("int_attr NOT BETWEEN 4 AND 6"), + FIELD_MAPPING, + FUNCTION_MAP ) assert where == "(int_attr NOT BETWEEN :int_attr_low AND :int_attr_high)" assert binds == {"int_attr_low": 4, "int_attr_high": 6} @@ -36,14 +35,18 @@ def test_between_with_binds(): def test_like(): where = to_sql_where( - parse("str_attr LIKE 'foo%'"), FIELD_MAPPING, FUNCTION_MAP + parse("str_attr LIKE 'foo%'"), + FIELD_MAPPING, + FUNCTION_MAP ) assert where == "str_attr LIKE 'foo%' ESCAPE '\\'" def test_like_with_binds(): where, binds = to_sql_where_with_binds( - parse("str_attr LIKE 'foo%'"), FIELD_MAPPING, FUNCTION_MAP + parse("str_attr LIKE 'foo%'"), + FIELD_MAPPING, + FUNCTION_MAP ) assert where == "str_attr LIKE :str_attr ESCAPE '\\'" assert binds == {"str_attr": "foo%"} @@ -51,14 +54,18 @@ def test_like_with_binds(): def test_combination(): where = to_sql_where( - parse("int_attr = 5 AND float_attr < 6.0"), FIELD_MAPPING, FUNCTION_MAP + parse("int_attr = 5 AND float_attr < 6.0"), + FIELD_MAPPING, + FUNCTION_MAP ) assert where == "((int_attr = 5) AND (float_attr < 6.0))" def test_combination_with_binds(): where, binds = to_sql_where_with_binds( - parse("int_attr = 5 AND float_attr < 6.0"), FIELD_MAPPING, FUNCTION_MAP + parse("int_attr = 5 AND float_attr < 6.0"), + FIELD_MAPPING, + FUNCTION_MAP ) assert where == "((int_attr = :int_attr) AND (float_attr < :float_attr))" assert binds == {"int_attr": 5, "float_attr": 6.0} @@ -70,12 +77,14 @@ def test_spatial(): FIELD_MAPPING, FUNCTION_MAP, ) - wkb = "01030000000100000005000000000000000000F03F0000000000000000000000000000" - wkb += "F03F000000000000F03F0000000000000000000000000000F03F000000000000000000" - wkb += "00000000000000000000000000F03F0000000000000000" - assert ( - where - == f"SDO_RELATE(geometry_attr, SDO_UTIL.FROM_WKBGEOMETRY('{wkb}'), 'mask=ANYINTERACT') = 'TRUE'" + geo_json = ( + "{\"type\": \"Polygon\", " + "\"coordinates\": [[[0, 0], [0, 1], [1, 1], [1, 0], [0, 0]]]}" + ) + assert where == ( + "SDO_RELATE(geometry_attr, " + f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', srid => 4326), " + "'mask=ANYINTERACT') = 'TRUE'" ) @@ -85,11 +94,56 @@ def test_spatial_with_binds(): FIELD_MAPPING, FUNCTION_MAP, ) - wkb = "01030000000100000005000000000000000000F03F0000000000000000000000000000" - wkb += "F03F000000000000F03F0000000000000000000000000000F03F000000000000000000" - wkb += "00000000000000000000000000F03F0000000000000000" - assert ( - where - == "SDO_RELATE(geometry_attr, SDO_UTIL.FROM_WKBGEOMETRY(:wkb), 'mask=ANYINTERACT') = 'TRUE'" + geo_json = ( + "{\"type\": \"Polygon\", " + "\"coordinates\": [[[0, 0], [0, 1], [1, 1], [1, 0], [0, 0]]]}" + ) + assert where == ( + "SDO_RELATE(geometry_attr, " + "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid), " + "'mask=ANYINTERACT') = 'TRUE'" + ) + assert binds == {"geo_json": geo_json, "srid": 4326} + + +def test_bbox(): + where = to_sql_where( + parse("BBOX(point_attr,-140.99778,41.6751050889,-52.6480987209,83.23324)"), + FIELD_MAPPING, + FUNCTION_MAP, + ) + geo_json = ( + "{\"type\": \"Polygon\", \"coordinates\": [[" + "[-140.99778, 41.6751050889], " + "[-140.99778, 83.23324], " + "[-52.6480987209, 83.23324], " + "[-52.6480987209, 41.6751050889], " + "[-140.99778, 41.6751050889]]]}" + ) + assert where == ( + "SDO_RELATE(geometry_attr, " + f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', srid => 4326), " + "'mask=ANYINTERACT') = 'TRUE'" + ) + + +def test_bbox_with_binds(): + where, binds = to_sql_where_with_binds( + parse("BBOX(point_attr,-140.99778,41.6751050889,-52.6480987209,83.23324)"), + FIELD_MAPPING, + FUNCTION_MAP, + ) + geo_json = ( + "{\"type\": \"Polygon\", \"coordinates\": [[" + "[-140.99778, 41.6751050889], " + "[-140.99778, 83.23324], " + "[-52.6480987209, 83.23324], " + "[-52.6480987209, 41.6751050889], " + "[-140.99778, 41.6751050889]]]}" + ) + assert where == ( + "SDO_RELATE(geometry_attr, " + "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid), " + "'mask=ANYINTERACT') = 'TRUE'" ) - assert binds == {"wkb": wkb} + assert binds == {"geo_json": geo_json, "srid": 4326} From 469700d29db8e18fa1af9bf67433fcfdd02f7882 Mon Sep 17 00:00:00 2001 From: Andreas Kosubek Date: Thu, 7 Dec 2023 10:47:52 +0100 Subject: [PATCH 3/4] + Bind variable counter --- pygeofilter/backends/oraclesql/__init__.py | 4 +- pygeofilter/backends/oraclesql/evaluate.py | 106 +++++++++++++-------- tests/backends/oraclesql/test_evaluate.py | 32 +++---- 3 files changed, 85 insertions(+), 57 deletions(-) diff --git a/pygeofilter/backends/oraclesql/__init__.py b/pygeofilter/backends/oraclesql/__init__.py index 55305df..6dd24d9 100644 --- a/pygeofilter/backends/oraclesql/__init__.py +++ b/pygeofilter/backends/oraclesql/__init__.py @@ -1,3 +1,3 @@ -from .evaluate import to_sql_where, to_sql_where_with_binds +from .evaluate import to_sql_where, to_sql_where_with_bind_variables -__all__ = ["to_sql_where", "to_sql_where_with_binds"] +__all__ = ["to_sql_where", "to_sql_where_with_bind_variables"] diff --git a/pygeofilter/backends/oraclesql/evaluate.py b/pygeofilter/backends/oraclesql/evaluate.py index b0168f8..ad2a42f 100644 --- a/pygeofilter/backends/oraclesql/evaluate.py +++ b/pygeofilter/backends/oraclesql/evaluate.py @@ -60,10 +60,6 @@ ast.SpatialComparisonOp.EQUALS: "EQUAL", } -WITH_BINDS = False - -BIND_VARIABLES = {} - class OracleSQLEvaluator(Evaluator): def __init__( @@ -72,6 +68,11 @@ def __init__( self.attribute_map = attribute_map self.function_map = function_map + self.with_bind_variables = False + self.bind_variables = {} + # Counter for bind variables + self.b_cnt = 0 + @handle(ast.Not) def not_(self, node, sub): return f"NOT {sub}" @@ -82,21 +83,29 @@ def combination(self, node, lhs, rhs): @handle(ast.Comparison, subclasses=True) def comparison(self, node, lhs, rhs): - if WITH_BINDS: - BIND_VARIABLES[f"{lhs}"] = rhs - sql = f"({lhs} {COMPARISON_OP_MAP[node.op]} :{lhs})" + if self.with_bind_variables: + self.bind_variables[f"{lhs}_{self.b_cnt}"] = rhs + sql = f"({lhs} {COMPARISON_OP_MAP[node.op]} :{lhs}_{self.b_cnt})" + self.b_cnt += 1 else: sql = f"({lhs} {COMPARISON_OP_MAP[node.op]} {rhs})" return sql @handle(ast.Between) def between(self, node, lhs, low, high): - if WITH_BINDS: - BIND_VARIABLES[f"{lhs}_high"] = high - BIND_VARIABLES[f"{lhs}_low"] = low - sql = f"({lhs} {'NOT ' if node.not_ else ''}BETWEEN :{lhs}_low AND :{lhs}_high)" + if self.with_bind_variables: + self.bind_variables[f"{lhs}_high_{self.b_cnt}"] = high + self.bind_variables[f"{lhs}_low_{self.b_cnt}"] = low + sql = ( + f"({lhs} {'NOT ' if node.not_ else ''}BETWEEN " + f":{lhs}_low_{self.b_cnt} AND :{lhs}_high_{self.b_cnt})" + ) + self.b_cnt += 1 else: - sql = f"({lhs} {'NOT ' if node.not_ else ''}BETWEEN {low} AND {high})" + sql = ( + f"({lhs} {'NOT ' if node.not_ else ''}BETWEEN " + f"{low} AND {high})" + ) return sql @handle(ast.Like) @@ -107,10 +116,10 @@ def like(self, node, lhs): if node.singlechar != "_": pattern = pattern.replace(node.singlechar, "_") - if WITH_BINDS: - BIND_VARIABLES[f"{lhs}"] = pattern + if self.with_bind_variables: + self.bind_variables[f"{lhs}_{self.b_cnt}"] = pattern sql = f"{lhs} {'NOT ' if node.not_ else ''}LIKE " - sql += f":{lhs} ESCAPE '{node.escapechar}'" + sql += f":{lhs}_{self.b_cnt} ESCAPE '{node.escapechar}'" else: sql = f"{lhs} {'NOT ' if node.not_ else ''}LIKE " @@ -147,12 +156,19 @@ def bbox(self, node, lhs): srid = 4326 param = "mask=ANYINTERACT" - if WITH_BINDS: - BIND_VARIABLES["geo_json"] = geo_json - BIND_VARIABLES["srid"] = srid - geom_sql = "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid)" + if self.with_bind_variables: + self.bind_variables[f"geo_json_{self.b_cnt}"] = geo_json + self.bind_variables[f"srid_{self.b_cnt}"] = srid + geom_sql = ( + f"SDO_UTIL.FROM_JSON(geometry => :geo_json_{self.b_cnt}, " + f"srid => :srid_{self.b_cnt})" + ) + self.b_cnt += 1 else: - geom_sql = f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', srid => {srid})" + geom_sql = ( + f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', " + f"srid => {srid})" + ) sql = f"SDO_RELATE({lhs}, {geom_sql}, '{param}') = 'TRUE'" return sql @@ -185,12 +201,19 @@ def geometry(self, node: values.Geometry): srid = 4326 geo_json = json.dumps(node.geometry) print(geo_json) - if WITH_BINDS: - BIND_VARIABLES["geo_json"] = geo_json - BIND_VARIABLES["srid"] = srid - sql = "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid)" + if self.with_bind_variables: + self.bind_variables[f"geo_json_{self.b_cnt}"] = geo_json + self.bind_variables[f"srid_{self.b_cnt}"] = srid + sql = ( + f"SDO_UTIL.FROM_JSON(geometry => :geo_json_{self.b_cnt}, " + f"srid => :srid_{self.b_cnt})" + ) + self.b_cnt += 1 else: - sql = f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', srid => {srid})" + sql = ( + f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', " + f"srid => {srid})" + ) return sql @handle(values.Envelope) @@ -199,12 +222,19 @@ def envelope(self, node: values.Envelope): # node and translate to SRID srid = 4326 geo_json = json.dumps(node.geometry) - if WITH_BINDS: - BIND_VARIABLES["geo_json"] = geo_json - BIND_VARIABLES["srid"] = srid - sql = "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid)" + if self.with_bind_variables: + self.bind_variables[f"geo_json_{self.b_cnt}"] = geo_json + self.bind_variables[f"srid_{self.b_cnt}"] = srid + sql = ( + f"SDO_UTIL.FROM_JSON(geometry => :geo_json_{self.b_cnt}, " + f"srid => :srid_{self.b_cnt})" + ) + self.b_cnt += 1 else: - sql = f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', srid => {srid})" + sql = ( + f"SDO_UTIL.FROM_JSON(geometry => '{geo_json}', " + f"srid => {srid})" + ) return sql @@ -213,19 +243,17 @@ def to_sql_where( field_mapping: Dict[str, str], function_map: Optional[Dict[str, str]] = None, ) -> str: - global WITH_BINDS - WITH_BINDS = False - return OracleSQLEvaluator(field_mapping, function_map or {}).evaluate(root) + orcle = OracleSQLEvaluator(field_mapping, function_map or {}) + orcle.with_bind_variables = False + return orcle.evaluate(root) -def to_sql_where_with_binds( +def to_sql_where_with_bind_variables( root: ast.Node, field_mapping: Dict[str, str], function_map: Optional[Dict[str, str]] = None, ) -> str: orcle = OracleSQLEvaluator(field_mapping, function_map or {}) - global WITH_BINDS - WITH_BINDS = True - global BIND_VARIABLES - BIND_VARIABLES = {} - return orcle.evaluate(root), BIND_VARIABLES + orcle.with_bind_variables = True + orcle.bind_variables = {} + return orcle.evaluate(root), orcle.bind_variables diff --git a/tests/backends/oraclesql/test_evaluate.py b/tests/backends/oraclesql/test_evaluate.py index fa8a27f..f8ed4ec 100644 --- a/tests/backends/oraclesql/test_evaluate.py +++ b/tests/backends/oraclesql/test_evaluate.py @@ -1,6 +1,6 @@ from pygeofilter.backends.oraclesql import ( to_sql_where, - to_sql_where_with_binds, + to_sql_where_with_bind_variables, ) from pygeofilter.parsers.ecql import parse @@ -24,13 +24,13 @@ def test_between(): def test_between_with_binds(): - where, binds = to_sql_where_with_binds( + where, binds = to_sql_where_with_bind_variables( parse("int_attr NOT BETWEEN 4 AND 6"), FIELD_MAPPING, FUNCTION_MAP ) - assert where == "(int_attr NOT BETWEEN :int_attr_low AND :int_attr_high)" - assert binds == {"int_attr_low": 4, "int_attr_high": 6} + assert where == "(int_attr NOT BETWEEN :int_attr_low_0 AND :int_attr_high_0)" + assert binds == {"int_attr_low_0": 4, "int_attr_high_0": 6} def test_like(): @@ -43,13 +43,13 @@ def test_like(): def test_like_with_binds(): - where, binds = to_sql_where_with_binds( + where, binds = to_sql_where_with_bind_variables( parse("str_attr LIKE 'foo%'"), FIELD_MAPPING, FUNCTION_MAP ) - assert where == "str_attr LIKE :str_attr ESCAPE '\\'" - assert binds == {"str_attr": "foo%"} + assert where == "str_attr LIKE :str_attr_0 ESCAPE '\\'" + assert binds == {"str_attr_0": "foo%"} def test_combination(): @@ -62,13 +62,13 @@ def test_combination(): def test_combination_with_binds(): - where, binds = to_sql_where_with_binds( + where, binds = to_sql_where_with_bind_variables( parse("int_attr = 5 AND float_attr < 6.0"), FIELD_MAPPING, FUNCTION_MAP ) - assert where == "((int_attr = :int_attr) AND (float_attr < :float_attr))" - assert binds == {"int_attr": 5, "float_attr": 6.0} + assert where == "((int_attr = :int_attr_0) AND (float_attr < :float_attr_1))" + assert binds == {"int_attr_0": 5, "float_attr_1": 6.0} def test_spatial(): @@ -89,7 +89,7 @@ def test_spatial(): def test_spatial_with_binds(): - where, binds = to_sql_where_with_binds( + where, binds = to_sql_where_with_bind_variables( parse("INTERSECTS(point_attr, ENVELOPE (0 1 0 1))"), FIELD_MAPPING, FUNCTION_MAP, @@ -100,10 +100,10 @@ def test_spatial_with_binds(): ) assert where == ( "SDO_RELATE(geometry_attr, " - "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid), " + "SDO_UTIL.FROM_JSON(geometry => :geo_json_0, srid => :srid_0), " "'mask=ANYINTERACT') = 'TRUE'" ) - assert binds == {"geo_json": geo_json, "srid": 4326} + assert binds == {"geo_json_0": geo_json, "srid_0": 4326} def test_bbox(): @@ -128,7 +128,7 @@ def test_bbox(): def test_bbox_with_binds(): - where, binds = to_sql_where_with_binds( + where, binds = to_sql_where_with_bind_variables( parse("BBOX(point_attr,-140.99778,41.6751050889,-52.6480987209,83.23324)"), FIELD_MAPPING, FUNCTION_MAP, @@ -143,7 +143,7 @@ def test_bbox_with_binds(): ) assert where == ( "SDO_RELATE(geometry_attr, " - "SDO_UTIL.FROM_JSON(geometry => :geo_json, srid => :srid), " + "SDO_UTIL.FROM_JSON(geometry => :geo_json_0, srid => :srid_0), " "'mask=ANYINTERACT') = 'TRUE'" ) - assert binds == {"geo_json": geo_json, "srid": 4326} + assert binds == {"geo_json_0": geo_json, "srid_0": 4326} From b7faf82e2aaa657cc8ab0a764d5225702ce6fff4 Mon Sep 17 00:00:00 2001 From: Bernhard Mallinger Date: Tue, 9 Jan 2024 09:45:04 +0100 Subject: [PATCH 4/4] Add source code headers to non-empty files --- pygeofilter/backends/oraclesql/__init__.py | 28 +++++++++++++++++++++ pygeofilter/backends/oraclesql/evaluate.py | 2 ++ tests/backends/oraclesql/test_evaluate.py | 29 ++++++++++++++++++++++ 3 files changed, 59 insertions(+) diff --git a/pygeofilter/backends/oraclesql/__init__.py b/pygeofilter/backends/oraclesql/__init__.py index 6dd24d9..6008561 100644 --- a/pygeofilter/backends/oraclesql/__init__.py +++ b/pygeofilter/backends/oraclesql/__init__.py @@ -1,3 +1,31 @@ +# ------------------------------------------------------------------------------ +# +# Project: pygeofilter +# Authors: Andreas Kosubek +# Bernhard Mallinger +# ------------------------------------------------------------------------------ +# Copyright (C) 2024 EOX IT Services GmbH +# +# Permission is hereby granted, free of charge, to any person obtaining a copy +# of this software and associated documentation files (the "Software"), to deal +# in the Software without restriction, including without limitation the rights +# to use, copy, modify, merge, publish, distribute, sublicense, and/or sell +# copies of the Software, and to permit persons to whom the Software is +# furnished to do so, subject to the following conditions: +# +# The above copyright notice and this permission notice shall be included in +# all copies of this Software or works derived from this Software. +# +# THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +# IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +# FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +# AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +# LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +# OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN +# THE SOFTWARE. +# ------------------------------------------------------------------------------ + + from .evaluate import to_sql_where, to_sql_where_with_bind_variables __all__ = ["to_sql_where", "to_sql_where_with_bind_variables"] diff --git a/pygeofilter/backends/oraclesql/evaluate.py b/pygeofilter/backends/oraclesql/evaluate.py index ad2a42f..4562998 100644 --- a/pygeofilter/backends/oraclesql/evaluate.py +++ b/pygeofilter/backends/oraclesql/evaluate.py @@ -2,9 +2,11 @@ # # Project: pygeofilter # Authors: Andreas Kosubek +# Bernhard Mallinger # # ------------------------------------------------------------------------------ # Copyright (C) 2023 Agrar Markt Austria +# Copyright (C) 2024 EOX IT Services GmbH # # Permission is hereby granted, free of charge, to any person obtaining a copy # of this software and associated documentation files (the "Software"), to deal diff --git a/tests/backends/oraclesql/test_evaluate.py b/tests/backends/oraclesql/test_evaluate.py index f8ed4ec..f8159ca 100644 --- a/tests/backends/oraclesql/test_evaluate.py +++ b/tests/backends/oraclesql/test_evaluate.py @@ -1,3 +1,32 @@ +# ------------------------------------------------------------------------------ +# +# Project: pygeofilter +# Authors: Andreas Kosubek +# Bernhard Mallinger +# ------------------------------------------------------------------------------ +# Copyright (C) 2023 Agrar Markt Austria +# Copyright (C) 2024 EOX IT Services GmbH +# +# Permission is hereby granted, free of charge, to any person obtaining a copy +# of this software and associated documentation files (the "Software"), to deal +# in the Software without restriction, including without limitation the rights +# to use, copy, modify, merge, publish, distribute, sublicense, and/or sell +# copies of the Software, and to permit persons to whom the Software is +# furnished to do so, subject to the following conditions: +# +# The above copyright notice and this permission notice shall be included in +# all copies of this Software or works derived from this Software. +# +# THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +# IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +# FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +# AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +# LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +# OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN +# THE SOFTWARE. +# ------------------------------------------------------------------------------ + + from pygeofilter.backends.oraclesql import ( to_sql_where, to_sql_where_with_bind_variables,