Skip to content

Commit 642b527

Browse files
committed
Database: restrict the checks on name unicity to the 'official' authorities provided by upstream PROJ
1 parent a30fccf commit 642b527

File tree

2 files changed

+38
-7
lines changed

2 files changed

+38
-7
lines changed

data/sql/commit.sql

Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -28,6 +28,13 @@ FOR EACH ROW BEGIN
2828
SELECT RAISE(ABORT, 'corrupt definition of authority_list')
2929
WHERE (SELECT 1 FROM authority_list LIMIT 1) = 0;
3030

31+
-- check that the auth_name of all objects in object_view is recorded in builtin_authorities
32+
SELECT RAISE(ABORT, 'One or several authorities referenced in object_view are missing in builtin_authorities')
33+
WHERE EXISTS (
34+
SELECT DISTINCT o.auth_name FROM object_view o WHERE NOT EXISTS (
35+
SELECT 1 FROM builtin_authorities b WHERE o.auth_name = b.auth_name)
36+
);
37+
3138
-- check that a usage is registered for most objects where this is needed
3239
SELECT RAISE(ABORT, 'One or several objects lack a corresponding record in the usage table')
3340
WHERE EXISTS (

data/sql/proj_db_table_defs.sql

Lines changed: 31 additions & 7 deletions
Original file line numberDiff line numberDiff line change
@@ -306,6 +306,20 @@ CREATE TABLE vertical_crs(
306306
CONSTRAINT fk_vertical_crs_datum FOREIGN KEY (datum_auth_name, datum_code) REFERENCES vertical_datum(auth_name, code) ON DELETE CASCADE
307307
) WITHOUT ROWID;
308308

309+
-- Authorities provided by the upstream PROJ
310+
-- This is used to check unicity of object names
311+
CREATE TABLE builtin_authorities(auth_name TEXT NOT NULL PRIMARY KEY) WITHOUT ROWID;
312+
INSERT INTO builtin_authorities VALUES
313+
('EPSG'),
314+
('ESRI'),
315+
('IAU_2015'),
316+
('IGNF'),
317+
('NKG'),
318+
('NRCAN'),
319+
('OGC'),
320+
('PROJ')
321+
;
322+
309323
CREATE TRIGGER vertical_crs_insert_trigger
310324
BEFORE INSERT ON vertical_crs
311325
FOR EACH ROW BEGIN
@@ -314,7 +328,8 @@ FOR EACH ROW BEGIN
314328
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.auth_name = NEW.auth_name AND crs_view.code = NEW.code);
315329

316330
SELECT RAISE(ABORT, 'insert on vertical_crs violates constraint: name (of a non-deprecated entry) must not already exist in (a non-deprecated entry of) crs_view')
317-
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.name = NEW.name AND crs_view.deprecated = 0 AND NEW.deprecated = 0 AND NEW.auth_name != 'IGNF'
331+
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.name = NEW.name AND crs_view.deprecated = 0 AND NEW.deprecated = 0
332+
AND NEW.auth_name IN (SELECT auth_name FROM builtin_authorities WHERE auth_name != 'IGNF')
318333
AND NOT(NEW.auth_name = 'ESRI' and crs_view.table_name = 'geodetic_crs') -- some ESRI vertical CRS are an ellipsoidal height CRS derived from a geodetic CRS
319334
);
320335

@@ -729,7 +744,9 @@ FOR EACH ROW BEGIN
729744
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.auth_name = NEW.auth_name AND crs_view.code = NEW.code);
730745

731746
SELECT RAISE(ABORT, 'insert on projected_crs violates constraint: name (of a non-deprecated entry) must not already exist in (a non-deprecated entry of) crs_view')
732-
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.name = NEW.name AND crs_view.deprecated = 0 AND NEW.deprecated = 0 AND NEW.auth_name != 'IGNF' AND NEW.name != 'unknown');
747+
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.name = NEW.name AND crs_view.deprecated = 0 AND NEW.deprecated = 0
748+
AND NEW.auth_name IN (SELECT auth_name FROM builtin_authorities WHERE auth_name != 'IGNF')
749+
);
733750

734751
SELECT RAISE(ABORT, 'insert on projected_crs violates constraint: geodetic_crs must not be deprecated when projected_crs is not deprecated')
735752
WHERE EXISTS(SELECT 1 FROM geodetic_crs WHERE geodetic_crs.auth_name = NEW.geodetic_crs_auth_name AND geodetic_crs.code = NEW.geodetic_crs_code AND geodetic_crs.deprecated != 0 AND geodetic_crs.name NOT LIKE 'Unknown datum%' AND geodetic_crs.name NOT LIKE 'Unspecified datum%') AND NEW.deprecated = 0 AND NOT (NEW.auth_name = 'ESRI' AND NEW.geodetic_crs_auth_name != 'ESRI');
@@ -773,7 +790,9 @@ FOR EACH ROW BEGIN
773790
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.auth_name = NEW.auth_name AND crs_view.code = NEW.code);
774791

775792
SELECT RAISE(ABORT, 'insert on compound_crs violates constraint: name (of a non-deprecated entry) must not already exist in (a non-deprecated entry of) crs_view')
776-
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.name = NEW.name AND crs_view.deprecated = 0 AND NEW.deprecated = 0 AND NEW.auth_name != 'IGNF');
793+
WHERE EXISTS (SELECT 1 FROM crs_view WHERE crs_view.name = NEW.name AND crs_view.deprecated = 0 AND NEW.deprecated = 0
794+
AND NEW.auth_name IN (SELECT auth_name FROM builtin_authorities WHERE auth_name != 'IGNF')
795+
);
777796

