From 89323fe4b7042db0d1499b125e460e02725b4d24 Mon Sep 17 00:00:00 2001 From: Even Rouault Date: Sun, 10 Mar 2024 19:52:21 +0100 Subject: [PATCH] Database: move final consistency checks on transformations as insert time triggers --- data/sql/commit.sql | 135 ----------------------- data/sql/consistency_checks_triggers.sql | 117 ++++++++++++++++++++ 2 files changed, 117 insertions(+), 135 deletions(-) diff --git a/data/sql/commit.sql b/data/sql/commit.sql index 081d2a7f30..1677f9dec2 100644 --- a/data/sql/commit.sql +++ b/data/sql/commit.sql @@ -106,141 +106,6 @@ FOR EACH ROW BEGIN cov.target_crs_auth_name || cov.target_crs_code NOT IN (SELECT auth_name || code FROM crs_view)); - -- check that grids with NTv2 method are properly registered - SELECT RAISE(ABORT, 'One grid_transformation with NTv2 has not its source_crs in geodetic_crs table with type = ''geographic 2D''') - WHERE EXISTS (SELECT * FROM grid_transformation g WHERE - g.method_name = 'NTv2' AND - g.source_crs_auth_name || g.source_crs_code NOT IN - (SELECT auth_name || code FROM geodetic_crs - WHERE type = 'geographic 2D')); - SELECT RAISE(ABORT, 'One grid_transformation with NTv2 has not its target_crs in geodetic_crs table with type = ''geographic 2D''') - WHERE EXISTS (SELECT * FROM grid_transformation g WHERE - g.method_name = 'NTv2' AND - g.target_crs_auth_name || g.target_crs_code NOT IN - (SELECT auth_name || code FROM geodetic_crs - WHERE type = 'geographic 2D')); - - -- check that grids with Geographic3D to GravityRelatedHeight method are properly registered - SELECT RAISE(ABORT, 'One grid_transformation with Geographic3D to GravityRelatedHeight has not its target_crs in vertical_crs table') - WHERE EXISTS (SELECT * FROM grid_transformation g WHERE - g.deprecated = 0 AND - g.method_name LIKE 'Geographic3D to GravityRelatedHeight%' AND - g.target_crs_auth_name || g.target_crs_code NOT IN - (SELECT auth_name || code FROM vertical_crs)); - SELECT RAISE(ABORT, 'One grid_transformation with Geographic3D to GravityRelatedHeight or Geog3D to Geog2D+XXX has not its source_crs in geodetic_crs table with type = ''geographic 3D''') - WHERE EXISTS (SELECT * FROM grid_transformation g WHERE - g.deprecated = 0 AND - (g.method_name LIKE 'Geographic3D to %' OR g.method_name LIKE 'Geog3D to %') AND - g.source_crs_auth_name || g.source_crs_code NOT IN - (SELECT auth_name || code FROM geodetic_crs - WHERE type = 'geographic 3D')); - - -- check that grids with 'Vertical Offset by Grid Interpolation' methods are properly registered - SELECT RAISE(ABORT, 'One grid_transformation with Vertical Offset by Grid Interpolation has not its source_crs in vertical_crs table') - WHERE EXISTS (SELECT * FROM grid_transformation g WHERE - g.method_name LIKE 'Vertical Offset by Grid Interpolation%' AND - g.source_crs_auth_name || g.source_crs_code NOT IN - (SELECT auth_name || code FROM vertical_crs)); - SELECT RAISE(ABORT, 'One grid_transformation with Vertical Offset by Grid Interpolation has not its target_crs in vertical_crs table') - WHERE EXISTS (SELECT * FROM grid_transformation g WHERE - g.method_name LIKE 'Vertical Offset by Grid Interpolation%' AND - g.target_crs_auth_name || g.target_crs_code NOT IN - (SELECT auth_name || code FROM vertical_crs)); - - -- check that Helmert transformations have source and target of the same nature (the fkey already checks they are geodetic_crs) - SELECT RAISE(ABORT, 'One helmert_transformation has a source CRS of a different nature than its target CRS') - WHERE EXISTS (SELECT helmert_transformation.auth_name, - helmert_transformation.code, - helmert_transformation.name, - crs1.type AS crs1_type, - crs2.type AS crs2_type - FROM helmert_transformation - JOIN geodetic_crs crs1 ON - crs1.auth_name = source_crs_auth_name AND crs1.code = source_crs_code - JOIN geodetic_crs crs2 ON - crs2.auth_name = target_crs_auth_name AND crs2.code = target_crs_code - WHERE helmert_transformation.deprecated = 0 AND crs1.type != crs2.type); - - -- check that the method used by a Helmert transformation is consistent with the dimensionality of the CRS - SELECT RAISE(ABORT, 'The domain of the method of helmert_transformation is not consistent with the dimensionality of the CRS') - WHERE EXISTS (SELECT helmert_transformation.auth_name, - helmert_transformation.code, - helmert_transformation.name, - helmert_transformation.method_name, - crs.type AS crs_type - FROM helmert_transformation - JOIN geodetic_crs crs ON - crs.auth_name = source_crs_auth_name AND crs.code = source_crs_code - WHERE helmert_transformation.deprecated = 0 AND - ((method_name LIKE '%geog2D domain%' AND crs.type != 'geographic 2D') OR - (method_name LIKE '%geog3D domain%' AND crs.type != 'geographic 3D') OR - (method_name LIKE '%geocentric domain%' AND crs.type != 'geocentric'))); - - -- check that a time-dependent Helmert transformation has its source or target CRS being dyanmic - SELECT RAISE(ABORT, 'A time-dependent Helmert transformations has its source and target CRS both non-dynamic') - WHERE EXISTS (SELECT helmert_transformation.auth_name, - helmert_transformation.code, - helmert_transformation.name - FROM helmert_transformation - JOIN geodetic_crs crs1 ON - crs1.auth_name = source_crs_auth_name AND crs1.code = source_crs_code - JOIN geodetic_crs crs2 ON - crs2.auth_name = target_crs_auth_name AND crs2.code = target_crs_code - JOIN geodetic_datum gd1 ON - gd1.auth_name = crs1.datum_auth_name AND gd1.code = crs1.datum_code - JOIN geodetic_datum gd2 ON - gd2.auth_name = crs2.datum_auth_name AND gd2.code = crs2.datum_code - WHERE helmert_transformation.deprecated = 0 AND - method_name LIKE 'Time-dependent%' AND - gd1.frame_reference_epoch IS NULL AND - gd2.frame_reference_epoch IS NULL); - - -- check that transformations operations between vertical CRS are from/into a vertical CRS - SELECT RAISE(ABORT, 'A transformation operating on vertical CRS has a source CRS not being a vertical CRS') - WHERE EXISTS (SELECT other_transformation.auth_name, - other_transformation.code, - other_transformation.name - FROM other_transformation - LEFT JOIN vertical_crs crs ON - crs.auth_name = source_crs_auth_name AND crs.code = source_crs_code - WHERE other_transformation.deprecated = 0 AND - method_name IN ('Vertical Offset', 'Height Depth Reversal', 'Change of Vertical Unit') AND - crs.code IS NULL); - SELECT RAISE(ABORT, 'AA transformation operating on vertical CRS has a target CRS not being a vertical CRS') - WHERE EXISTS (SELECT other_transformation.auth_name, - other_transformation.code, - other_transformation.name - FROM other_transformation - LEFT JOIN vertical_crs crs ON - crs.auth_name = target_crs_auth_name AND crs.code = target_crs_code - WHERE other_transformation.deprecated = 0 AND - method_name IN ('Vertical Offset', 'Height Depth Reversal', 'Change of Vertical Unit') AND - crs.code IS NULL); - - -- check that 'Geographic2D with Height Offsets' transformations have a compound CRS with a geog2D as source - SELECT RAISE(ABORT, 'A transformation Geographic2D with Height Offsets does not have a compound CRS with a geog2D as source') - WHERE EXISTS (SELECT other_transformation.auth_name, - other_transformation.code, - other_transformation.name - FROM other_transformation - LEFT JOIN compound_crs ccrs ON - ccrs.auth_name = source_crs_auth_name AND ccrs.code = source_crs_code - LEFT JOIN geodetic_crs gcrs ON - gcrs.auth_name = horiz_crs_auth_name AND gcrs.code = horiz_crs_code - WHERE other_transformation.deprecated = 0 AND - method_name = 'Geographic2D with Height Offsets' AND - (gcrs.code IS NULL OR gcrs.type != 'geographic 2D')); - SELECT RAISE(ABORT, 'A transformation Geographic2D with Height Offsets does not have a geographic 3D CRS as target') - WHERE EXISTS (SELECT other_transformation.auth_name, - other_transformation.code, - other_transformation.name - FROM other_transformation - LEFT JOIN geodetic_crs gcrs ON - gcrs.auth_name = target_crs_auth_name AND gcrs.code = target_crs_code - WHERE other_transformation.deprecated = 0 AND - method_name = 'Geographic2D with Height Offsets' AND - (gcrs.type IS NULL OR gcrs.type != 'geographic 3D')); - -- check that transformations intersect the area of use of their source/target CRS -- EPSG, ESRI and IGNF have cases where this does not hold. SELECT RAISE(ABORT, 'The area of use of at least one coordinate_operation does not intersect the one of its source CRS') diff --git a/data/sql/consistency_checks_triggers.sql b/data/sql/consistency_checks_triggers.sql index 713fd9b7e9..18716b8e53 100644 --- a/data/sql/consistency_checks_triggers.sql +++ b/data/sql/consistency_checks_triggers.sql @@ -285,6 +285,47 @@ FOR EACH ROW BEGIN WHERE EXISTS(SELECT 1 FROM geodetic_crs crs WHERE crs.auth_name = NEW.source_crs_auth_name AND crs.code = NEW.source_crs_code AND crs.deprecated != 0) AND NEW.deprecated = 0 AND NOT (NEW.auth_name = 'ESRI') AND NOT (NEW.auth_name = 'EPSG' AND NEW.code = '5375'); -- Issue with EPSG:5375 "SIRGAS-Chile to WGS 84 (1)" SELECT RAISE(ABORT, 'insert on helmert_transformation violates constraint: target_crs must not be deprecated when helmert_transformation is not deprecated') WHERE EXISTS(SELECT 1 FROM geodetic_crs crs WHERE crs.auth_name = NEW.target_crs_auth_name AND crs.code = NEW.target_crs_code AND crs.deprecated != 0) AND NEW.deprecated = 0 AND NOT (NEW.auth_name = 'ESRI'); + + -- check that source and target of the same nature + SELECT RAISE(ABORT, 'insert on helmert_transformation violates constraint: source CRS and target CRS must have same geodetic_crs.type') + WHERE EXISTS (SELECT 1 FROM geodetic_crs crs1, geodetic_crs crs2 WHERE + crs1.auth_name = NEW.source_crs_auth_name AND crs1.code = NEW.source_crs_code + AND crs2.auth_name = NEW.target_crs_auth_name AND crs2.code = NEW.target_crs_code + AND NEW.deprecated = 0 AND crs1.type != crs2.type); + + -- check that the method used by a Helmert transformation is consistent with the dimensionality of the CRS + SELECT RAISE(ABORT, 'insert on helmert_transformation violates constraint: the domain of the method of helmert_transformation should be consistent with the dimensionality of the CRS') + WHERE NEW.deprecated = 0 AND + EXISTS (SELECT 1 FROM geodetic_crs crs + LEFT JOIN coordinate_operation_method m ON + NEW.method_auth_name = m.auth_name AND NEW.method_code = m.code + WHERE + crs.auth_name = NEW.source_crs_auth_name AND crs.code = NEW.source_crs_code AND + ((m.name LIKE '%geog2D domain%' AND crs.type != 'geographic 2D') OR + (m.name LIKE '%geog3D domain%' AND crs.type != 'geographic 3D') OR + (m.name LIKE '%geocentric domain%' AND crs.type != 'geocentric'))); + + -- check that a time-dependent Helmert transformation has its source or target CRS being dyanmic + SELECT RAISE(ABORT, 'insert on helmert_transformation violates constraint: a time-dependent Helmert transformations should have at least one of its source or target CRS dynamic') + WHERE NEW.deprecated = 0 + AND EXISTS (SELECT 1 FROM coordinate_operation_method m + WHERE NEW.method_auth_name = m.auth_name AND NEW.method_code = m.code AND + m.name LIKE 'Time-dependent%') + AND EXISTS ( + SELECT 1 FROM geodetic_crs crs + JOIN geodetic_datum gd ON + gd.auth_name = crs.datum_auth_name AND gd.code = crs.datum_code + WHERE crs.auth_name = NEW.source_crs_auth_name AND + crs.code = NEW.source_crs_code AND + gd.frame_reference_epoch IS NULL) + AND EXISTS ( + SELECT 1 FROM geodetic_crs crs + JOIN geodetic_datum gd ON + gd.auth_name = crs.datum_auth_name AND gd.code = crs.datum_code + WHERE crs.auth_name = NEW.target_crs_auth_name AND + crs.code = NEW.target_crs_code AND + gd.frame_reference_epoch IS NULL); + END; CREATE TRIGGER grid_transformation_insert_trigger @@ -312,6 +353,51 @@ FOR EACH ROW BEGIN WHERE EXISTS(SELECT 1 FROM crs_view crs WHERE crs.auth_name = NEW.source_crs_auth_name AND crs.code = NEW.source_crs_code AND crs.deprecated != 0) AND NEW.deprecated = 0 AND NOT (NEW.auth_name = 'ESRI'); SELECT RAISE(ABORT, 'insert on grid_transformation violates constraint: target_crs must not be deprecated when grid_transformation is not deprecated') WHERE EXISTS(SELECT 1 FROM crs_view crs WHERE crs.auth_name = NEW.target_crs_auth_name AND crs.code = NEW.target_crs_code AND crs.deprecated != 0) AND NEW.deprecated = 0 AND NOT (NEW.auth_name = 'ESRI'); + + -- check that grids with NTv2 method are properly registered + SELECT RAISE(ABORT, 'insert on grid_transformation violates constraint: grid_transformation with NTv2 must have its source_crs in geodetic_crs table with type = ''geographic 2D''') + WHERE NEW.method_name = 'NTv2' AND + NOT EXISTS (SELECT 1 FROM geodetic_crs crs WHERE + NEW.source_crs_auth_name = crs.auth_name AND + NEW.source_crs_code = crs.code AND + crs.type = 'geographic 2D'); + + SELECT RAISE(ABORT, 'insert on grid_transformation violates constraint: grid_transformation with NTv2 has have its target_crs in geodetic_crs table with type = ''geographic 2D''') + WHERE NEW.method_name = 'NTv2' AND + NOT EXISTS (SELECT 1 FROM geodetic_crs crs WHERE + NEW.target_crs_auth_name = crs.auth_name AND + NEW.target_crs_code = crs.code AND + crs.type = 'geographic 2D'); + + -- check that grids with Geographic3D to GravityRelatedHeight method are properly registered + SELECT RAISE(ABORT, 'insert on grid_transformation violates constraint: grid_transformation with Geographic3D to GravityRelatedHeight must have its target_crs in vertical_crs table') + WHERE NEW.deprecated = 0 AND + NEW.method_name LIKE 'Geographic3D to GravityRelatedHeight%' AND + NOT EXISTS (SELECT 1 FROM vertical_crs crs WHERE + NEW.target_crs_auth_name = crs.auth_name AND + NEW.target_crs_code = crs.code); + + SELECT RAISE(ABORT, 'insert on grid_transformation violates constraint: grid_transformation with Geographic3D to GravityRelatedHeight or Geog3D to Geog2D+XXX must have its source_crs in geodetic_crs table with type = ''geographic 3D''') + WHERE NEW.deprecated = 0 AND + (NEW.method_name LIKE 'Geographic3D to %' OR NEW.method_name LIKE 'Geog3D to %') AND + NOT EXISTS (SELECT 1 FROM geodetic_crs crs WHERE + NEW.source_crs_auth_name = crs.auth_name AND + NEW.source_crs_code = crs.code AND + crs.type = 'geographic 3D'); + + -- check that grids with 'Vertical Offset by Grid Interpolation' methods are properly registered + SELECT RAISE(ABORT, 'insert on grid_transformation violates constraint: grid_transformation with Vertical Offset by Grid Interpolation must have its source_crs in vertical_crs table') + WHERE NEW.method_name LIKE 'Vertical Offset by Grid Interpolation%' AND + NOT EXISTS (SELECT 1 FROM vertical_crs crs WHERE + NEW.source_crs_auth_name = crs.auth_name AND + NEW.source_crs_code = crs.code); + + SELECT RAISE(ABORT, 'insert on grid_transformation violates constraint: grid_transformation with Vertical Offset by Grid Interpolation must have its target_crs in vertical_crs table') + WHERE NEW.method_name LIKE 'Vertical Offset by Grid Interpolation%' AND + NOT EXISTS (SELECT 1 FROM vertical_crs crs WHERE + NEW.target_crs_auth_name = crs.auth_name AND + NEW.target_crs_code = crs.code); + END; CREATE TRIGGER grid_packages_insert_trigger @@ -363,6 +449,37 @@ FOR EACH ROW BEGIN WHERE EXISTS(SELECT 1 FROM crs_view crs WHERE crs.auth_name = NEW.source_crs_auth_name AND crs.code = NEW.source_crs_code AND crs.deprecated != 0) AND NEW.deprecated = 0 AND NOT (NEW.auth_name = 'ESRI'); SELECT RAISE(ABORT, 'insert on other_transformation violates constraint: target_crs must not be deprecated when other_transformation is not deprecated') WHERE EXISTS(SELECT 1 FROM crs_view crs WHERE crs.auth_name = NEW.target_crs_auth_name AND crs.code = NEW.target_crs_code AND crs.deprecated != 0) AND NEW.deprecated = 0 AND NOT (NEW.auth_name = 'ESRI'); + + -- check that transformations operations between vertical CRS are from/into a vertical CRS + SELECT RAISE(ABORT, 'insert on other_transformation violates constraint: transformation operating on vertical CRS must have a source CRS being a vertical CRS') + WHERE NEW.deprecated = 0 AND + NEW.method_name IN ('Vertical Offset', 'Height Depth Reversal', 'Change of Vertical Unit') AND + NOT EXISTS (SELECT 1 FROM vertical_crs crs WHERE + crs.auth_name = NEW.source_crs_auth_name AND crs.code = NEW.source_crs_code); + + SELECT RAISE(ABORT, 'insert on other_transformation violates constraint: transformation operating on vertical CRS must have a target CRS being a vertical CRS') + WHERE NEW.deprecated = 0 AND + NEW.method_name IN ('Vertical Offset', 'Height Depth Reversal', 'Change of Vertical Unit') AND + NOT EXISTS (SELECT 1 FROM vertical_crs crs WHERE + crs.auth_name = NEW.target_crs_auth_name AND crs.code = NEW.target_crs_code); + + -- check that 'Geographic2D with Height Offsets' transformations have a compound CRS with a geog2D as source + SELECT RAISE(ABORT, 'insert on other_transformation violates constraint: a transformation Geographic2D with Height Offsets must have a compound CRS with a geog2D as source') + WHERE NEW.deprecated = 0 AND + NEW.method_name = 'Geographic2D with Height Offsets' AND + NOT EXISTS (SELECT 1 FROM compound_crs ccrs + LEFT JOIN geodetic_crs gcrs ON + gcrs.auth_name = horiz_crs_auth_name AND gcrs.code = horiz_crs_code + WHERE + ccrs.auth_name = NEW.source_crs_auth_name AND ccrs.code = NEW.source_crs_code + AND gcrs.type = 'geographic 2D'); + + SELECT RAISE(ABORT, 'insert on other_transformation violates constraint: a transformation Geographic2D with Height Offsets must have a geographic 3D CRS as target') + WHERE NEW.deprecated = 0 AND + NEW.method_name = 'Geographic2D with Height Offsets' AND + NOT EXISTS (SELECT 1 FROM geodetic_crs gcrs WHERE + gcrs.auth_name = NEW.target_crs_auth_name AND gcrs.code = NEW.target_crs_code + AND gcrs.type = 'geographic 3D'); END; CREATE TRIGGER concatenated_operation_insert_trigger