From e2ee11b9f502195abf603bc2e09bc0ee414ca11d Mon Sep 17 00:00:00 2001 From: "gpt-engineer-app[bot]" <159125892+gpt-engineer-app[bot]@users.noreply.github.com> Date: Wed, 12 Nov 2025 01:39:05 +0000 Subject: [PATCH] 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 --- src/App.tsx | 9 + src/components/layout/AdminSidebar.tsx | 10 +- src/hooks/admin/useDatabaseMaintenance.ts | 135 +++++++++++ src/integrations/supabase/types.ts | 13 + src/lib/queryKeys.ts | 1 + src/pages/admin/DatabaseMaintenance.tsx | 224 ++++++++++++++++++ ...4_f6cee3a7-9a88-490b-95a0-8c18596d6a07.sql | 188 +++++++++++++++ 7 files changed, 578 insertions(+), 2 deletions(-) create mode 100644 src/hooks/admin/useDatabaseMaintenance.ts create mode 100644 src/pages/admin/DatabaseMaintenance.tsx create mode 100644 supabase/migrations/20251112013704_f6cee3a7-9a88-490b-95a0-8c18596d6a07.sql diff --git a/src/App.tsx b/src/App.tsx index 558100ee..53704f3b 100644 --- a/src/App.tsx +++ b/src/App.tsx @@ -70,6 +70,7 @@ const AdminUsers = lazy(() => import("./pages/AdminUsers")); const AdminBlog = lazy(() => import("./pages/AdminBlog")); const AdminSettings = lazy(() => import("./pages/AdminSettings")); const AdminDatabaseStats = lazy(() => import("./pages/AdminDatabaseStats")); +const DatabaseMaintenance = lazy(() => import("./pages/admin/DatabaseMaintenance")); const AdminContact = lazy(() => import("./pages/admin/AdminContact")); const AdminEmailSettings = lazy(() => import("./pages/admin/AdminEmailSettings")); const ErrorMonitoring = lazy(() => import("./pages/admin/ErrorMonitoring")); @@ -423,6 +424,14 @@ function AppContent(): React.JSX.Element { } /> + + + + } + /> {/* Utility routes - lazy loaded */} } /> diff --git a/src/components/layout/AdminSidebar.tsx b/src/components/layout/AdminSidebar.tsx index 628f28db..83f821a0 100644 --- a/src/components/layout/AdminSidebar.tsx +++ b/src/components/layout/AdminSidebar.tsx @@ -1,4 +1,4 @@ -import { LayoutDashboard, FileText, Flag, Users, Settings, ArrowLeft, ScrollText, BookOpen, Inbox, Mail, AlertTriangle, Shield, Activity, BarChart } from 'lucide-react'; +import { LayoutDashboard, FileText, Flag, Users, Settings, ArrowLeft, ScrollText, BookOpen, Inbox, Mail, AlertTriangle, Shield, Activity, BarChart, Database } from 'lucide-react'; import { NavLink } from 'react-router-dom'; import { useUserRole } from '@/hooks/useUserRole'; import { useSidebar } from '@/hooks/useSidebar'; @@ -73,6 +73,12 @@ export function AdminSidebar() { url: '/admin/database-stats', icon: BarChart, }, + { + title: 'Database Maintenance', + url: '/admin/database-maintenance', + icon: Database, + visible: isSuperuser, // Only superusers can access + }, { title: 'Users', url: '/admin/users', @@ -134,7 +140,7 @@ export function AdminSidebar() { Navigation - {navItems.map((item) => ( + {navItems.filter(item => item.visible !== false).map((item) => ( { + const { data, error } = await supabase.rpc('get_maintenance_tables'); + + if (error) throw error; + + return data as unknown as MaintenanceTable[]; + }, + staleTime: 2 * 60 * 1000, // 2 minutes + }); +} + +export function useVacuumTable() { + const queryClient = useQueryClient(); + + return useMutation({ + mutationFn: async (tableName: string) => { + const { data, error } = await supabase.rpc('run_vacuum_table', { + table_name: tableName, + }); + + if (error) throw error; + + return data as unknown as MaintenanceResult; + }, + onSuccess: (result) => { + if (result.success) { + toast.success(`Vacuum completed on ${result.table_name}`, { + description: `Duration: ${Math.round(result.duration_ms)}ms`, + }); + } else { + toast.error(`Vacuum failed on ${result.table_name}`, { + description: result.error, + }); + } + queryClient.invalidateQueries({ queryKey: queryKeys.admin.maintenanceTables() }); + }, + onError: (error: Error) => { + toast.error('Vacuum operation failed', { + description: error.message, + }); + }, + }); +} + +export function useAnalyzeTable() { + const queryClient = useQueryClient(); + + return useMutation({ + mutationFn: async (tableName: string) => { + const { data, error } = await supabase.rpc('run_analyze_table', { + table_name: tableName, + }); + + if (error) throw error; + + return data as unknown as MaintenanceResult; + }, + onSuccess: (result) => { + if (result.success) { + toast.success(`Analyze completed on ${result.table_name}`, { + description: `Duration: ${Math.round(result.duration_ms)}ms`, + }); + } else { + toast.error(`Analyze failed on ${result.table_name}`, { + description: result.error, + }); + } + queryClient.invalidateQueries({ queryKey: queryKeys.admin.maintenanceTables() }); + }, + onError: (error: Error) => { + toast.error('Analyze operation failed', { + description: error.message, + }); + }, + }); +} + +export function useReindexTable() { + const queryClient = useQueryClient(); + + return useMutation({ + mutationFn: async (tableName: string) => { + const { data, error } = await supabase.rpc('run_reindex_table', { + table_name: tableName, + }); + + if (error) throw error; + + return data as unknown as MaintenanceResult; + }, + onSuccess: (result) => { + if (result.success) { + toast.success(`Reindex completed on ${result.table_name}`, { + description: `Duration: ${Math.round(result.duration_ms)}ms`, + }); + } else { + toast.error(`Reindex failed on ${result.table_name}`, { + description: result.error, + }); + } + queryClient.invalidateQueries({ queryKey: queryKeys.admin.maintenanceTables() }); + }, + onError: (error: Error) => { + toast.error('Reindex operation failed', { + description: error.message, + }); + }, + }); +} diff --git a/src/integrations/supabase/types.ts b/src/integrations/supabase/types.ts index 2eaba647..366c6a72 100644 --- a/src/integrations/supabase/types.ts +++ b/src/integrations/supabase/types.ts @@ -6853,6 +6853,16 @@ export type Database = { Args: { _profile_user_id: string; _viewer_id?: string } Returns: Json } + get_maintenance_tables: { + Args: never + Returns: { + indexes_size: string + row_count: number + table_name: string + table_size: string + total_size: string + }[] + } get_my_sessions: { Args: never Returns: { @@ -7115,6 +7125,7 @@ export type Database = { Returns: string } run_all_cleanup_jobs: { Args: never; Returns: Json } + run_analyze_table: { Args: { table_name: string }; Returns: Json } run_data_retention_cleanup: { Args: never; Returns: Json } run_pipeline_monitoring: { Args: never @@ -7124,6 +7135,7 @@ export type Database = { status: string }[] } + run_reindex_table: { Args: { table_name: string }; Returns: Json } run_system_maintenance: { Args: never Returns: { @@ -7132,6 +7144,7 @@ export type Database = { task: string }[] } + run_vacuum_table: { Args: { table_name: string }; Returns: Json } set_config_value: { Args: { is_local?: boolean diff --git a/src/lib/queryKeys.ts b/src/lib/queryKeys.ts index 4b6183b7..55c19a28 100644 --- a/src/lib/queryKeys.ts +++ b/src/lib/queryKeys.ts @@ -103,6 +103,7 @@ export const queryKeys = { admin: { databaseStats: () => ['admin', 'database-stats'] as const, recentAdditions: (limit: number) => ['admin', 'recent-additions', limit] as const, + maintenanceTables: () => ['admin', 'maintenance-tables'] as const, }, // Analytics queries diff --git a/src/pages/admin/DatabaseMaintenance.tsx b/src/pages/admin/DatabaseMaintenance.tsx new file mode 100644 index 00000000..2b03795a --- /dev/null +++ b/src/pages/admin/DatabaseMaintenance.tsx @@ -0,0 +1,224 @@ +import { useState } from 'react'; +import { AdminLayout } from '@/components/layout/AdminLayout'; +import { AdminPageLayout } from '@/components/admin'; +import { Card, CardContent, CardDescription, CardHeader, CardTitle } from '@/components/ui/card'; +import { Button } from '@/components/ui/button'; +import { Badge } from '@/components/ui/badge'; +import { Alert, AlertDescription, AlertTitle } from '@/components/ui/alert'; +import { + Table, + TableBody, + TableCell, + TableHead, + TableHeader, + TableRow, +} from '@/components/ui/table'; +import { + useMaintenanceTables, + useVacuumTable, + useAnalyzeTable, + useReindexTable, +} from '@/hooks/admin/useDatabaseMaintenance'; +import { Database, RefreshCw, Zap, Settings, AlertTriangle } from 'lucide-react'; +import { Skeleton } from '@/components/ui/skeleton'; + +export default function DatabaseMaintenance() { + const { data: tables, isLoading, refetch } = useMaintenanceTables(); + const vacuumMutation = useVacuumTable(); + const analyzeMutation = useAnalyzeTable(); + const reindexMutation = useReindexTable(); + + const [selectedTable, setSelectedTable] = useState(null); + + const handleVacuum = (tableName: string) => { + setSelectedTable(tableName); + vacuumMutation.mutate(tableName); + }; + + const handleAnalyze = (tableName: string) => { + setSelectedTable(tableName); + analyzeMutation.mutate(tableName); + }; + + const handleReindex = (tableName: string) => { + setSelectedTable(tableName); + reindexMutation.mutate(tableName); + }; + + const isOperationPending = (tableName: string) => { + return ( + selectedTable === tableName && + (vacuumMutation.isPending || analyzeMutation.isPending || reindexMutation.isPending) + ); + }; + + return ( + + + + + Superuser Access Required + + These operations require superuser privileges. They can help improve database + performance by reclaiming storage, updating statistics, and rebuilding indexes. + + + +
+ + + VACUUM + + + + + Reclaims storage occupied by dead tuples and makes space available for reuse + + + + + + + ANALYZE + + + + + Updates statistics used by the query planner for optimal query execution plans + + + + + + + REINDEX + + + + + Rebuilds indexes to eliminate bloat and restore optimal index performance + + + +
+ + + +
+
+ Database Tables + + Select maintenance operations to perform on each table + +
+ +
+
+ + {isLoading ? ( +
+ {Array.from({ length: 5 }).map((_, i) => ( + + ))} +
+ ) : tables && tables.length > 0 ? ( +
+ + + + Table Name + Rows + Table Size + Indexes Size + Total Size + Actions + + + + {tables.map((table) => ( + + + {table.table_name} + + + {table.row_count?.toLocaleString() || 'N/A'} + + + {table.table_size} + + + {table.indexes_size} + + + {table.total_size} + + +
+ + + +
+
+
+ ))} +
+
+
+ ) : ( +
+ No tables available +
+ )} +
+
+
+
+ ); +} diff --git a/supabase/migrations/20251112013704_f6cee3a7-9a88-490b-95a0-8c18596d6a07.sql b/supabase/migrations/20251112013704_f6cee3a7-9a88-490b-95a0-8c18596d6a07.sql new file mode 100644 index 00000000..44b2117e --- /dev/null +++ b/supabase/migrations/20251112013704_f6cee3a7-9a88-490b-95a0-8c18596d6a07.sql @@ -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; +$$; \ No newline at end of file