Skip to content

Commit 9e770f2

Browse files
authored
feat: add support for foreign keys (#78)
Google Cloud Spanner now supports Foreign Key Constraints. These now also show up in the corresponding DatabaseMetaData methods. Fixes #77
1 parent 3d6f356 commit 9e770f2

File tree

5 files changed

+383
-62
lines changed

5 files changed

+383
-62
lines changed

src/main/resources/com/google/cloud/spanner/jdbc/DatabaseMetaData_GetCrossReferences.sql

Lines changed: 32 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -14,21 +14,35 @@
1414
* limitations under the License.
1515
*/
1616

17-
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
18-
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
19-
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME, CHILD.ORDINAL_POSITION AS KEY_SEQ, 3 AS UPDATE_RULE,
20-
CASE WHEN TABLES.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 3 END AS DELETE_RULE, NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
21-
7 AS DEFERRABILITY, TABLES.ON_DELETE_ACTION
22-
FROM INFORMATION_SCHEMA.INDEX_COLUMNS PARENT
23-
INNER JOIN INFORMATION_SCHEMA.INDEXES PARENT_INDEX ON PARENT.INDEX_NAME=PARENT_INDEX.INDEX_NAME AND PARENT.TABLE_NAME=PARENT_INDEX.TABLE_NAME AND PARENT.TABLE_SCHEMA=PARENT_INDEX.TABLE_SCHEMA AND PARENT.TABLE_CATALOG=PARENT_INDEX.TABLE_CATALOG AND PARENT_INDEX.INDEX_TYPE='PRIMARY_KEY'
24-
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS CHILD ON NOT PARENT.TABLE_NAME=CHILD.TABLE_NAME AND PARENT.COLUMN_NAME=CHILD.COLUMN_NAME
25-
INNER JOIN INFORMATION_SCHEMA.INDEXES CHILD_INDEX ON CHILD.INDEX_NAME=CHILD_INDEX.INDEX_NAME AND CHILD.TABLE_NAME=CHILD_INDEX.TABLE_NAME AND CHILD.TABLE_SCHEMA=CHILD_INDEX.TABLE_SCHEMA AND CHILD.TABLE_CATALOG=CHILD_INDEX.TABLE_CATALOG AND CHILD_INDEX.INDEX_TYPE='PRIMARY_KEY'
26-
INNER JOIN INFORMATION_SCHEMA.TABLES ON CHILD.TABLE_CATALOG=TABLES.TABLE_CATALOG AND CHILD.TABLE_SCHEMA=TABLES.TABLE_SCHEMA AND CHILD.TABLE_NAME=TABLES.TABLE_NAME AND PARENT.TABLE_NAME=TABLES.PARENT_TABLE_NAME
27-
WHERE PARENT_INDEX.INDEX_TYPE='PRIMARY_KEY' AND CHILD.ORDINAL_POSITION IS NOT NULL
28-
AND UPPER(PARENT.TABLE_CATALOG) LIKE ?
29-
AND UPPER(PARENT.TABLE_SCHEMA) LIKE ?
30-
AND UPPER(PARENT.TABLE_NAME) LIKE ?
31-
AND UPPER(CHILD.TABLE_CATALOG) LIKE ?
32-
AND UPPER(CHILD.TABLE_SCHEMA) LIKE ?
33-
AND UPPER(CHILD.TABLE_NAME) LIKE ?
34-
ORDER BY CHILD.TABLE_CATALOG, CHILD.TABLE_SCHEMA, CHILD.TABLE_NAME, CHILD.ORDINAL_POSITION
17+
SELECT *
18+
FROM (
19+
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
20+
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
21+
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME, CHILD.ORDINAL_POSITION AS KEY_SEQ, 3 AS UPDATE_RULE,
22+
CASE WHEN TABLES.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 3 END AS DELETE_RULE, NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
23+
7 AS DEFERRABILITY
24+
FROM INFORMATION_SCHEMA.INDEX_COLUMNS PARENT
25+
INNER JOIN INFORMATION_SCHEMA.INDEXES PARENT_INDEX ON PARENT.INDEX_NAME=PARENT_INDEX.INDEX_NAME AND PARENT.TABLE_NAME=PARENT_INDEX.TABLE_NAME AND PARENT.TABLE_SCHEMA=PARENT_INDEX.TABLE_SCHEMA AND PARENT.TABLE_CATALOG=PARENT_INDEX.TABLE_CATALOG AND PARENT_INDEX.INDEX_TYPE='PRIMARY_KEY'
26+
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS CHILD ON NOT PARENT.TABLE_NAME=CHILD.TABLE_NAME AND PARENT.COLUMN_NAME=CHILD.COLUMN_NAME
27+
INNER JOIN INFORMATION_SCHEMA.INDEXES CHILD_INDEX ON CHILD.INDEX_NAME=CHILD_INDEX.INDEX_NAME AND CHILD.TABLE_NAME=CHILD_INDEX.TABLE_NAME AND CHILD.TABLE_SCHEMA=CHILD_INDEX.TABLE_SCHEMA AND CHILD.TABLE_CATALOG=CHILD_INDEX.TABLE_CATALOG AND CHILD_INDEX.INDEX_TYPE='PRIMARY_KEY'
28+
INNER JOIN INFORMATION_SCHEMA.TABLES ON CHILD.TABLE_CATALOG=TABLES.TABLE_CATALOG AND CHILD.TABLE_SCHEMA=TABLES.TABLE_SCHEMA AND CHILD.TABLE_NAME=TABLES.TABLE_NAME AND PARENT.TABLE_NAME=TABLES.PARENT_TABLE_NAME
29+
WHERE PARENT_INDEX.INDEX_TYPE='PRIMARY_KEY' AND CHILD.ORDINAL_POSITION IS NOT NULL
30+
31+
UNION ALL
32+
33+
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
34+
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
35+
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME, CHILD.ORDINAL_POSITION AS KEY_SEQ, 3 AS UPDATE_RULE,
36+
3 AS DELETE_RULE, CONSTRAINTS.CONSTRAINT_NAME AS FK_NAME, CONSTRAINTS.UNIQUE_CONSTRAINT_NAME AS PK_NAME,
37+
7 AS DEFERRABILITY
38+
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS CONSTRAINTS
39+
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE CHILD ON CONSTRAINTS.CONSTRAINT_CATALOG=CHILD.CONSTRAINT_CATALOG AND CONSTRAINTS.CONSTRAINT_SCHEMA= CHILD.CONSTRAINT_SCHEMA AND CONSTRAINTS.CONSTRAINT_NAME= CHILD.CONSTRAINT_NAME
40+
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE PARENT ON CONSTRAINTS.UNIQUE_CONSTRAINT_CATALOG=PARENT.CONSTRAINT_CATALOG AND CONSTRAINTS.UNIQUE_CONSTRAINT_SCHEMA=PARENT.CONSTRAINT_SCHEMA AND CONSTRAINTS.UNIQUE_CONSTRAINT_NAME=PARENT.CONSTRAINT_NAME AND PARENT.ORDINAL_POSITION=CHILD.POSITION_IN_UNIQUE_CONSTRAINT
41+
) AS CROSS_REF
42+
WHERE UPPER(PKTABLE_CAT) LIKE ?
43+
AND UPPER(PKTABLE_SCHEM) LIKE ?
44+
AND UPPER(PKTABLE_NAME) LIKE ?
45+
AND UPPER(FKTABLE_CAT) LIKE ?
46+
AND UPPER(FKTABLE_SCHEM) LIKE ?
47+
AND UPPER(FKTABLE_NAME) LIKE ?
48+
ORDER BY FKTABLE_CAT, FKTABLE_SCHEM, FKTABLE_NAME, KEY_SEQ

src/main/resources/com/google/cloud/spanner/jdbc/DatabaseMetaData_GetExportedKeys.sql

Lines changed: 35 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -14,21 +14,38 @@
1414
* limitations under the License.
1515
*/
1616

17-
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM,
18-
PARENT.TABLE_NAME AS PKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS PKCOLUMN_NAME,
19-
CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
20-
CHILD.TABLE_NAME AS FKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS FKCOLUMN_NAME,
21-
PARENT_INDEX_COLUMNS.ORDINAL_POSITION AS KEY_SEQ,
22-
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
23-
CASE WHEN CHILD.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 1 END AS DELETE_RULE, -- 0 = cascade
24-
NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
25-
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
26-
FROM INFORMATION_SCHEMA.TABLES PARENT
27-
INNER JOIN INFORMATION_SCHEMA.TABLES CHILD ON CHILD.PARENT_TABLE_NAME=PARENT.TABLE_NAME
28-
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS PARENT_INDEX_COLUMNS ON
29-
PARENT_INDEX_COLUMNS.TABLE_NAME=PARENT.TABLE_NAME
30-
AND PARENT_INDEX_COLUMNS.INDEX_NAME='PRIMARY_KEY'
31-
WHERE UPPER(PARENT.TABLE_CATALOG) LIKE ?
32-
AND UPPER(PARENT.TABLE_SCHEMA) LIKE ?
33-
AND UPPER(PARENT.TABLE_NAME) LIKE ?
34-
ORDER BY CHILD.TABLE_CATALOG, CHILD.TABLE_SCHEMA, CHILD.TABLE_NAME, PARENT_INDEX_COLUMNS.ORDINAL_POSITION
17+
SELECT *
18+
FROM (
19+
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM,
20+
PARENT.TABLE_NAME AS PKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS PKCOLUMN_NAME,
21+
CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
22+
CHILD.TABLE_NAME AS FKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS FKCOLUMN_NAME,
23+
PARENT_INDEX_COLUMNS.ORDINAL_POSITION AS KEY_SEQ,
24+
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
25+
CASE WHEN CHILD.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 1 END AS DELETE_RULE, -- 0 = cascade
26+
NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
27+
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
28+
FROM INFORMATION_SCHEMA.TABLES PARENT
29+
INNER JOIN INFORMATION_SCHEMA.TABLES CHILD ON CHILD.PARENT_TABLE_NAME=PARENT.TABLE_NAME
30+
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS PARENT_INDEX_COLUMNS ON
31+
PARENT_INDEX_COLUMNS.TABLE_NAME=PARENT.TABLE_NAME
32+
AND PARENT_INDEX_COLUMNS.INDEX_NAME='PRIMARY_KEY'
33+
34+
UNION ALL
35+
36+
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
37+
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
38+
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME,
39+
CHILD.ORDINAL_POSITION AS KEY_SEQ,
40+
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
41+
1 AS DELETE_RULE, -- 1 = importedKeyRestrict
42+
CONSTRAINTS.CONSTRAINT_NAME AS FK_NAME, CONSTRAINTS.UNIQUE_CONSTRAINT_NAME AS PK_NAME,
43+
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
44+
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS CONSTRAINTS
45+
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE CHILD ON CONSTRAINTS.CONSTRAINT_CATALOG=CHILD.CONSTRAINT_CATALOG AND CONSTRAINTS.CONSTRAINT_SCHEMA= CHILD.CONSTRAINT_SCHEMA AND CONSTRAINTS.CONSTRAINT_NAME= CHILD.CONSTRAINT_NAME
46+
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE PARENT ON CONSTRAINTS.UNIQUE_CONSTRAINT_CATALOG=PARENT.CONSTRAINT_CATALOG AND CONSTRAINTS.UNIQUE_CONSTRAINT_SCHEMA=PARENT.CONSTRAINT_SCHEMA AND CONSTRAINTS.UNIQUE_CONSTRAINT_NAME=PARENT.CONSTRAINT_NAME AND PARENT.ORDINAL_POSITION=CHILD.POSITION_IN_UNIQUE_CONSTRAINT
47+
) EXPORTED_KEYS
48+
WHERE UPPER(PKTABLE_CAT) LIKE ?
49+
AND UPPER(PKTABLE_SCHEM) LIKE ?
50+
AND UPPER(PKTABLE_NAME) LIKE ?
51+
ORDER BY FKTABLE_CAT, FKTABLE_SCHEM, FKTABLE_NAME, KEY_SEQ

src/main/resources/com/google/cloud/spanner/jdbc/DatabaseMetaData_GetImportedKeys.sql

Lines changed: 35 additions & 18 deletions
Original file line numberDiff line numberDiff line change
@@ -14,21 +14,38 @@
1414
* limitations under the License.
1515
*/
1616

17-
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM,
18-
PARENT.TABLE_NAME AS PKTABLE_NAME, COL.COLUMN_NAME AS PKCOLUMN_NAME,
19-
CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
20-
CHILD.TABLE_NAME AS FKTABLE_NAME, COL.COLUMN_NAME FKCOLUMN_NAME,
21-
COL.ORDINAL_POSITION AS KEY_SEQ,
22-
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
23-
CASE WHEN CHILD.ON_DELETE_ACTION = 'CASCADE' THEN 0 ELSE 1 END AS DELETE_RULE, -- 0 = cascade
24-
NULL AS FK_NAME, INDEXES.INDEX_NAME AS PK_NAME,
25-
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
26-
FROM INFORMATION_SCHEMA.TABLES CHILD
27-
INNER JOIN INFORMATION_SCHEMA.TABLES PARENT ON CHILD.TABLE_CATALOG=PARENT.TABLE_CATALOG AND CHILD.TABLE_SCHEMA=PARENT.TABLE_SCHEMA AND CHILD.PARENT_TABLE_NAME=PARENT.TABLE_NAME
28-
INNER JOIN INFORMATION_SCHEMA.INDEXES ON PARENT.TABLE_CATALOG=INDEXES.TABLE_CATALOG AND PARENT.TABLE_SCHEMA=INDEXES.TABLE_SCHEMA AND PARENT.TABLE_NAME=INDEXES.TABLE_NAME AND INDEXES.INDEX_TYPE='PRIMARY_KEY'
29-
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS COL ON INDEXES.TABLE_CATALOG=COL.TABLE_CATALOG AND INDEXES.TABLE_SCHEMA=COL.TABLE_SCHEMA AND INDEXES.TABLE_NAME=COL.TABLE_NAME AND INDEXES.INDEX_NAME=COL.INDEX_NAME
30-
WHERE CHILD.PARENT_TABLE_NAME IS NOT NULL
31-
AND UPPER(CHILD.TABLE_CATALOG) LIKE ?
32-
AND UPPER(CHILD.TABLE_SCHEMA) LIKE ?
33-
AND UPPER(CHILD.TABLE_NAME) LIKE ?
34-
ORDER BY PARENT.TABLE_CATALOG, PARENT.TABLE_SCHEMA, PARENT.TABLE_NAME, COL.ORDINAL_POSITION
17+
SELECT *
18+
FROM (
19+
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM,
20+
PARENT.TABLE_NAME AS PKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS PKCOLUMN_NAME,
21+
CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
22+
CHILD.TABLE_NAME AS FKTABLE_NAME, PARENT_INDEX_COLUMNS.COLUMN_NAME AS FKCOLUMN_NAME,
23+
PARENT_INDEX_COLUMNS.ORDINAL_POSITION AS KEY_SEQ,
24+
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
25+
CASE WHEN CHILD.ON_DELETE_ACTION='CASCADE' THEN 0 ELSE 1 END AS DELETE_RULE, -- 0 = cascade
26+
NULL AS FK_NAME, 'PRIMARY_KEY' AS PK_NAME,
27+
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
28+
FROM INFORMATION_SCHEMA.TABLES PARENT
29+
INNER JOIN INFORMATION_SCHEMA.TABLES CHILD ON CHILD.PARENT_TABLE_NAME=PARENT.TABLE_NAME
30+
INNER JOIN INFORMATION_SCHEMA.INDEX_COLUMNS PARENT_INDEX_COLUMNS ON
31+
PARENT_INDEX_COLUMNS.TABLE_NAME=PARENT.TABLE_NAME
32+
AND PARENT_INDEX_COLUMNS.INDEX_NAME='PRIMARY_KEY'
33+
34+
UNION ALL
35+
36+
SELECT PARENT.TABLE_CATALOG AS PKTABLE_CAT, PARENT.TABLE_SCHEMA AS PKTABLE_SCHEM, PARENT.TABLE_NAME AS PKTABLE_NAME,
37+
PARENT.COLUMN_NAME AS PKCOLUMN_NAME, CHILD.TABLE_CATALOG AS FKTABLE_CAT, CHILD.TABLE_SCHEMA AS FKTABLE_SCHEM,
38+
CHILD.TABLE_NAME AS FKTABLE_NAME, CHILD.COLUMN_NAME AS FKCOLUMN_NAME,
39+
CHILD.ORDINAL_POSITION AS KEY_SEQ,
40+
1 AS UPDATE_RULE, -- 1 = importedKeyRestrict
41+
1 AS DELETE_RULE, -- 1 = importedKeyRestrict
42+
CONSTRAINTS.CONSTRAINT_NAME AS FK_NAME, CONSTRAINTS.UNIQUE_CONSTRAINT_NAME AS PK_NAME,
43+
7 AS DEFERRABILITY -- 7 = importedKeyNotDeferrable
44+
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS CONSTRAINTS
45+
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE CHILD ON CONSTRAINTS.CONSTRAINT_CATALOG=CHILD.CONSTRAINT_CATALOG AND CONSTRAINTS.CONSTRAINT_SCHEMA= CHILD.CONSTRAINT_SCHEMA AND CONSTRAINTS.CONSTRAINT_NAME= CHILD.CONSTRAINT_NAME
46+
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE PARENT ON CONSTRAINTS.UNIQUE_CONSTRAINT_CATALOG=PARENT.CONSTRAINT_CATALOG AND CONSTRAINTS.UNIQUE_CONSTRAINT_SCHEMA=PARENT.CONSTRAINT_SCHEMA AND CONSTRAINTS.UNIQUE_CONSTRAINT_NAME=PARENT.CONSTRAINT_NAME AND PARENT.ORDINAL_POSITION=CHILD.POSITION_IN_UNIQUE_CONSTRAINT
47+
) IMPORTED_KEYS
48+
WHERE UPPER(FKTABLE_CAT) LIKE ?
49+
AND UPPER(FKTABLE_SCHEM) LIKE ?
50+
AND UPPER(FKTABLE_NAME) LIKE ?
51+
ORDER BY PKTABLE_CAT, PKTABLE_SCHEM, PKTABLE_NAME, KEY_SEQ

0 commit comments

Comments
 (0)