mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-20 10:11:13 -05:00
Add database maintenance tooling
- Implement maintenance hooks (useMaintenanceTables, useVacuumTable, useAnalyzeTable, useReindexTable) - Add DatabaseMaintenance page and UI for vacuum/analyze/reindex - Wire new route / admin/database-maintenance and sidebar entry - Remove DatabaseMaintenance icon usage on page and align with AdminLayout props
This commit is contained in:
@@ -0,0 +1,188 @@
|
||||
-- Database Maintenance Functions
|
||||
-- These functions allow authorized users to perform database maintenance operations
|
||||
|
||||
-- Function to run VACUUM on a specific table
|
||||
CREATE OR REPLACE FUNCTION run_vacuum_table(table_name text)
|
||||
RETURNS jsonb
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
result jsonb;
|
||||
start_time timestamp;
|
||||
end_time timestamp;
|
||||
BEGIN
|
||||
-- Only allow superusers to run this
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM profiles
|
||||
WHERE id = auth.uid()
|
||||
AND role = 'superuser'
|
||||
) THEN
|
||||
RAISE EXCEPTION 'Only superusers can perform database maintenance';
|
||||
END IF;
|
||||
|
||||
start_time := clock_timestamp();
|
||||
|
||||
-- Execute VACUUM on the specified table
|
||||
EXECUTE format('VACUUM ANALYZE %I', table_name);
|
||||
|
||||
end_time := clock_timestamp();
|
||||
|
||||
result := jsonb_build_object(
|
||||
'table_name', table_name,
|
||||
'operation', 'VACUUM ANALYZE',
|
||||
'started_at', start_time,
|
||||
'completed_at', end_time,
|
||||
'duration_ms', EXTRACT(MILLISECONDS FROM (end_time - start_time)),
|
||||
'success', true
|
||||
);
|
||||
|
||||
RETURN result;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RETURN jsonb_build_object(
|
||||
'table_name', table_name,
|
||||
'operation', 'VACUUM ANALYZE',
|
||||
'success', false,
|
||||
'error', SQLERRM
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Function to run ANALYZE on a specific table
|
||||
CREATE OR REPLACE FUNCTION run_analyze_table(table_name text)
|
||||
RETURNS jsonb
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
result jsonb;
|
||||
start_time timestamp;
|
||||
end_time timestamp;
|
||||
BEGIN
|
||||
-- Only allow superusers to run this
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM profiles
|
||||
WHERE id = auth.uid()
|
||||
AND role = 'superuser'
|
||||
) THEN
|
||||
RAISE EXCEPTION 'Only superusers can perform database maintenance';
|
||||
END IF;
|
||||
|
||||
start_time := clock_timestamp();
|
||||
|
||||
-- Execute ANALYZE on the specified table
|
||||
EXECUTE format('ANALYZE %I', table_name);
|
||||
|
||||
end_time := clock_timestamp();
|
||||
|
||||
result := jsonb_build_object(
|
||||
'table_name', table_name,
|
||||
'operation', 'ANALYZE',
|
||||
'started_at', start_time,
|
||||
'completed_at', end_time,
|
||||
'duration_ms', EXTRACT(MILLISECONDS FROM (end_time - start_time)),
|
||||
'success', true
|
||||
);
|
||||
|
||||
RETURN result;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RETURN jsonb_build_object(
|
||||
'table_name', table_name,
|
||||
'operation', 'ANALYZE',
|
||||
'success', false,
|
||||
'error', SQLERRM
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Function to run REINDEX on a specific table
|
||||
CREATE OR REPLACE FUNCTION run_reindex_table(table_name text)
|
||||
RETURNS jsonb
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
DECLARE
|
||||
result jsonb;
|
||||
start_time timestamp;
|
||||
end_time timestamp;
|
||||
BEGIN
|
||||
-- Only allow superusers to run this
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM profiles
|
||||
WHERE id = auth.uid()
|
||||
AND role = 'superuser'
|
||||
) THEN
|
||||
RAISE EXCEPTION 'Only superusers can perform database maintenance';
|
||||
END IF;
|
||||
|
||||
start_time := clock_timestamp();
|
||||
|
||||
-- Execute REINDEX on the specified table
|
||||
EXECUTE format('REINDEX TABLE %I', table_name);
|
||||
|
||||
end_time := clock_timestamp();
|
||||
|
||||
result := jsonb_build_object(
|
||||
'table_name', table_name,
|
||||
'operation', 'REINDEX',
|
||||
'started_at', start_time,
|
||||
'completed_at', end_time,
|
||||
'duration_ms', EXTRACT(MILLISECONDS FROM (end_time - start_time)),
|
||||
'success', true
|
||||
);
|
||||
|
||||
RETURN result;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RETURN jsonb_build_object(
|
||||
'table_name', table_name,
|
||||
'operation', 'REINDEX',
|
||||
'success', false,
|
||||
'error', SQLERRM
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Function to get list of tables that can be maintained
|
||||
CREATE OR REPLACE FUNCTION get_maintenance_tables()
|
||||
RETURNS TABLE (
|
||||
table_name text,
|
||||
row_count bigint,
|
||||
table_size text,
|
||||
indexes_size text,
|
||||
total_size text
|
||||
)
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER
|
||||
SET search_path = public
|
||||
AS $$
|
||||
BEGIN
|
||||
-- Only allow superusers to view this
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM profiles
|
||||
WHERE id = auth.uid()
|
||||
AND role = 'superuser'
|
||||
) THEN
|
||||
RAISE EXCEPTION 'Only superusers can view database maintenance information';
|
||||
END IF;
|
||||
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
t.tablename::text,
|
||||
(xpath('/row/cnt/text()', xml_count))[1]::text::bigint as row_count,
|
||||
pg_size_pretty(pg_total_relation_size(quote_ident(t.tablename)::regclass) - pg_indexes_size(quote_ident(t.tablename)::regclass)) as table_size,
|
||||
pg_size_pretty(pg_indexes_size(quote_ident(t.tablename)::regclass)) as indexes_size,
|
||||
pg_size_pretty(pg_total_relation_size(quote_ident(t.tablename)::regclass)) as total_size
|
||||
FROM pg_tables t
|
||||
LEFT JOIN LATERAL (
|
||||
SELECT table_to_xml(t.tablename::regclass, false, true, '') as xml_count
|
||||
) x ON true
|
||||
WHERE t.schemaname = 'public'
|
||||
ORDER BY pg_total_relation_size(quote_ident(t.tablename)::regclass) DESC;
|
||||
END;
|
||||
$$;
|
||||
Reference in New Issue
Block a user