From 9850c76d4fa6de7f2866d08a348e170932d8aa77 Mon Sep 17 00:00:00 2001 From: Luke Vella Date: Sun, 22 Dec 2024 11:48:34 +0100 Subject: [PATCH] Batch processing and error handling improvements --- .../migration.sql | 107 +++++++++++++----- 1 file changed, 77 insertions(+), 30 deletions(-) diff --git a/packages/database/prisma/migrations/20241218160237_create_guest_users/migration.sql b/packages/database/prisma/migrations/20241218160237_create_guest_users/migration.sql index a737688a8..752064a61 100644 --- a/packages/database/prisma/migrations/20241218160237_create_guest_users/migration.sql +++ b/packages/database/prisma/migrations/20241218160237_create_guest_users/migration.sql @@ -1,51 +1,98 @@ +BEGIN; + -- Create guest users for participants without user_id and link them DO $$ DECLARE - participant_record RECORD; + v_processed INTEGER := 0; + v_total_processed INTEGER := 0; + v_batch_size INTEGER := 1000; BEGIN - FOR participant_record IN - SELECT id, name, email - FROM participants - WHERE user_id IS NULL + RAISE NOTICE 'Starting participant migration...'; + + -- Process participants in batches LOOP - WITH new_user AS ( + WITH to_process AS ( + SELECT id, name, email + FROM participants + WHERE user_id IS NULL + LIMIT v_batch_size + FOR UPDATE SKIP LOCKED + ), + new_users AS ( INSERT INTO users (id, is_guest, created_at) - VALUES ( - gen_random_uuid()::text, - TRUE, - NOW() - ) + SELECT gen_random_uuid()::text, TRUE, NOW() + FROM to_process RETURNING id ) - UPDATE participants - SET user_id = (SELECT id FROM new_user) - WHERE id = participant_record.id; + UPDATE participants p + SET user_id = u.id + FROM ( + SELECT id, ROW_NUMBER() OVER () as rn + FROM new_users + ) u + WHERE p.id IN ( + SELECT id FROM to_process + ) + AND p.user_id IS NULL; + + GET DIAGNOSTICS v_processed = ROW_COUNT; + v_total_processed := v_total_processed + v_processed; + + EXIT WHEN v_processed = 0; + RAISE NOTICE 'Processed % participants (total: %)', v_processed, v_total_processed; END LOOP; + + RAISE NOTICE 'Completed participant migration. Total processed: %', v_total_processed; END; -$$; +$$; -- Create guest users for comments without user_id and link them DO $$ DECLARE - comment_record RECORD; + v_processed INTEGER := 0; + v_total_processed INTEGER := 0; + v_batch_size INTEGER := 1000; BEGIN - FOR comment_record IN - SELECT id, author_name - FROM comments - WHERE user_id IS NULL + RAISE NOTICE 'Starting comment migration...'; + + -- Process comments in batches LOOP - WITH new_user AS ( + WITH to_process AS ( + SELECT id, author_name + FROM comments + WHERE user_id IS NULL + LIMIT v_batch_size + FOR UPDATE SKIP LOCKED + ), + new_users AS ( INSERT INTO users (id, is_guest, created_at) - VALUES ( - gen_random_uuid()::text, - TRUE, - NOW() - ) + SELECT gen_random_uuid()::text, TRUE, NOW() + FROM to_process RETURNING id ) - UPDATE comments - SET user_id = (SELECT id FROM new_user) - WHERE id = comment_record.id; + UPDATE comments c + SET user_id = u.id + FROM ( + SELECT id, ROW_NUMBER() OVER () as rn + FROM new_users + ) u + WHERE c.id IN ( + SELECT id FROM to_process + ) + AND c.user_id IS NULL; + + GET DIAGNOSTICS v_processed = ROW_COUNT; + v_total_processed := v_total_processed + v_processed; + + EXIT WHEN v_processed = 0; + RAISE NOTICE 'Processed % comments (total: %)', v_processed, v_total_processed; END LOOP; + + RAISE NOTICE 'Completed comment migration. Total processed: %', v_total_processed; +EXCEPTION WHEN OTHERS THEN + RAISE WARNING 'Error during comment migration: %', SQLERRM; + RAISE; END; -$$; \ No newline at end of file +$$; + +COMMIT; \ No newline at end of file