Fix: Database timeout when deleting large sources (#737)

* fix: implement CASCADE DELETE for source deletion timeout issue

- Add migration 009 to add CASCADE DELETE constraints to foreign keys
- Simplify delete_source() to only delete parent record
- Database now handles cascading deletes efficiently
- Fixes timeout issues when deleting sources with thousands of pages

* chore: update complete_setup.sql to include CASCADE DELETE constraints

- Add ON DELETE CASCADE to foreign keys in initial setup
- Include migration 009 in the migrations tracking
- Ensures new installations have CASCADE DELETE from the start
This commit is contained in:
Wirasm
2025-10-09 17:52:06 +03:00
committed by GitHub
parent a580fdfe66
commit 489415d723
3 changed files with 116 additions and 75 deletions

View File

@@ -0,0 +1,67 @@
-- =====================================================
-- Migration 009: Add CASCADE DELETE constraints
-- =====================================================
-- This migration adds CASCADE DELETE to foreign key constraints
-- for archon_crawled_pages and archon_code_examples tables
-- to fix database timeout issues when deleting large sources
--
-- Issue: Deleting sources with thousands of crawled pages times out
-- Solution: Let the database handle cascading deletes efficiently
-- =====================================================
-- Start transaction for atomic changes
BEGIN;
-- Drop existing foreign key constraints
ALTER TABLE archon_crawled_pages
DROP CONSTRAINT IF EXISTS archon_crawled_pages_source_id_fkey;
ALTER TABLE archon_code_examples
DROP CONSTRAINT IF EXISTS archon_code_examples_source_id_fkey;
-- Re-add foreign key constraints with CASCADE DELETE
ALTER TABLE archon_crawled_pages
ADD CONSTRAINT archon_crawled_pages_source_id_fkey
FOREIGN KEY (source_id)
REFERENCES archon_sources(source_id)
ON DELETE CASCADE;
ALTER TABLE archon_code_examples
ADD CONSTRAINT archon_code_examples_source_id_fkey
FOREIGN KEY (source_id)
REFERENCES archon_sources(source_id)
ON DELETE CASCADE;
-- Add comment explaining the CASCADE behavior
COMMENT ON CONSTRAINT archon_crawled_pages_source_id_fkey ON archon_crawled_pages IS
'Foreign key with CASCADE DELETE - automatically deletes all crawled pages when source is deleted';
COMMENT ON CONSTRAINT archon_code_examples_source_id_fkey ON archon_code_examples IS
'Foreign key with CASCADE DELETE - automatically deletes all code examples when source is deleted';
-- Record the migration
INSERT INTO archon_migrations (version, migration_name)
VALUES ('0.1.0', '009_add_cascade_delete_constraints')
ON CONFLICT (version, migration_name) DO NOTHING;
-- Commit transaction
COMMIT;
-- =====================================================
-- Verification queries (run separately if needed)
-- =====================================================
-- To verify the constraints after migration:
--
-- SELECT
-- tc.table_name,
-- tc.constraint_name,
-- tc.constraint_type,
-- rc.delete_rule
-- FROM information_schema.table_constraints tc
-- JOIN information_schema.referential_constraints rc
-- ON tc.constraint_name = rc.constraint_name
-- WHERE tc.table_name IN ('archon_crawled_pages', 'archon_code_examples')
-- AND tc.constraint_type = 'FOREIGN KEY';
--
-- Expected result: Both constraints should show delete_rule = 'CASCADE'
-- =====================================================

View File

@@ -223,8 +223,8 @@ CREATE TABLE IF NOT EXISTS archon_crawled_pages (
-- Add a unique constraint to prevent duplicate chunks for the same URL
UNIQUE(url, chunk_number),
-- Add foreign key constraint to sources table
FOREIGN KEY (source_id) REFERENCES archon_sources(source_id)
-- Add foreign key constraint to sources table with CASCADE DELETE
FOREIGN KEY (source_id) REFERENCES archon_sources(source_id) ON DELETE CASCADE
);
-- Multi-dimensional indexes
@@ -272,8 +272,8 @@ CREATE TABLE IF NOT EXISTS archon_code_examples (
-- Add a unique constraint to prevent duplicate chunks for the same URL
UNIQUE(url, chunk_number),
-- Add foreign key constraint to sources table
FOREIGN KEY (source_id) REFERENCES archon_sources(source_id)
-- Add foreign key constraint to sources table with CASCADE DELETE
FOREIGN KEY (source_id) REFERENCES archon_sources(source_id) ON DELETE CASCADE
);
-- Multi-dimensional indexes
@@ -990,7 +990,8 @@ VALUES
('0.1.0', '005_ollama_create_functions'),
('0.1.0', '006_ollama_create_indexes_optional'),
('0.1.0', '007_add_priority_column_to_tasks'),
('0.1.0', '008_add_migration_tracking')
('0.1.0', '008_add_migration_tracking'),
('0.1.0', '009_add_cascade_delete_constraints')
ON CONFLICT (version, migration_name) DO NOTHING;
-- Enable Row Level Security on migrations table