Page 951 for tables overview

This commit is contained in:
Jan Kvetina 2022-01-09 15:02:45 +01:00
parent 30e3d5d1a3
commit 29e6dd30e2
5 changed files with 2852 additions and 0 deletions

File diff suppressed because it is too large Load Diff

View File

@ -125,6 +125,7 @@ prompt --install
@@application/pages/page_00925.sql
@@application/pages/page_00940.sql
@@application/pages/page_00950.sql
@@application/pages/page_00951.sql
@@application/pages/page_00970.sql
@@application/pages/page_00990.sql
@@application/pages/page_09999.sql

View File

@ -0,0 +1,82 @@
CREATE OR REPLACE VIEW user_obj_columns AS
WITH x AS (
SELECT
app.get_item('$TABLE') AS table_name
FROM users u
WHERE u.user_id = app.get_user_id()
),
c AS (
SELECT
c.table_name,
c.column_id,
c.column_name,
--
c.data_type ||
CASE
WHEN c.data_type LIKE '%CHAR%' OR c.data_type = 'RAW' THEN
DECODE(NVL(c.char_length, 0), 0, '',
'(' || c.char_length || DECODE(c.char_used, 'C', ' CHAR', '') || ')'
)
WHEN c.data_type = 'NUMBER' THEN
DECODE(NVL(c.data_precision || c.data_scale, 0), 0, '',
DECODE(NVL(c.data_scale, 0), 0, '(' || c.data_precision || ')',
'(' || c.data_precision || ',' || c.data_scale || ')'
)
)
END AS data_type,
--
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
FROM user_tab_columns c
JOIN user_tables t
ON t.table_name = c.table_name
CROSS JOIN x
WHERE t.table_name = NVL(x.table_name, t.table_name)
AND t.table_name NOT LIKE '%\__$' ESCAPE '\'
),
n AS (
SELECT
m.table_name,
m.column_name,
NULLIF(SUM(CASE WHEN n.constraint_type = 'P' THEN 1 ELSE 0 END), 0) AS count_pk,
NULLIF(SUM(CASE WHEN n.constraint_type = 'R' THEN 1 ELSE 0 END), 0) AS count_fk,
NULLIF(SUM(CASE WHEN n.constraint_type = 'U' THEN 1 ELSE 0 END), 0) AS count_uq,
NULLIF(SUM(CASE WHEN n.constraint_type = 'C' THEN 1 ELSE 0 END), 0) AS count_ch
FROM user_cons_columns m
JOIN user_constraints n
ON n.constraint_name = m.constraint_name
AND n.constraint_type IN ('P', 'R', 'U', 'C')
CROSS JOIN x
WHERE n.table_name = NVL(x.table_name, n.table_name)
GROUP BY m.table_name, m.column_name
)
SELECT
c.table_name,
c.column_id,
c.column_name,
c.name_length,
c.data_type,
--
n.count_pk,
n.count_uq,
n.count_fk,
--
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,
--
m.comments
FROM c
LEFT JOIN n
ON n.table_name = c.table_name
AND n.column_name = c.column_name
LEFT JOIN user_col_comments m
ON m.table_name = c.table_name
AND m.column_name = c.column_name;

View File