778797
SELECT RAISE(ABORT, 'insert on compound_crs violates constraint: horiz_crs(auth_name, code) not found')
779798
WHERE NOT EXISTS (SELECT 1 FROM crs_view WHERE crs_view.auth_name = NEW.horiz_crs_auth_name AND crs_view.code = NEW.horiz_crs_code);
@@ -1038,7 +1057,8 @@ FOR EACH ROW BEGIN
10381057
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.auth_name = NEW.auth_name AND covwv.code = NEW.code);
10391058

10401059
SELECT RAISE(ABORT, 'insert on helmert_transformation violates constraint: name (of a non-deprecated entry) must not already exist in (a non-deprecated entry of) coordinate_operation_with_conversion_view')
1041-
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.name = NEW.name AND covwv.deprecated = 0 AND NEW.deprecated = 0 AND NEW.auth_name != 'IGNF'
1060+
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.name = NEW.name AND covwv.deprecated = 0 AND NEW.deprecated = 0
1061+
AND NEW.auth_name IN (SELECT auth_name FROM builtin_authorities WHERE auth_name != 'IGNF')
10421062
AND NEW.name != 'NKG_ETRF00 to [email protected]' -- NKG:P1_2008_EE and NKG:P1_2008_FI have the same name
10431063
AND NEW.name != 'NKG_ETRF14 to [email protected]' -- NKG:PAR_2020_EE and NKG:PAR_2020_FI have the same name
10441064
);
@@ -1114,7 +1134,8 @@ FOR EACH ROW BEGIN
11141134
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.auth_name = NEW.auth_name AND covwv.code = NEW.code);
11151135

11161136
SELECT RAISE(ABORT, 'insert on grid_transformation violates constraint: name (of a non-deprecated entry) must not already exist in (a non-deprecated entry of) coordinate_operation_with_conversion_view')
1117-
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.name = NEW.name AND covwv.deprecated = 0 AND NEW.deprecated = 0 AND NEW.auth_name != 'IGNF'
1137+
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.name = NEW.name AND covwv.deprecated = 0 AND NEW.deprecated = 0
1138+
AND NEW.auth_name IN (SELECT auth_name FROM builtin_authorities WHERE auth_name != 'IGNF')
11181139
AND NEW.name != 'NAD83(CSRS)v2 to NAD83(CSRS)v3 (1)' -- duplicate entry in EPSG
11191140
AND NEW.name != 'ETRS89 to ETRS89 + Baltic 1957 height (1)' -- duplicate entry in EPSG
11201141
AND NOT (NEW.description LIKE 'Reversible alternative to%' AND covwv.description NOT LIKE 'Reversible alternative to%')
@@ -1292,7 +1313,8 @@ FOR EACH ROW BEGIN
12921313
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.auth_name = NEW.auth_name AND covwv.code = NEW.code);
12931314

12941315
SELECT RAISE(ABORT, 'insert on other_transformation violates constraint: name (of a non-deprecated entry) must not already exist in (a non-deprecated entry of) coordinate_operation_with_conversion_view')
1295-
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.name = NEW.name AND covwv.deprecated = 0 AND NEW.deprecated = 0 AND NEW.auth_name != 'IGNF'
1316+
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.name = NEW.name AND covwv.deprecated = 0 AND NEW.deprecated = 0
1317+
AND NEW.auth_name IN (SELECT auth_name FROM builtin_authorities WHERE auth_name != 'IGNF')
12961318
AND NEW.name != 'NKG_ETRF14 to [email protected]' -- NKG:PAR_2020_NO and NKG:NKG_ETRF14_ETRF93_2000 have the same name
12971319
AND NEW.name != '[email protected] to [email protected]' -- NKG:ETRF96_2000_TO_ETRF96_1997_56 and NKG:EE_2020_INTRAPLATE have the same name
12981320
AND NEW.name != '[email protected] to [email protected]' -- NKG:ETRF93_2000_TO_ETRF93_1995 and NKG:NO_2020_INTRAPLATE have the same name
@@ -1347,7 +1369,9 @@ FOR EACH ROW BEGIN
13471369
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.auth_name = NEW.auth_name AND covwv.code = NEW.code);
13481370

13491371
SELECT RAISE(ABORT, 'insert on concatenated_operation violates constraint: name (of a non-deprecated entry) must not already exist in (a non-deprecated entry of) coordinate_operation_with_conversion_view')
1350-
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.name = NEW.name AND covwv.deprecated = 0 AND NEW.deprecated = 0 AND new.auth_name != 'IGNF');
1372+
WHERE EXISTS (SELECT 1 FROM coordinate_operation_with_conversion_view covwv WHERE covwv.name = NEW.name AND covwv.deprecated = 0 AND NEW.deprecated = 0
1373+
AND NEW.auth_name IN (SELECT auth_name FROM builtin_authorities WHERE auth_name != 'IGNF')
1374+
);
13511375

13521376
SELECT RAISE(ABORT, 'insert on concatenated_operation violates constraint: source_crs(auth_name, code) not found')
13531377
WHERE NOT EXISTS (SELECT 1 FROM crs_view WHERE crs_view.auth_name = NEW.source_crs_auth_name AND crs_view.code = NEW.source_crs_code);

0 commit comments

Comments
 (0)