Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
[Issue #2603] Setup triggers on our opportunity tables which populate…
… the search queue table (#2611) Summary Fixes #2603 Time to review: 15 mins Changes proposed Add migration which adds DB triggers to populate `opportunity_search_index_queue` based on updates made to existing tables: opportunity opportunity_assistance_listing current_opportunity_summary opportunity_summary link_opportunity_summary_funding_instrument link_opportunity_summary_funding_category link_opportunity_summary_applicant_type opportunity_attachment Context for reviewers See test SQL below. Created migration will add or update entries in the opportunity_search_index_queue table until a subsequent process handles them. Additional information See attached SQL file for running tests based on these changes: ``` -- Start transaction for all tests BEGIN; -- Test 1: Basic opportunity insert INSERT INTO api.opportunity (opportunity_id, opportunity_title, is_draft) VALUES (99999, 'Test Opportunity', false); -- Verify queue entry was created SELECT EXISTS ( SELECT 1 FROM api.opportunity_search_index_queue WHERE opportunity_id = 99999 AND has_update = true ) as "Test 1: Queue entry created for new opportunity"; -- Test 2: Multiple related inserts in single transaction INSERT INTO api.opportunity (opportunity_id, opportunity_title, is_draft) VALUES (99998, 'Test Multi-Update Opportunity', false); INSERT INTO api.opportunity_summary ( opportunity_summary_id, opportunity_id, summary_description, is_forecast ) VALUES (99998, 99998, 'Test Summary', false); INSERT INTO api.current_opportunity_summary ( opportunity_id, opportunity_summary_id, opportunity_status_id ) VALUES (99998, 99998, 1); INSERT INTO api.link_opportunity_summary_funding_instrument ( opportunity_summary_id, funding_instrument_id ) VALUES (99998, 1); INSERT INTO api.opportunity_attachment ( attachment_id, opportunity_id, opportunity_attachment_type_id, file_location, mime_type, file_name, file_description, file_size_bytes ) VALUES ( 99998, 99998, 1, 'test/location', 'text/plain', 'test.txt', 'Test file', 100 ); -- Verify only one queue entry exists for multiple updates SELECT (SELECT COUNT(*) FROM api.opportunity_search_index_queue WHERE opportunity_id = 99998) = 1 as "Test 2: Single queue entry for multiple updates"; -- Test 3: Update existing record UPDATE api.opportunity SET opportunity_title = 'Updated Title' WHERE opportunity_id = 99999; -- Verify has_update is still true SELECT has_update FROM api.opportunity_search_index_queue WHERE opportunity_id = 99999 as "Test 3: has_update still true after update"; -- Test 4: Link table triggers INSERT INTO api.opportunity_summary ( opportunity_summary_id, opportunity_id, summary_description, is_forecast ) VALUES (99999, 99999, 'Another Test Summary', false); INSERT INTO api.link_opportunity_summary_funding_instrument ( opportunity_summary_id, funding_instrument_id ) VALUES (99999, 1); -- Verify queue entry still exists and has_update is true SELECT EXISTS ( SELECT 1 FROM api.opportunity_search_index_queue WHERE opportunity_id = 99999 AND has_update = true ) as "Test 4: Queue entry exists after link table insert"; -- Test 5: Verify timestamps are updating UPDATE api.opportunity SET opportunity_title = 'Another Update' WHERE opportunity_id = 99999; SELECT updated_at > created_at FROM api.opportunity_search_index_queue WHERE opportunity_id = 99999 as "Test 5: Updated timestamp is newer than created"; -- Output all test data for manual verification SELECT 'Final Queue State' as description; SELECT * FROM api.opportunity_search_index_queue WHERE opportunity_id IN (99999, 99998); -- Cleanup ROLLBACK; ```
- Loading branch information