From 4b878b4d9ff8816de60557217037240ec8b40074 Mon Sep 17 00:00:00 2001 From: Markus Demleitner <m@tfiu.de> Date: Mon, 22 Nov 2021 10:59:53 +0100 Subject: [PATCH 1/5] Fixing test expectation for updates in pg_sphere.test.sql --- expected/init_test.out | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/expected/init_test.out b/expected/init_test.out index 6d91697..01d73a2 100644 --- a/expected/init_test.out +++ b/expected/init_test.out @@ -33,5 +33,5 @@ psql:pg_sphere.test.sql:8569: NOTICE: argument type pointkey is only a shell psql:pg_sphere.test.sql:8575: NOTICE: argument type pointkey is only a shell psql:pg_sphere.test.sql:8581: NOTICE: argument type pointkey is only a shell psql:pg_sphere.test.sql:8587: NOTICE: argument type pointkey is only a shell -psql:pg_sphere.test.sql:9152: NOTICE: return type smoc is only a shell -psql:pg_sphere.test.sql:9158: NOTICE: argument type smoc is only a shell +psql:pg_sphere.test.sql:9154: NOTICE: return type smoc is only a shell +psql:pg_sphere.test.sql:9160: NOTICE: argument type smoc is only a shell From 97080b5c18d4a7c89b11fb388b5944ebb1e09b29 Mon Sep 17 00:00:00 2001 From: Markus Demleitner <m@tfiu.de> Date: Mon, 22 Nov 2021 11:35:38 +0100 Subject: [PATCH 2/5] Adding documentation for the max_order function --- doc/functions.sgm | 28 ++++++++++++++++++++++++++++ 1 file changed, 28 insertions(+) diff --git a/doc/functions.sgm b/doc/functions.sgm index be89326..1318141 100644 --- a/doc/functions.sgm +++ b/doc/functions.sgm @@ -638,6 +638,34 @@ </programlisting> </example> + <funcsynopsis> + <funcprototype> + <funcdef><function>max_order</function></funcdef> + <paramdef>smoc</paramdef> + </funcprototype> + </funcsynopsis> + <para> + Returns the maximal order of an smoc. + </para> + <para> + The maximal order of a MOC can be higher than than the highest + order appearing in the serialisation. For instance, in the example + below the full-sky coverage given at order 6 means that no patch + larger than about 1 degree is not covered. In the ASCII + serialisation, give the maximum order with an with an empty cell + list. + </para> + + <example> + <title>Obtaining a MOC order</title> + <programlisting> +<![CDATA[SELECT max_order(smoc('0/0-11 6/')) as order;]]> +<![CDATA[ order]]> +<![CDATA[-----------]]> +<![CDATA[ 6 ]]> + </programlisting> + </example> + </sect2> </sect1> From 2bde2b191f2f7a53b4f0a4149abd832056fd86bb Mon Sep 17 00:00:00 2001 From: Markus Demleitner <m@tfiu.de> Date: Wed, 8 Dec 2021 17:03:37 +0100 Subject: [PATCH 3/5] Adding support of casting of circles and polygons to mocs in contains and intersects constraints. I'm also adding a little file on how to hack pg_sphere; yes, that's mainly repeating stuff from the pg docs, but I guess it'll help a few folks; it would have helped me. --- .gitignore | 1 + HACKING | 50 +++ Makefile | 17 +- doc/gen_moccast.py | 156 ++++++++ doc/operators.sgm | 45 ++- expected/mocautocast.out | 209 ++++++++++ ...e--1.2.0.sql.in => pg_sphere--1.2.1.sql.in | 0 pg_sphere.control | 2 +- pgs_moc_geo_casts.sql.in | 374 ++++++++++++++++++ sql/mocautocast.sql | 123 ++++++ 10 files changed, 969 insertions(+), 8 deletions(-) create mode 100644 HACKING create mode 100644 doc/gen_moccast.py create mode 100644 expected/mocautocast.out rename pg_sphere--1.2.0.sql.in => pg_sphere--1.2.1.sql.in (100%) create mode 100644 pgs_moc_geo_casts.sql.in create mode 100644 sql/mocautocast.sql diff --git a/.gitignore b/.gitignore index 4e384bf..7ab2e85 100644 --- a/.gitignore +++ b/.gitignore @@ -8,3 +8,4 @@ regression.out regression.diffs tags +buildpod diff --git a/HACKING b/HACKING new file mode 100644 index 0000000..0b86594 --- /dev/null +++ b/HACKING @@ -0,0 +1,50 @@ +SQL definitions +=============== + +Long version: +<https://www.postgresql.org/docs/current/extend-extensions.html>. + +If you're writing new features that require SQL support, pick some +descriptive name; let's say my_new_op. + +Put your new code into a file called pgs_my_new_op.sql.in. The .in +extension here usually indicates "it's for copying stuff together"; +usally, not much processing is done on such files. + +Then edit the Makefile. The PGS_SQL variable contains a list of the +SQL files eventually copied together, without the .in. Add your new +file there. + +You will also need to create an upgrade file. In order to tell postgres +to execute it, increase PGSPHERE_VERSION as appropriate. As a +consequence, you will have to:: + + git mv pg_sphere--<old version>.sql.in pg_sphere--<new version>.sql.in + +and also to update the version in pg_sphere.control. + +Then create a make rule:: + + pg_sphere--<old version>--<new version>.sql: pgs_my_new_op.sql.in + cat $^ > $@ + +(of course, this will extend to having multiple sql.in files). + +Finally, add the target of that rule to the DATA_built variable. + + +Regression tests +================ + +Regressions tests are as per +<https://www.postgresql.org/docs/current/extend-pgxs.html>. + +In short, write queries executing your new features into a file +sql/my_new_op.sql, and add "my_new_op" (without the extension or the +directory name) to both REGRESS and TESTS in the Makefile. + +Then touch expected/my_new_op.out, run make test. This will of course +fail, because your tests hopefully will output something. But then you +can pick out the diff from +/var/lib/postgresql/pgsphere/regression.diffs, have another critical +look at it and generatoe your .out file from it. diff --git a/Makefile b/Makefile index fed246b..c3c5296 100644 --- a/Makefile +++ b/Makefile @@ -1,4 +1,4 @@ -PGSPHERE_VERSION = 1.2.0 +PGSPHERE_VERSION = 1.2.1 # the base dir name may be changed depending on git clone command SRC_DIR = $(shell basename $(shell pwd)) @@ -17,18 +17,19 @@ DATA_built = $(RELEASE_SQL) \ pg_sphere--1.0_gavo--1.1.5beta0gavo.sql \ pg_sphere--1.1.5beta0gavo--1.1.5beta2gavo.sql \ pg_sphere--1.1.5beta2gavo--1.1.5beta4gavo.sql \ - pg_sphere--1.1.5beta4gavo--1.2.0.sql + pg_sphere--1.1.5beta4gavo--1.2.0.sql \ + pg_sphere--1.2.0--1.2.1.sql DOCS = README.pg_sphere COPYRIGHT.pg_sphere REGRESS = init tables points euler circle line ellipse poly path box index \ contains_ops contains_ops_compat bounding_box_gist gnomo healpix \ - moc + moc mocautocast REGRESS_9_5 = index_9.5 # experimental for spoint3 TESTS = init_test tables points euler circle line ellipse poly path box index \ contains_ops contains_ops_compat bounding_box_gist gnomo healpix \ - moc + moc mocautocast ifndef CXXFLAGS # no support for CXXFLAGS in PGXS before v11 @@ -45,7 +46,8 @@ PGS_SQL = pgs_types.sql pgs_point.sql pgs_euler.sql pgs_circle.sql \ pgs_line.sql pgs_ellipse.sql pgs_polygon.sql pgs_path.sql \ pgs_box.sql pgs_contains_ops.sql pgs_contains_ops_compat.sql \ pgs_gist.sql gnomo.sql \ - healpix.sql pgs_gist_spoint3.sql pgs_moc_type.sql pgs_moc_compat.sql pgs_moc_ops.sql + healpix.sql pgs_gist_spoint3.sql pgs_moc_type.sql pgs_moc_compat.sql pgs_moc_ops.sql \ + pgs_moc_geo_casts.sql PGS_SQL_9_5 = pgs_9.5.sql # experimental for spoint3 USE_PGXS = 1 @@ -154,7 +156,7 @@ ifeq ($(pg_version_9_5_plus),y) else endif -# local stuff follows here, next will be "beta2" +# local stuff follows here AUGMENT_GAVO_111 = $(AUGMENT_UNP_111) healpix.sql # for vanilla 1.1.1 users UPGRADE_GAVO_111 = $(UPGRADE_UNP_COMMON) @@ -196,6 +198,9 @@ ifeq ($(has_parallel), n) sed -i -e '/PARALLEL/d' $@ # version $(pg_version) does not have support for PARALLEL endif +pg_sphere--1.2.0--1.2.1.sql: pgs_moc_geo_casts.sql.in + cat $^ > $@ + # end of local stuff sscan.o : sparse.c diff --git a/doc/gen_moccast.py b/doc/gen_moccast.py new file mode 100644 index 0000000..49c816f --- /dev/null +++ b/doc/gen_moccast.py @@ -0,0 +1,156 @@ +# A script to create the automatic casts for overlaps and intersects +# between MOCs and spolys/scircles. +# +# This has originally been used to create pg_sphere--1.2.0--1.2.1.sql. +# Before 1.2.1 is release, this can be fixed to improve that SQL. +# After the 1.2.1 release, this is just documentation on how MOC +# casts were generated that is perhaps just a bit more readable than +# that bunch of SQL. + +import datetime +import re +import sys + + +OVERLAP_DEFS = [ + # func_stem, operator, commutator + ('subset', '<@', '@>'), + ('not_subset', '!<@', '!@>'), + ('superset', '@>', '<@'), + ('not_superset', '!@>', '!<@'), +] + +INTERSECT_DEFS = [ + # func_stem, operator, commutator + ('intersect', '&&', '&&'), + ('not_intersect', '!&&', '!&&'), +] + + +GEO_TYPES = ["scircle", "spoly"] + +OP_DEFS = OVERLAP_DEFS + + +class Accum: + """an accumulator for our output. + """ + def __init__(self): + self.parts = [] + + @property + def content(self): + return "".join(self.parts) + + def write(self, s): + self.parts.append(s) + + def writeln(self, *strings): + self.parts.append("\n".join(strings)+"\n") + + def replace_last(self, subs): + """replaces the last non-whitespace char with the string subs. + """ + for index, part in enumerate(reversed(self.parts)): + if part.strip(): + break + else: + # nothing to replace + return + + index = -1-index + self.parts[index] = re.sub("[^\s](\s*)$", + lambda mat: subs+mat.group(1), + self.parts[index]) + + def introduce_section(self, sec_name): + self.writeln() + self.writeln("-- #################################") + self.writeln(f"-- {sec_name}") + + +def emit_drop_code(accum): + accum.introduce_section("Cleanup") + + accum.writeln("DROP OPERATOR IF EXISTS") + for _, op, _ in OP_DEFS: + for geo_type in GEO_TYPES: + accum.writeln(f" {op} (smoc, {geo_type}),") + accum.writeln(f" {op} ({geo_type}, smoc),") + accum.replace_last(";") + + +def make_negator(op): + if op.startswith("!"): + return op[1:] + else: + return "!"+op + + +def emit_op_def(accum, operator, leftarg, rightarg, procedure, commutator): + accum.writeln( + f"CREATE OPERATOR {operator} (", + f" LEFTARG = {leftarg},", + f" RIGHTARG = {rightarg},", + f" PROCEDURE = {procedure},", + f" COMMUTATOR = '{commutator}',", + f" NEGATOR = '{make_negator(operator)}',", + f" RESTRICT = contsel,", + f" JOIN = contjoinsel", + f");") + + +def emit_op_and_func(accum, op_def): + func_stem, operator, commutator = op_def + for geo_type in GEO_TYPES: + func_name = f"{geo_type}_{func_stem}_smoc" + accum.writeln( + f"CREATE OR REPLACE FUNCTION {func_name}(", + f" geo_arg {geo_type}, a_moc smoc) RETURNS BOOL AS $body$", + f" SELECT smoc(max_order(a_moc), geo_arg) {operator} a_moc", + f" $body$ LANGUAGE SQL STABLE;") + emit_op_def(accum, operator, + geo_type, "smoc", + func_name, + commutator) + + accum.writeln() + + func_name = f"smoc_{func_stem}_{geo_type}" + accum.writeln( + f"CREATE OR REPLACE FUNCTION {func_name}(", + f" a_moc smoc, geo_arg {geo_type}) RETURNS BOOL AS $body$", + f" SELECT a_moc {operator} smoc(max_order(a_moc), geo_arg)", + f" $body$ LANGUAGE SQL STABLE;") + emit_op_def(accum, operator, + "smoc", geo_type, + func_name, + commutator) + + accum.writeln() + + +def main(): + accum = Accum() + + accum.writeln("-- MOC/geometry automatic casts.") + accum.writeln(f"-- Generated {datetime.date.today()} by {sys.argv[0]}.") + accum.writeln(f"-- Re-generation needs to be triggered manually.") + accum.writeln() + emit_drop_code(accum) + + accum.introduce_section(" smoc/geo OVERLAPS") + for op_def in OVERLAP_DEFS: + emit_op_and_func(accum, op_def) + accum.writeln() + + accum.introduce_section(" smoc/geo INTERSECTS") + for op_def in INTERSECT_DEFS: + emit_op_and_func(accum, op_def) + accum.writeln() + + print(accum.content) + + +if __name__=="__main__": + main() diff --git a/doc/operators.sgm b/doc/operators.sgm index fe22550..7162a01 100644 --- a/doc/operators.sgm +++ b/doc/operators.sgm @@ -231,10 +231,19 @@ <para> An overlap or contain operator does not exist for all combinations of data types. - For instance, scircle <@ <type>spoint</type> is + For instance, scircle <@ <type>spoint</type> is useless because a spherical point can never contain a spherical circle. </para> + <para> + When one of the arguments of such an operator is a MOC + and the other is an scircle or an spoly, the non-MOC argument + is converted to a MOC of the order of the maximum order of + the MOC. When comparing against a MOC-valued column, it + is usually much faster to explicitly convert the geometry + using the smoc constructor, as the conversion will then + only happen once. + </para> <example> <title>Is the left circle contained by the right circle?</title> <programlisting> @@ -255,6 +264,40 @@ <![CDATA[(1 row)]]> </programlisting> </example> + + <example> + <title>Overlaps between a circle and a moc</title> + <programlisting> +<![CDATA[sql> SELECT scircle '<(37d, 5d), 0.25d>' <@ smoc('4/1117') AS test ;]]> +<![CDATA[ test]]> +<![CDATA[------]]> +<![CDATA[ f]]> +<![CDATA[(1 row)]]> + </programlisting> + </example> + + <example> + <title>Overlaps between a circle and a moc with explicit order</title> + <programlisting> +<![CDATA[sql> SELECT scircle '<(37d, 5d), 0.25d>' <@ smoc('4/1117 5/') AS test ;]]> +<![CDATA[ test]]> +<![CDATA[------]]> +<![CDATA[ t]]> +<![CDATA[(1 row)]]> + </programlisting> + </example> + + <example> + <title>Overlaps between a circle and a moc with explicit cast (normally faster)</title> + <programlisting> +<![CDATA[sql> SELECT smoc(5, scircle '<(37d, 5d), 0.25d>') <@ smoc('4/1117 5/') AS test ;]]> +<![CDATA[ test]]> +<![CDATA[------]]> +<![CDATA[ t]]> +<![CDATA[(1 row)]]> + </programlisting> + </example> + </sect2> <sect2 id="op.cross"> diff --git a/expected/mocautocast.out b/expected/mocautocast.out new file mode 100644 index 0000000..9be0ffc --- /dev/null +++ b/expected/mocautocast.out @@ -0,0 +1,209 @@ +-- These are MOCs generated by +-- SELECT smoc(mocorder, scircle '<(27d, -43d), 0.1d>'); +-- intended to check automatic casts of other geometries. +CREATE TABLE varorders ( + mocorder smallint, + geo smoc); +INSERT INTO varorders (mocorder, geo) VALUES + (1, smoc('1/32 34 1/')), + (-3, smoc('1/32 34 3/')), + (3, smoc('3/547-548 550 553 3/')), + (7, smoc('7/140857-140860 140862 140944-140945 7/')), + (-7, smoc('1/32 34 7/')); +-- OVERLAPS smoc/scircle +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gsupc +FROM varorders +WHERE geo @> scircle '<(30d, -43d), 1d>'; + gsupc +------- + -7/-3 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gnsupc +FROM varorders +WHERE geo !@> scircle '<(30d, -43d), 1d>'; + gnsupc +---------- + 1/ 3/ 7 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) csubg +FROM varorders +WHERE scircle '<(30d, -43d), 1d>' <@ geo; + csubg +------- + -7/-3 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cnsubg +FROM varorders +WHERE scircle '<(30d, -43d), 1d>' !<@ geo; + cnsubg +---------- + 1/ 3/ 7 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gsubc +FROM varorders +WHERE geo <@ scircle '<(30d, -43d), 1d>'; + gsubc +------- + 1 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gnsubc +FROM varorders +WHERE geo !<@ scircle '<(30d, -43d), 1d>'; + gnsubc +------------- + -7/-3/ 3/ 7 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) csupg +FROM varorders +WHERE scircle '<(30d, -43d), 1d>' @> geo; + csupg +------- + 1 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cnsupg +FROM varorders +WHERE scircle '<(30d, -43d), 1d>' !@> geo; + cnsupg +------------- + -7/-3/ 3/ 7 +(1 row) + +-- OVERLAPS smoc/spoly +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gsupp +FROM varorders +WHERE geo @> spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}'); + gsupp +------- + -7/-3 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gnsupp +FROM varorders +WHERE geo !@> spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}'); + gnsupp +---------- + 1/ 3/ 7 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) psubg +FROM varorders +WHERE spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}') <@ geo; + psubg +------- + -7/-3 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) pnsubg +FROM varorders +WHERE spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}') !<@ geo; + pnsubg +---------- + 1/ 3/ 7 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gsubp +FROM varorders +WHERE geo <@ spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}'); + gsubp +------- + 1 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gnsubp +FROM varorders +WHERE geo !<@ spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}'); + gnsubp +------------- + -7/-3/ 3/ 7 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) psupg +FROM varorders +WHERE spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}') @> geo; + psupg +------- + 1 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) pnsupg +FROM varorders +WHERE spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}') !@> geo; + pnsupg +------------- + -7/-3/ 3/ 7 +(1 row) + +-- INTERSECTS smoc/scircle +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cgim +FROM varorders +WHERE scircle '<(45d, -40d), 1d>' && geo; + cgim +---------- + -7/-3/ 1 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cgnim +FROM varorders +WHERE scircle '<(45d, -40d), 1d>' !&& geo; + cgnim +------- + 3/ 7 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cmig +FROM varorders +WHERE geo && scircle '<(45d, -40d), 1d>'; + cmig +---------- + -7/-3/ 1 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cnim +FROM varorders +WHERE geo !&& scircle '<(45d, -40d), 1d>'; + cnim +------- + 3/ 7 +(1 row) + +-- INTERSECTS smoc/spoly +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cgim +FROM varorders +WHERE spoly '{(51.1d, -50.1d), (45.8d, -47.5), (46.7d, -43.7d)}' && geo; + cgim +---------- + -7/-3/ 1 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cgnim +FROM varorders +WHERE spoly '{(51.1d, -50.1d), (45.8d, -47.5), (46.7d, -43.7d)}' !&& geo; + cgnim +------- + 3/ 7 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cmig +FROM varorders +WHERE geo && spoly '{(51.1d, -50.1d), (45.8d, -47.5), (46.7d, -43.7d)}'; + cmig +---------- + -7/-3/ 1 +(1 row) + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cnim +FROM varorders +WHERE geo !&& spoly '{(51.1d, -50.1d), (45.8d, -47.5), (46.7d, -43.7d)}'; + cnim +------- + 3/ 7 +(1 row) + +DROP TABLE varorders; diff --git a/pg_sphere--1.2.0.sql.in b/pg_sphere--1.2.1.sql.in similarity index 100% rename from pg_sphere--1.2.0.sql.in rename to pg_sphere--1.2.1.sql.in diff --git a/pg_sphere.control b/pg_sphere.control index eacc07b..2b64f2f 100644 --- a/pg_sphere.control +++ b/pg_sphere.control @@ -1,5 +1,5 @@ # pg_sphere extension comment = 'spherical objects with useful functions, operators and index support' -default_version = '1.2.0' +default_version = '1.2.1' module_pathname = '$libdir/pg_sphere' relocatable = true diff --git a/pgs_moc_geo_casts.sql.in b/pgs_moc_geo_casts.sql.in new file mode 100644 index 0000000..025cf04 --- /dev/null +++ b/pgs_moc_geo_casts.sql.in @@ -0,0 +1,374 @@ +-- MOC/geometry automatic casts. +-- Generated 2021-12-08 by gen_moccast.py. +-- You probably do not want to re-generate this; fixes need to be updates +-- on the SQL level. + + +-- ################################# +-- Cleanup +-- DROP OPERATOR IF EXISTS +-- <@ (smoc, scircle), +-- <@ (scircle, smoc), +-- <@ (smoc, spoly), +-- <@ (spoly, smoc), +-- !<@ (smoc, scircle), +-- !<@ (scircle, smoc), +-- !<@ (smoc, spoly), +-- !<@ (spoly, smoc), +-- @> (smoc, scircle), +-- @> (scircle, smoc), +-- @> (smoc, spoly), +-- @> (spoly, smoc), +-- !@> (smoc, scircle), +-- !@> (scircle, smoc), +-- !@> (smoc, spoly), +-- !@> (spoly, smoc); + +-- ################################# +-- smoc/geo OVERLAPS +CREATE OR REPLACE FUNCTION scircle_subset_smoc( + geo_arg scircle, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) <@ a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR <@ ( + LEFTARG = scircle, + RIGHTARG = smoc, + PROCEDURE = scircle_subset_smoc, + COMMUTATOR = '@>', + NEGATOR = '!<@', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_subset_scircle( + a_moc smoc, geo_arg scircle) RETURNS BOOL AS $body$ + SELECT a_moc <@ smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR <@ ( + LEFTARG = smoc, + RIGHTARG = scircle, + PROCEDURE = smoc_subset_scircle, + COMMUTATOR = '@>', + NEGATOR = '!<@', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION spoly_subset_smoc( + geo_arg spoly, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) <@ a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR <@ ( + LEFTARG = spoly, + RIGHTARG = smoc, + PROCEDURE = spoly_subset_smoc, + COMMUTATOR = '@>', + NEGATOR = '!<@', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_subset_spoly( + a_moc smoc, geo_arg spoly) RETURNS BOOL AS $body$ + SELECT a_moc <@ smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR <@ ( + LEFTARG = smoc, + RIGHTARG = spoly, + PROCEDURE = smoc_subset_spoly, + COMMUTATOR = '@>', + NEGATOR = '!<@', + RESTRICT = contsel, + JOIN = contjoinsel +); + + +CREATE OR REPLACE FUNCTION scircle_not_subset_smoc( + geo_arg scircle, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) !<@ a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !<@ ( + LEFTARG = scircle, + RIGHTARG = smoc, + PROCEDURE = scircle_not_subset_smoc, + COMMUTATOR = '!@>', + NEGATOR = '<@', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_not_subset_scircle( + a_moc smoc, geo_arg scircle) RETURNS BOOL AS $body$ + SELECT a_moc !<@ smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !<@ ( + LEFTARG = smoc, + RIGHTARG = scircle, + PROCEDURE = smoc_not_subset_scircle, + COMMUTATOR = '!@>', + NEGATOR = '<@', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION spoly_not_subset_smoc( + geo_arg spoly, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) !<@ a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !<@ ( + LEFTARG = spoly, + RIGHTARG = smoc, + PROCEDURE = spoly_not_subset_smoc, + COMMUTATOR = '!@>', + NEGATOR = '<@', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_not_subset_spoly( + a_moc smoc, geo_arg spoly) RETURNS BOOL AS $body$ + SELECT a_moc !<@ smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !<@ ( + LEFTARG = smoc, + RIGHTARG = spoly, + PROCEDURE = smoc_not_subset_spoly, + COMMUTATOR = '!@>', + NEGATOR = '<@', + RESTRICT = contsel, + JOIN = contjoinsel +); + + +CREATE OR REPLACE FUNCTION scircle_superset_smoc( + geo_arg scircle, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) @> a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR @> ( + LEFTARG = scircle, + RIGHTARG = smoc, + PROCEDURE = scircle_superset_smoc, + COMMUTATOR = '<@', + NEGATOR = '!@>', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_superset_scircle( + a_moc smoc, geo_arg scircle) RETURNS BOOL AS $body$ + SELECT a_moc @> smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR @> ( + LEFTARG = smoc, + RIGHTARG = scircle, + PROCEDURE = smoc_superset_scircle, + COMMUTATOR = '<@', + NEGATOR = '!@>', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION spoly_superset_smoc( + geo_arg spoly, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) @> a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR @> ( + LEFTARG = spoly, + RIGHTARG = smoc, + PROCEDURE = spoly_superset_smoc, + COMMUTATOR = '<@', + NEGATOR = '!@>', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_superset_spoly( + a_moc smoc, geo_arg spoly) RETURNS BOOL AS $body$ + SELECT a_moc @> smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR @> ( + LEFTARG = smoc, + RIGHTARG = spoly, + PROCEDURE = smoc_superset_spoly, + COMMUTATOR = '<@', + NEGATOR = '!@>', + RESTRICT = contsel, + JOIN = contjoinsel +); + + +CREATE OR REPLACE FUNCTION scircle_not_superset_smoc( + geo_arg scircle, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) !@> a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !@> ( + LEFTARG = scircle, + RIGHTARG = smoc, + PROCEDURE = scircle_not_superset_smoc, + COMMUTATOR = '!<@', + NEGATOR = '@>', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_not_superset_scircle( + a_moc smoc, geo_arg scircle) RETURNS BOOL AS $body$ + SELECT a_moc !@> smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !@> ( + LEFTARG = smoc, + RIGHTARG = scircle, + PROCEDURE = smoc_not_superset_scircle, + COMMUTATOR = '!<@', + NEGATOR = '@>', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION spoly_not_superset_smoc( + geo_arg spoly, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) !@> a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !@> ( + LEFTARG = spoly, + RIGHTARG = smoc, + PROCEDURE = spoly_not_superset_smoc, + COMMUTATOR = '!<@', + NEGATOR = '@>', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_not_superset_spoly( + a_moc smoc, geo_arg spoly) RETURNS BOOL AS $body$ + SELECT a_moc !@> smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !@> ( + LEFTARG = smoc, + RIGHTARG = spoly, + PROCEDURE = smoc_not_superset_spoly, + COMMUTATOR = '!<@', + NEGATOR = '@>', + RESTRICT = contsel, + JOIN = contjoinsel +); + + + +-- ################################# +-- smoc/geo INTERSECTS +CREATE OR REPLACE FUNCTION scircle_intersect_smoc( + geo_arg scircle, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) && a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR && ( + LEFTARG = scircle, + RIGHTARG = smoc, + PROCEDURE = scircle_intersect_smoc, + COMMUTATOR = '&&', + NEGATOR = '!&&', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_intersect_scircle( + a_moc smoc, geo_arg scircle) RETURNS BOOL AS $body$ + SELECT a_moc && smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR && ( + LEFTARG = smoc, + RIGHTARG = scircle, + PROCEDURE = smoc_intersect_scircle, + COMMUTATOR = '&&', + NEGATOR = '!&&', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION spoly_intersect_smoc( + geo_arg spoly, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) && a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR && ( + LEFTARG = spoly, + RIGHTARG = smoc, + PROCEDURE = spoly_intersect_smoc, + COMMUTATOR = '&&', + NEGATOR = '!&&', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_intersect_spoly( + a_moc smoc, geo_arg spoly) RETURNS BOOL AS $body$ + SELECT a_moc && smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR && ( + LEFTARG = smoc, + RIGHTARG = spoly, + PROCEDURE = smoc_intersect_spoly, + COMMUTATOR = '&&', + NEGATOR = '!&&', + RESTRICT = contsel, + JOIN = contjoinsel +); + + +CREATE OR REPLACE FUNCTION scircle_not_intersect_smoc( + geo_arg scircle, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) !&& a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !&& ( + LEFTARG = scircle, + RIGHTARG = smoc, + PROCEDURE = scircle_not_intersect_smoc, + COMMUTATOR = '!&&', + NEGATOR = '&&', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_not_intersect_scircle( + a_moc smoc, geo_arg scircle) RETURNS BOOL AS $body$ + SELECT a_moc !&& smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !&& ( + LEFTARG = smoc, + RIGHTARG = scircle, + PROCEDURE = smoc_not_intersect_scircle, + COMMUTATOR = '!&&', + NEGATOR = '&&', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION spoly_not_intersect_smoc( + geo_arg spoly, a_moc smoc) RETURNS BOOL AS $body$ + SELECT smoc(max_order(a_moc), geo_arg) !&& a_moc + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !&& ( + LEFTARG = spoly, + RIGHTARG = smoc, + PROCEDURE = spoly_not_intersect_smoc, + COMMUTATOR = '!&&', + NEGATOR = '&&', + RESTRICT = contsel, + JOIN = contjoinsel +); + +CREATE OR REPLACE FUNCTION smoc_not_intersect_spoly( + a_moc smoc, geo_arg spoly) RETURNS BOOL AS $body$ + SELECT a_moc !&& smoc(max_order(a_moc), geo_arg) + $body$ LANGUAGE SQL STABLE; +CREATE OPERATOR !&& ( + LEFTARG = smoc, + RIGHTARG = spoly, + PROCEDURE = smoc_not_intersect_spoly, + COMMUTATOR = '!&&', + NEGATOR = '&&', + RESTRICT = contsel, + JOIN = contjoinsel +); + + + diff --git a/sql/mocautocast.sql b/sql/mocautocast.sql new file mode 100644 index 0000000..165f25f --- /dev/null +++ b/sql/mocautocast.sql @@ -0,0 +1,123 @@ +-- These are MOCs generated by +-- SELECT smoc(mocorder, scircle '<(27d, -43d), 0.1d>'); +-- intended to check automatic casts of other geometries. + +CREATE TABLE varorders ( + mocorder smallint, + geo smoc); +INSERT INTO varorders (mocorder, geo) VALUES + (1, smoc('1/32 34 1/')), + (-3, smoc('1/32 34 3/')), + (3, smoc('3/547-548 550 553 3/')), + (7, smoc('7/140857-140860 140862 140944-140945 7/')), + (-7, smoc('1/32 34 7/')); + +-- OVERLAPS smoc/scircle + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gsupc +FROM varorders +WHERE geo @> scircle '<(30d, -43d), 1d>'; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gnsupc +FROM varorders +WHERE geo !@> scircle '<(30d, -43d), 1d>'; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) csubg +FROM varorders +WHERE scircle '<(30d, -43d), 1d>' <@ geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cnsubg +FROM varorders +WHERE scircle '<(30d, -43d), 1d>' !<@ geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gsubc +FROM varorders +WHERE geo <@ scircle '<(30d, -43d), 1d>'; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gnsubc +FROM varorders +WHERE geo !<@ scircle '<(30d, -43d), 1d>'; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) csupg +FROM varorders +WHERE scircle '<(30d, -43d), 1d>' @> geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cnsupg +FROM varorders +WHERE scircle '<(30d, -43d), 1d>' !@> geo; + + +-- OVERLAPS smoc/spoly + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gsupp +FROM varorders +WHERE geo @> spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}'); + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gnsupp +FROM varorders +WHERE geo !@> spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}'); + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) psubg +FROM varorders +WHERE spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}') <@ geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) pnsubg +FROM varorders +WHERE spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}') !<@ geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gsubp +FROM varorders +WHERE geo <@ spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}'); + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) gnsubp +FROM varorders +WHERE geo !<@ spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}'); + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) psupg +FROM varorders +WHERE spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}') @> geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) pnsupg +FROM varorders +WHERE spoly('{(26d,-42d), (26d,-41d), (27d,-41d)}') !@> geo; + + +-- INTERSECTS smoc/scircle + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cgim +FROM varorders +WHERE scircle '<(45d, -40d), 1d>' && geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cgnim +FROM varorders +WHERE scircle '<(45d, -40d), 1d>' !&& geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cmig +FROM varorders +WHERE geo && scircle '<(45d, -40d), 1d>'; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cnim +FROM varorders +WHERE geo !&& scircle '<(45d, -40d), 1d>'; + + +-- INTERSECTS smoc/spoly + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cgim +FROM varorders +WHERE spoly '{(51.1d, -50.1d), (45.8d, -47.5), (46.7d, -43.7d)}' && geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cgnim +FROM varorders +WHERE spoly '{(51.1d, -50.1d), (45.8d, -47.5), (46.7d, -43.7d)}' !&& geo; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cmig +FROM varorders +WHERE geo && spoly '{(51.1d, -50.1d), (45.8d, -47.5), (46.7d, -43.7d)}'; + +SELECT string_agg(to_char(mocorder, '9'), '/' ORDER BY mocorder) cnim +FROM varorders +WHERE geo !&& spoly '{(51.1d, -50.1d), (45.8d, -47.5), (46.7d, -43.7d)}'; + + +DROP TABLE varorders; From 9420a22c0c5943670f18a5d0708ed95f307d64bc Mon Sep 17 00:00:00 2001 From: Markus Demleitner <m@tfiu.de> Date: Tue, 14 Dec 2021 11:16:27 +0100 Subject: [PATCH 4/5] Enabling operator dropping in the moc-vs-geometry SQL. I hadn't done this before because the warnings spoiled the regression expectation. I'm now shutting those up for while I'm doing the dropping. --- pgs_moc_geo_casts.sql.in | 37 ++++++++++++++++++++----------------- 1 file changed, 20 insertions(+), 17 deletions(-) diff --git a/pgs_moc_geo_casts.sql.in b/pgs_moc_geo_casts.sql.in index 025cf04..3ace187 100644 --- a/pgs_moc_geo_casts.sql.in +++ b/pgs_moc_geo_casts.sql.in @@ -6,23 +6,26 @@ -- ################################# -- Cleanup --- DROP OPERATOR IF EXISTS --- <@ (smoc, scircle), --- <@ (scircle, smoc), --- <@ (smoc, spoly), --- <@ (spoly, smoc), --- !<@ (smoc, scircle), --- !<@ (scircle, smoc), --- !<@ (smoc, spoly), --- !<@ (spoly, smoc), --- @> (smoc, scircle), --- @> (scircle, smoc), --- @> (smoc, spoly), --- @> (spoly, smoc), --- !@> (smoc, scircle), --- !@> (scircle, smoc), --- !@> (smoc, spoly), --- !@> (spoly, smoc); + +set client_min_messages = 'warning'; +DROP OPERATOR IF EXISTS + <@ (smoc, scircle), + <@ (scircle, smoc), + <@ (smoc, spoly), + <@ (spoly, smoc), + !<@ (smoc, scircle), + !<@ (scircle, smoc), + !<@ (smoc, spoly), + !<@ (spoly, smoc), + @> (smoc, scircle), + @> (scircle, smoc), + @> (smoc, spoly), + @> (spoly, smoc), + !@> (smoc, scircle), + !@> (scircle, smoc), + !@> (smoc, spoly), + !@> (spoly, smoc); +reset client_min_messages; -- ################################# -- smoc/geo OVERLAPS From 5e7ab4e313ee3af507093eaee9a9db64fb9c2386 Mon Sep 17 00:00:00 2001 From: Markus Demleitner <m@tfiu.de> Date: Mon, 5 Sep 2022 16:30:49 +0200 Subject: [PATCH 5/5] Attempting to fix upgrade script for pg 9.x. --- Makefile | 3 +++ 1 file changed, 3 insertions(+) diff --git a/Makefile b/Makefile index c3c5296..6387ba7 100644 --- a/Makefile +++ b/Makefile @@ -200,6 +200,9 @@ endif pg_sphere--1.2.0--1.2.1.sql: pgs_moc_geo_casts.sql.in cat $^ > $@ +ifeq ($(has_parallel), n) + sed -i -e '/PARALLEL/d' $@ # version $(pg_version) does not have support for PARALLEL +endif # end of local stuff