14
14
* limitations under the License.
15
15
*/
16
16
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
0 commit comments