Adjust constraints, add indexes and save actions

This commit is contained in:
Jan Kvetina 2022-01-12 21:38:25 +01:00
parent 2429a06531
commit 7c9eb793c2
5 changed files with 1126 additions and 314 deletions

File diff suppressed because it is too large Load Diff

View File

@ -27,11 +27,7 @@ c AS (
--
c.nullable,
c.data_default,
--
CASE WHEN c.column_id = 1 THEN 'Y' END AS is_first,
CASE WHEN LEAD(c.column_id) OVER(PARTITION BY c.table_name ORDER BY c.column_id) IS NULL THEN 'Y' END AS is_last,
--
MAX(LENGTH(c.column_name)) OVER(PARTITION BY c.table_name) AS name_length
c.avg_col_len
FROM user_tab_columns c
JOIN user_tables t
ON t.table_name = c.table_name
@ -59,8 +55,9 @@ SELECT
c.table_name,
c.column_id,
c.column_name,
c.name_length,
c.data_type,
c.data_default,
c.avg_col_len AS avg_length,
--
n.count_pk,
n.count_uq,
@ -68,8 +65,7 @@ SELECT
--
NULLIF(n.count_ch - CASE WHEN c.nullable = 'N' THEN 1 ELSE 0 END, 0) AS count_ch,
--
CASE WHEN c.nullable = 'N' THEN 'Y' END AS is_nn,
CASE WHEN c.data_default IS NOT NULL THEN 'Y' END AS is_default,
CASE WHEN c.nullable = 'N' THEN 'Y' END AS is_nn,
--
m.comments
FROM c

View File

@ -5,6 +5,21 @@ WITH x AS (
FROM users u
WHERE u.user_id = app.get_user_id()
),
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)
AND c.constraint_type = ''C''
')) AS constraint_source
FROM x
),
s AS (
SELECT
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
n.table_name,
@ -33,6 +48,7 @@ c AS (
--
LISTAGG(c.column_name, ', ') WITHIN GROUP (ORDER BY c.position) AS cols,
--
MAX(CASE WHEN s.constraint_name IS NOT NULL THEN 'Y' END) AS is_nn,
MAX(CASE WHEN n.generated = 'GENERATED NAME' THEN 'Y' END) AS is_generated,
MAX(CASE WHEN n.status = 'DISABLED' THEN 'Y' END) AS is_disabled,
MAX(CASE WHEN n.deferrable = 'DEFERRABLE' THEN 'Y' END) AS is_deferred,
@ -43,12 +59,16 @@ c AS (
ON n.table_name = NVL(x.table_name, n.table_name)
JOIN user_cons_columns c
ON 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'
WHERE n.table_name NOT IN (SELECT object_name FROM RECYCLEBIN)
GROUP BY n.table_name, n.constraint_name, n.constraint_type
)
SELECT
c.table_name,
c.constraint_name,
c.constraint_name AS constraint_name_old,
c.constraint_type,
c.cols,
--
@ -56,10 +76,13 @@ SELECT
p.primary_cols,
p.primary_constraint,
--
c.is_nn,
c.is_generated,
c.is_disabled,
c.is_deferred,
c.delete_rule
c.delete_rule,
--
TO_CHAR(CASE c.constraint_type WHEN 'P' THEN 1 WHEN 'R' THEN 2 ELSE 3 END) || c.constraint_name AS sort#
FROM c
LEFT JOIN p
ON p.table_name = c.table_name

17
views/obj_indexes.sql Normal file
View File

@ -0,0 +1,17 @@
CREATE OR REPLACE VIEW obj_indexes AS
WITH x AS (
SELECT
app.get_item('$TABLE_NAME') AS table_name
FROM users u
WHERE u.user_id = app.get_user_id()
)
SELECT
i.table_name,
i.index_name,
LISTAGG(i.column_name, ', ') WITHIN GROUP (ORDER BY i.column_position) AS cols
FROM user_ind_columns i
JOIN x
ON i.table_name = NVL(x.table_name, i.table_name)
WHERE i.table_name NOT IN (SELECT object_name FROM RECYCLEBIN)
GROUP BY i.table_name, i.index_name;

View File

@ -0,0 +1,46 @@
CREATE OR REPLACE VIEW obj_indexes_missing AS
WITH x AS (
SELECT
app.get_item('$TABLE_NAME') AS table_name
FROM users u
WHERE u.user_id = app.get_user_id()
),
f AS (
SELECT
t.table_name,
t.constraint_name AS index_name,
LISTAGG(t.column_name, ', ') WITHIN GROUP (ORDER BY t.position) AS cols
FROM user_cons_columns t
JOIN user_constraints n
ON n.constraint_name = t.constraint_name
JOIN x
ON n.table_name = NVL(x.table_name, n.table_name)
WHERE n.constraint_type = 'R'
AND n.table_name NOT IN (SELECT object_name FROM RECYCLEBIN)
GROUP BY t.table_name, t.constraint_name
)
SELECT
app.get_icon('fa-plus-square') AS action,
app.get_page_link(951,
in_names => 'P951_TABLE_NAME,P951_INDEX_NAME,P951_INDEX_ADD',
in_values => f.table_name || ',' || f.index_name || ',Y'
) AS action_url,
--
f.table_name,
f.index_name,
f.cols,
--
'CREATE INDEX ' || RPAD(f.index_name, 30) ||
' ON ' || RPAD(f.table_name, 30) || ' (' || f.cols || ') COMPUTE STATISTICS;' AS fix
FROM f
LEFT JOIN (
SELECT i.table_name, i.index_name, LISTAGG(i.column_name, ', ') WITHIN GROUP (ORDER BY i.column_position) AS cols
FROM user_ind_columns i
JOIN x
ON i.table_name = NVL(x.table_name, i.table_name)
GROUP BY i.table_name, i.index_name
) i
ON i.table_name = f.table_name
AND i.cols LIKE f.cols || '%'
WHERE i.index_name IS NULL;