Add owner/schema support for constraints

This commit is contained in:
Jan Kvetina 2022-03-10 21:27:55 +01:00
parent 06abbd0f1f
commit 1922730481
3 changed files with 59 additions and 37 deletions

View File

@ -1,46 +1,53 @@
CREATE OR REPLACE VIEW obj_constraints AS
WITH x AS (
SELECT /*+ MATERIALIZE */
app.get_item('$TABLE_NAME') AS table_name
app.get_owner() AS owner,
app.get_item('$TABLE_NAME') AS table_name
FROM DUAL
),
n AS (
SELECT XMLTYPE(DBMS_XMLGEN.GETXML('SELECT c.constraint_name AS name, c.search_condition AS text
FROM user_constraints c
WHERE c.table_name = NVL(''' || x.table_name || ''', c.table_name)
SELECT /*+ MATERIALIZE */
XMLTYPE(DBMS_XMLGEN.GETXML('SELECT c.constraint_name AS name, c.search_condition AS text
FROM all_constraints c
WHERE c.owner = ''' || x.owner || '''
AND c.table_name = NVL(''' || x.table_name || ''', c.table_name)
AND c.constraint_type = ''C''
')) AS constraint_source
FROM x
),
s AS (
SELECT
SELECT /*+ MATERIALIZE */
EXTRACTVALUE(s.object_value, '/ROW/NAME') AS constraint_name,
EXTRACTVALUE(s.object_value, '/ROW/TEXT') AS search_condition
FROM n
CROSS JOIN TABLE(XMLSEQUENCE(EXTRACT(n.constraint_source, '/ROWSET/ROW'))) s
),
p AS (
SELECT
SELECT /*+ MATERIALIZE */
n.table_name,
n.constraint_name,
k.table_name AS primary_table,
LISTAGG(p.column_name, ', ') WITHIN GROUP (ORDER BY p.position) AS primary_cols,
n.r_constraint_name AS primary_constraint
FROM user_constraints n
FROM all_constraints n
JOIN x
ON n.table_name = NVL(x.table_name, n.table_name)
JOIN user_cons_columns c
ON c.constraint_name = n.constraint_name
JOIN user_cons_columns p
ON p.constraint_name = n.r_constraint_name
ON x.owner = n.owner
AND n.table_name = NVL(x.table_name, n.table_name)
JOIN all_cons_columns c
ON c.owner = n.owner
AND c.constraint_name = n.constraint_name
JOIN all_cons_columns p
ON p.owner = n.owner
AND p.constraint_name = n.r_constraint_name
AND p.position = c.position
JOIN user_constraints k
ON k.constraint_name = n.r_constraint_name
JOIN all_constraints k
ON k.owner = n.owner
AND k.constraint_name = n.r_constraint_name
WHERE n.constraint_type = 'R'
GROUP BY n.table_name, n.constraint_name, k.table_name, n.r_constraint_name
),
c AS (
SELECT
SELECT /*+ MATERIALIZE */
n.table_name,
n.constraint_name,
n.constraint_type,
@ -53,11 +60,13 @@ c AS (
MAX(CASE WHEN n.deferrable = 'DEFERRABLE' THEN 'Y' END) AS is_deferred,
--
MAX(n.delete_rule) AS delete_rule
FROM user_constraints n
FROM all_constraints n
JOIN x
ON n.table_name = NVL(x.table_name, n.table_name)
JOIN user_cons_columns c
ON c.constraint_name = n.constraint_name
ON x.owner = n.owner
AND n.table_name = NVL(x.table_name, n.table_name)
JOIN all_cons_columns c
ON c.owner = n.owner
AND c.constraint_name = n.constraint_name
LEFT JOIN s
ON s.constraint_name = n.constraint_name
AND s.search_condition = '"' || c.column_name || '" IS NOT NULL'

View File

@ -1,7 +1,8 @@
CREATE OR REPLACE VIEW obj_constraints_fix_dt1 AS
WITH x AS (
SELECT /*+ MATERIALIZE */
app.get_item('$TABLE_NAME') AS table_name
app.get_owner() AS owner,
app.get_item('$TABLE_NAME') AS table_name
FROM DUAL
),
s AS (
@ -23,14 +24,19 @@ s AS (
n.constraint_type,
c.constraint_name,
n.r_constraint_name
FROM user_tab_columns a
JOIN user_tables t
ON t.table_name = a.table_name
JOIN user_cons_columns c
ON c.table_name = a.table_name
FROM all_tab_columns a
JOIN x
ON x.owner = a.owner
JOIN all_tables t
ON t.owner = a.owner
AND t.table_name = a.table_name
JOIN all_cons_columns c
ON c.owner = a.owner
AND c.table_name = a.table_name
AND c.column_name = a.column_name
JOIN user_constraints n
ON n.constraint_name = c.constraint_name
JOIN all_constraints n
ON n.owner = c.owner
AND n.constraint_name = c.constraint_name
AND n.constraint_type IN ('P', 'R')
ORDER BY a.table_name, n.constraint_type, n.constraint_name, a.column_name
)

View File

@ -1,7 +1,8 @@
CREATE OR REPLACE VIEW obj_constraints_fix_dt2 AS
WITH x AS (
SELECT /*+ MATERIALIZE */
app.get_item('$TABLE_NAME') AS table_name
app.get_owner() AS owner,
app.get_item('$TABLE_NAME') AS table_name
FROM DUAL
),
s AS (
@ -20,11 +21,15 @@ s AS (
--
ELSE a.data_type
END AS data_type
FROM user_tab_columns a
JOIN user_tables t
ON t.table_name = a.table_name
LEFT JOIN user_mviews m
ON m.mview_name = a.table_name
FROM all_tab_columns a
JOIN x
ON x.owner = a.owner
JOIN all_tables t
ON t.owner = a.owner
AND t.table_name = a.table_name
LEFT JOIN all_mviews m
ON m.owner = a.owner
AND m.mview_name = a.table_name
LEFT JOIN obj_constraints_fix_dt1 d
ON d.foreign_table = a.table_name
AND d.foreign_column = a.column_name
@ -33,7 +38,7 @@ s AS (
AND d.foreign_table IS NULL -- skip columns marked as FK errors
),
t AS (
SELECT
SELECT /*+ MATERIALIZE */
s.column_name,
s.data_type,
--
@ -43,15 +48,17 @@ t AS (
),
r AS (
-- unmatching column data types
SELECT t.*
SELECT /*+ MATERIALIZE */
t.*
FROM t
CROSS JOIN x
WHERE (
t.column_name IN (
SELECT c.column_name
FROM user_tab_cols c
FROM all_tab_cols c
JOIN x
ON x.table_name = c.table_name
ON x.owner = c.owner
AND x.table_name = c.table_name
)
OR x.table_name IS NULL
)