@ -0,0 +1,56 @@
CREATE OR REPLACE VIEW user_obj_partitions AS
WITH x AS (
SELECT
app.get_item('$TABLE') AS table_name
FROM users u
WHERE u.user_id = app.get_user_id()
),
p AS (
SELECT
p.*,
--
'SELECT p.high_value' || CHR(10) ||
'FROM user_tab_partitions p' || CHR(10) ||
'WHERE p.table_name = ''' || p.table_name || '''' || CHR(10) ||
' AND p.partition_name = ''' || p.partition_name || '''' AS query_
FROM user_tab_partitions p
JOIN x
ON x.table_name = p.table_name
),
r AS (
SELECT
p.partition_name,
LTRIM(RTRIM(h.high_value, ' )'), '( ') AS high_value
FROM p,
-- trick to convert LONG to VARCHAR2 on the fly
XMLTABLE('/ROWSET/ROW'
PASSING (DBMS_XMLGEN.GETXMLTYPE(p.query_))
COLUMNS high_value VARCHAR2(4000) PATH 'HIGH_VALUE'
) h
)
SELECT
p.partition_position,
p.partition_name,
p.partition_name AS partition_name_old,
p.high_value,
--
LTRIM(REGEXP_SUBSTR(r.high_value, '[^,' || ']+', 1, 1)) AS header_1,
LTRIM(REGEXP_SUBSTR(r.high_value, '[^,' || ']+', 1, 2)) AS header_2,
LTRIM(REGEXP_SUBSTR(r.high_value, '[^,' || ']+', 1, 3)) AS header_3,
LTRIM(REGEXP_SUBSTR(r.high_value, '[^,' || ']+', 1, 4)) AS header_4,
--
TO_NUMBER(EXTRACTVALUE(XMLTYPE(DBMS_XMLGEN.GETXML(
'SELECT /*+ PARALLEL(p,4) */ COUNT(*) AS r ' ||
'FROM ' || p.table_name || ' PARTITION (' || p.partition_name || ') p'
)), '/ROWSET/ROW/R')) AS count_rows,
--
p.subpartition_count AS subpartitions,
--
p.read_only,
p.read_only AS read_only_old,
--
app.get_icon('fa-trash-o', 'Truncate partition (delete also data)') AS action_truncate
FROM p
JOIN r
ON r.partition_name = p.partition_name;

114
views/user_obj_tables.sql Normal file
View File

@ -0,0 +1,114 @@
CREATE OR REPLACE VIEW user_obj_tables AS
WITH x AS (
SELECT
app.get_item('$TABLE') AS table_name
FROM users u
WHERE u.user_id = app.get_user_id()
),
s AS (
-- columns count
SELECT /* materialize */
c.table_name,
COUNT(*) AS count_cols
FROM user_tab_cols c
CROSS JOIN x
WHERE c.table_name = NVL(x.table_name, c.table_name)
GROUP BY c.table_name
),
c AS (
-- constraints overview
SELECT /* materialize */
c.table_name,
NULLIF(SUM(CASE WHEN c.constraint_type = 'P' THEN 1 ELSE 0 END), 0) AS count_pk,
NULLIF(SUM(CASE WHEN c.constraint_type = 'U' THEN 1 ELSE 0 END), 0) AS count_uq,
NULLIF(SUM(CASE WHEN c.constraint_type = 'R' THEN 1 ELSE 0 END), 0) AS count_fk
FROM user_constraints c
CROSS JOIN x
WHERE c.table_name = NVL(x.table_name, c.table_name)
AND c.constraint_type IN ('P', 'U', 'R')
GROUP BY c.table_name
),
i AS (
-- indexes overview
SELECT /* materialize */
i.table_name,
COUNT(i.table_name) AS count_ix
FROM user_indexes i
CROSS JOIN x
LEFT JOIN user_constraints c
ON c.constraint_name = i.index_name
WHERE i.table_name = NVL(x.table_name, i.table_name)
AND i.index_type != 'LOB'
AND c.constraint_name IS NULL
GROUP BY i.table_name
),
g AS (
-- triggers overview
SELECT /* materialize */
g.table_name,
COUNT(g.table_name) AS count_trg
FROM user_triggers g
CROSS JOIN x
WHERE g.table_name = NVL(x.table_name, g.table_name)
GROUP BY g.table_name
),
p AS (
-- partitions count
SELECT /* materialize */
p.table_name,
COUNT(*) AS partitions
FROM user_tab_partitions p
CROSS JOIN x
WHERE p.table_name = NVL(x.table_name, p.table_name)
GROUP BY p.table_name
)
--
SELECT
t.table_name,
s.count_cols,
t.num_rows AS count_rows,
--
CASE WHEN c.count_pk IS NOT NULL THEN 'Y' END AS is_pk,
CASE WHEN c.count_uq IS NOT NULL THEN 'Y' END AS is_uq,
--
c.count_fk,
i.count_ix,
g.count_trg,
--
p.partitions,
--
CASE WHEN t.temporary = 'Y' THEN 'Y' END AS is_temp,
CASE WHEN t.iot_type = 'IOT' THEN 'Y' END AS is_iot,
CASE WHEN t.row_movement = 'ENABLED' THEN 'Y' END AS is_row_mov,
--
ROUND(t.num_rows * t.avg_row_len / 1024, 0) AS size_,
--
CASE
WHEN ROUND(t.blocks * 8, 2) > 0
THEN ROUND(t.blocks * 8, 2) - ROUND(t.num_rows * t.avg_row_len / 1024, 0)
END AS wasted,
--
o.last_ddl_time,
t.last_analyzed,
--
c.comments
FROM user_tables t
JOIN user_objects o
ON o.object_name = t.table_name
AND o.object_type = 'TABLE' -- skip views
CROSS JOIN x
LEFT JOIN user_mviews m
ON m.mview_name = t.table_name -- skip mviews
LEFT JOIN user_tab_comments c
ON c.table_name = t.table_name
--
LEFT JOIN s ON s.table_name = t.table_name
LEFT JOIN c ON c.table_name = t.table_name
LEFT JOIN i ON i.table_name = t.table_name
LEFT JOIN g ON g.table_name = t.table_name
LEFT JOIN p ON p.table_name = t.table_name
--
WHERE t.table_name = NVL(x.table_name, t.table_name)
AND t.table_name NOT LIKE '%\__$' ESCAPE '\'
AND m.mview_name IS NULL;