239 lines
7.9 KiB
SQL
239 lines
7.9 KiB
SQL
-- Partition Validation Script
|
|
-- Sprint: SPRINT_3422_0001_0001 - Time-Based Partitioning
|
|
--
|
|
-- Purpose: Verify that partitioned tables are properly configured and healthy
|
|
|
|
-- ============================================================================
|
|
-- Part 1: List all partitioned tables
|
|
-- ============================================================================
|
|
|
|
\echo '=== Partitioned Tables ==='
|
|
|
|
SELECT
|
|
n.nspname AS schema,
|
|
c.relname AS table_name,
|
|
CASE pt.partstrat
|
|
WHEN 'r' THEN 'RANGE'
|
|
WHEN 'l' THEN 'LIST'
|
|
WHEN 'h' THEN 'HASH'
|
|
END AS partition_strategy,
|
|
array_to_string(array_agg(a.attname ORDER BY k.col), ', ') AS partition_key
|
|
FROM pg_class c
|
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
|
JOIN pg_partitioned_table pt ON c.oid = pt.partrelid
|
|
JOIN LATERAL unnest(pt.partattrs) WITH ORDINALITY AS k(col, idx) ON true
|
|
LEFT JOIN pg_attribute a ON a.attrelid = c.oid AND a.attnum = k.col
|
|
WHERE n.nspname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns', 'vuln')
|
|
GROUP BY n.nspname, c.relname, pt.partstrat
|
|
ORDER BY n.nspname, c.relname;
|
|
|
|
-- ============================================================================
|
|
-- Part 2: Partition inventory with sizes
|
|
-- ============================================================================
|
|
|
|
\echo ''
|
|
\echo '=== Partition Inventory ==='
|
|
|
|
SELECT
|
|
n.nspname AS schema,
|
|
parent.relname AS parent_table,
|
|
c.relname AS partition_name,
|
|
pg_get_expr(c.relpartbound, c.oid) AS bounds,
|
|
pg_size_pretty(pg_relation_size(c.oid)) AS size,
|
|
s.n_live_tup AS estimated_rows
|
|
FROM pg_class c
|
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
|
JOIN pg_inherits i ON c.oid = i.inhrelid
|
|
JOIN pg_class parent ON i.inhparent = parent.oid
|
|
LEFT JOIN pg_stat_user_tables s ON c.oid = s.relid
|
|
WHERE n.nspname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns', 'vuln')
|
|
AND c.relkind = 'r'
|
|
AND parent.relkind = 'p'
|
|
ORDER BY n.nspname, parent.relname, c.relname;
|
|
|
|
-- ============================================================================
|
|
-- Part 3: Check for missing future partitions
|
|
-- ============================================================================
|
|
|
|
\echo ''
|
|
\echo '=== Future Partition Coverage ==='
|
|
|
|
WITH partition_bounds AS (
|
|
SELECT
|
|
n.nspname AS schema_name,
|
|
parent.relname AS table_name,
|
|
c.relname AS partition_name,
|
|
-- Extract the TO date from partition bound
|
|
(regexp_match(pg_get_expr(c.relpartbound, c.oid), 'TO \(''([^'']+)''\)'))[1]::DATE AS end_date
|
|
FROM pg_class c
|
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
|
JOIN pg_inherits i ON c.oid = i.inhrelid
|
|
JOIN pg_class parent ON i.inhparent = parent.oid
|
|
WHERE c.relkind = 'r'
|
|
AND parent.relkind = 'p'
|
|
AND c.relname NOT LIKE '%_default'
|
|
),
|
|
max_bounds AS (
|
|
SELECT
|
|
schema_name,
|
|
table_name,
|
|
MAX(end_date) AS max_partition_date
|
|
FROM partition_bounds
|
|
WHERE end_date IS NOT NULL
|
|
GROUP BY schema_name, table_name
|
|
)
|
|
SELECT
|
|
schema_name,
|
|
table_name,
|
|
max_partition_date,
|
|
(max_partition_date - CURRENT_DATE) AS days_ahead,
|
|
CASE
|
|
WHEN (max_partition_date - CURRENT_DATE) < 30 THEN 'CRITICAL: Create partitions!'
|
|
WHEN (max_partition_date - CURRENT_DATE) < 60 THEN 'WARNING: Running low'
|
|
ELSE 'OK'
|
|
END AS status
|
|
FROM max_bounds
|
|
ORDER BY days_ahead;
|
|
|
|
-- ============================================================================
|
|
-- Part 4: Check for orphaned data in default partitions
|
|
-- ============================================================================
|
|
|
|
\echo ''
|
|
\echo '=== Default Partition Data (should be empty) ==='
|
|
|
|
DO $$
|
|
DECLARE
|
|
v_schema TEXT;
|
|
v_table TEXT;
|
|
v_count BIGINT;
|
|
v_sql TEXT;
|
|
BEGIN
|
|
FOR v_schema, v_table IN
|
|
SELECT n.nspname, c.relname
|
|
FROM pg_class c
|
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
|
WHERE c.relname LIKE '%_default'
|
|
AND n.nspname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns', 'vuln')
|
|
LOOP
|
|
v_sql := format('SELECT COUNT(*) FROM %I.%I', v_schema, v_table);
|
|
EXECUTE v_sql INTO v_count;
|
|
|
|
IF v_count > 0 THEN
|
|
RAISE NOTICE 'WARNING: %.% has % rows in default partition!',
|
|
v_schema, v_table, v_count;
|
|
ELSE
|
|
RAISE NOTICE 'OK: %.% is empty', v_schema, v_table;
|
|
END IF;
|
|
END LOOP;
|
|
END
|
|
$$;
|
|
|
|
-- ============================================================================
|
|
-- Part 5: Index health on partitions
|
|
-- ============================================================================
|
|
|
|
\echo ''
|
|
\echo '=== Partition Index Coverage ==='
|
|
|
|
SELECT
|
|
schemaname AS schema,
|
|
tablename AS table_name,
|
|
indexname AS index_name,
|
|
indexdef
|
|
FROM pg_indexes
|
|
WHERE schemaname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns', 'vuln')
|
|
AND tablename LIKE '%_partitioned' OR tablename LIKE '%_202%'
|
|
ORDER BY schemaname, tablename, indexname;
|
|
|
|
-- ============================================================================
|
|
-- Part 6: BRIN index effectiveness check
|
|
-- ============================================================================
|
|
|
|
\echo ''
|
|
\echo '=== BRIN Index Statistics ==='
|
|
|
|
SELECT
|
|
schemaname AS schema,
|
|
tablename AS table_name,
|
|
indexrelname AS index_name,
|
|
idx_scan AS scans,
|
|
idx_tup_read AS tuples_read,
|
|
idx_tup_fetch AS tuples_fetched,
|
|
pg_size_pretty(pg_relation_size(indexrelid)) AS index_size
|
|
FROM pg_stat_user_indexes
|
|
WHERE indexrelname LIKE 'brin_%'
|
|
ORDER BY schemaname, tablename;
|
|
|
|
-- ============================================================================
|
|
-- Part 7: Partition maintenance recommendations
|
|
-- ============================================================================
|
|
|
|
\echo ''
|
|
\echo '=== Maintenance Recommendations ==='
|
|
|
|
WITH partition_ages AS (
|
|
SELECT
|
|
n.nspname AS schema_name,
|
|
parent.relname AS table_name,
|
|
c.relname AS partition_name,
|
|
(regexp_match(pg_get_expr(c.relpartbound, c.oid), 'FROM \(''([^'']+)''\)'))[1]::DATE AS start_date,
|
|
(regexp_match(pg_get_expr(c.relpartbound, c.oid), 'TO \(''([^'']+)''\)'))[1]::DATE AS end_date
|
|
FROM pg_class c
|
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
|
JOIN pg_inherits i ON c.oid = i.inhrelid
|
|
JOIN pg_class parent ON i.inhparent = parent.oid
|
|
WHERE c.relkind = 'r'
|
|
AND parent.relkind = 'p'
|
|
AND c.relname NOT LIKE '%_default'
|
|
)
|
|
SELECT
|
|
schema_name,
|
|
table_name,
|
|
partition_name,
|
|
start_date,
|
|
end_date,
|
|
(CURRENT_DATE - end_date) AS days_old,
|
|
CASE
|
|
WHEN (CURRENT_DATE - end_date) > 365 THEN 'Consider archiving (>1 year old)'
|
|
WHEN (CURRENT_DATE - end_date) > 180 THEN 'Review retention policy (>6 months old)'
|
|
ELSE 'Current'
|
|
END AS recommendation
|
|
FROM partition_ages
|
|
WHERE start_date IS NOT NULL
|
|
ORDER BY schema_name, table_name, start_date;
|
|
|
|
-- ============================================================================
|
|
-- Summary
|
|
-- ============================================================================
|
|
|
|
\echo ''
|
|
\echo '=== Summary ==='
|
|
|
|
SELECT
|
|
'Partitioned Tables' AS metric,
|
|
COUNT(DISTINCT parent.relname)::TEXT AS value
|
|
FROM pg_class c
|
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
|
JOIN pg_inherits i ON c.oid = i.inhrelid
|
|
JOIN pg_class parent ON i.inhparent = parent.oid
|
|
WHERE n.nspname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns', 'vuln')
|
|
AND parent.relkind = 'p'
|
|
UNION ALL
|
|
SELECT
|
|
'Total Partitions',
|
|
COUNT(*)::TEXT
|
|
FROM pg_class c
|
|
JOIN pg_namespace n ON c.relnamespace = n.oid
|
|
JOIN pg_inherits i ON c.oid = i.inhrelid
|
|
JOIN pg_class parent ON i.inhparent = parent.oid
|
|
WHERE n.nspname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns', 'vuln')
|
|
AND parent.relkind = 'p'
|
|
UNION ALL
|
|
SELECT
|
|
'BRIN Indexes',
|
|
COUNT(*)::TEXT
|
|
FROM pg_indexes
|
|
WHERE indexname LIKE 'brin_%'
|
|
AND schemaname IN ('scheduler', 'notify', 'authority', 'vex', 'policy', 'unknowns', 'vuln');
|