Skip to content

Commit

Permalink
Dragnet selection: Show partitioning details
Browse files Browse the repository at this point in the history
  • Loading branch information
rammpeter committed Sep 18, 2023
1 parent 35d16ba commit f52d0ec
Showing 1 changed file with 31 additions and 20 deletions.
51 changes: 31 additions & 20 deletions app/helpers/dragnet/unused_tables_helper.rb
Original file line number Diff line number Diff line change
Expand Up @@ -237,28 +237,39 @@ def unused_tables
:name => t(:dragnet_helper_169_name, default: 'Empty partitions or subpartitions'),
:desc => t(:dragnet_helper_169_desc, default: "Empty partitions or subpartitions are possibly not necessary and could be dropped."),
:sql=> "\
WITH Tab_SubPartitions AS (SELECT /*+ NO_MERGE MATERIALIZE */ Table_Owner, Table_Name, Partition_Name, SubPartition_Name, Num_Rows, Interval FROM DBA_Tab_SubPartitions),
Tab_Partitions AS (SELECT /*+ NO_MERGE MATERIALIZE */ Table_Owner, Table_Name, Partition_Name, Num_Rows, Interval FROM DBA_Tab_Partitions),
WITH Tab_SubPartitions AS (SELECT /*+ NO_MERGE MATERIALIZE */ Table_Owner, Table_Name, Partition_Name, SubPartition_Name, Num_Rows, Interval, Last_Analyzed
FROM DBA_Tab_SubPartitions),
Tab_Partitions AS (SELECT /*+ NO_MERGE MATERIALIZE */ Table_Owner, Table_Name, Partition_Name, Num_Rows, Interval, Last_Analyzed
FROM DBA_Tab_Partitions),
Tab_Modifications AS (SELECT /*+ NO_MERGE MATERIALIZE */ Table_Owner, Table_Name, Partition_Name, SubPartition_Name, Inserts, Deletes FROM DBA_Tab_Modifications WHERE Partition_Name IS NOT NULL),
Segments AS (SELECT /*+ NO_MERGE MATERIALIZE */ Owner, Segment_Name, Partition_Name, Bytes FROM DBA_Segments WHERE Partition_Name IS NOT NULL)
SELECT Table_Owner, Table_Name, Type, COUNT(*) Empty_Partition_Count, ROUND(SUM(Bytes)/(1024*1024), 2) MBytes,
SUM(Num_Rows) Num_Rows_At_Analyze,
SUM(Inserts) Inserts_since_Analyze,
SUM(Deletes) Deletes_since_Analyze
Segments AS (SELECT /*+ NO_MERGE MATERIALIZE */ Owner, Segment_Name, Partition_Name, Bytes FROM DBA_Segments WHERE Partition_Name IS NOT NULL),
Part_Tables AS (SELECT /*+ NO_MERGE MATERIALIZE */ Owner, Table_Name, Partitioning_Type, SubPartitioning_Type, Interval
#{', AutoList, Interval_SubPartition, AutoList_SubPartition' if get_db_version >= '12.2'}
FROM DBA_Part_Tables)
SELECT x.*, pt.Partitioning_Type, pt.SubPartitioning_Type, pt.Interval #{' ,pt.AutoList, pt.Interval_SubPartition, pt.AutoList_SubPartition' if get_db_version >= '12.2'}
FROM (
SELECT 'SUBPARTITION' Type, p.Table_Owner, p.Table_Name, p.Num_Rows, p.Interval, NVL(m.Inserts, 0) Inserts, NVL(m.Deletes, 0) Deletes, s.Bytes
FROM Tab_SubPartitions p
JOIN Segments s ON s.Owner = p.Table_Owner AND s.Segment_Name = p.Table_Name AND s.Partition_Name = p.SubPartition_Name
LEFT OUTER JOIN Tab_Modifications m ON m.Table_Owner = p.Table_Owner AND m.Table_Name = p.Table_Name AND m.Partition_Name = p.Partition_Name AND m.SubPartition_Name = p.SubPartition_Name
UNION ALL
SELECT 'PARTITION' Type, p.Table_Owner, p.Table_Name, p.Num_Rows, p.Interval, NVL(m.Inserts, 0) Inserts, NVL(m.Deletes, 0) Deletes, s.Bytes
FROM Tab_Partitions p
JOIN Segments s ON s.Owner = p.Table_Owner AND s.Segment_Name = p.Table_Name AND s.Partition_Name = p.Partition_Name
LEFT OUTER JOIN Tab_Modifications m ON m.Table_Owner = p.Table_Owner AND m.Table_Name = p.Table_Name AND m.Partition_Name = p.Partition_Name AND m.SubPartition_Name IS NULL
)
WHERE Deletes >= NVL(Num_Rows, 0) + Inserts /* Num_Rows = 0 or all inserted rows are deleted */
AND Table_Owner NOT IN (#{system_schema_subselect})
GROUP BY Table_Owner, Table_Name, Type
SELECT Table_Owner, Table_Name, Type, COUNT(*) Empty_Partition_Count, ROUND(SUM(Bytes)/(1024*1024), 2) MBytes,
SUM(Num_Rows) Num_Rows_At_Analyze,
SUM(Inserts) Inserts_since_Analyze,
SUM(Deletes) Deletes_since_Analyze,
MIN(Last_Analyzed) Min_Last_Analyzed,
MAX(Last_Analyzed) Max_Last_Analyzed
FROM (
SELECT 'SUBPARTITION' Type, p.Table_Owner, p.Table_Name, p.Num_Rows, p.Interval, NVL(m.Inserts, 0) Inserts, NVL(m.Deletes, 0) Deletes, s.Bytes, Last_Analyzed
FROM Tab_SubPartitions p
JOIN Segments s ON s.Owner = p.Table_Owner AND s.Segment_Name = p.Table_Name AND s.Partition_Name = p.SubPartition_Name
LEFT OUTER JOIN Tab_Modifications m ON m.Table_Owner = p.Table_Owner AND m.Table_Name = p.Table_Name AND m.Partition_Name = p.Partition_Name AND m.SubPartition_Name = p.SubPartition_Name
UNION ALL
SELECT 'PARTITION' Type, p.Table_Owner, p.Table_Name, p.Num_Rows, p.Interval, NVL(m.Inserts, 0) Inserts, NVL(m.Deletes, 0) Deletes, s.Bytes, Last_Analyzed
FROM Tab_Partitions p
JOIN Segments s ON s.Owner = p.Table_Owner AND s.Segment_Name = p.Table_Name AND s.Partition_Name = p.Partition_Name
LEFT OUTER JOIN Tab_Modifications m ON m.Table_Owner = p.Table_Owner AND m.Table_Name = p.Table_Name AND m.Partition_Name = p.Partition_Name AND m.SubPartition_Name IS NULL
)
WHERE Deletes >= NVL(Num_Rows, 0) + Inserts /* Num_Rows = 0 or all inserted rows are deleted */
AND Table_Owner NOT IN (#{system_schema_subselect})
GROUP BY Table_Owner, Table_Name, Type
) x
JOIN Part_Tables pt ON pt.Owner = x.Table_Owner AND pt.Table_Name = x.Table_Name
ORDER BY MBytes DESC
",
},
Expand Down

0 comments on commit f52d0ec

Please sign in to comment.