From a12f926dd524f469bd8af43ee4a2c0c339e233e9 Mon Sep 17 00:00:00 2001 From: Mike H Date: Tue, 29 Oct 2024 15:20:40 -0400 Subject: [PATCH] [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; ``` --- ...24_10_28_add_opportunity_table_triggers.py | 83 +++++++++++++++++++ api/src/db/models/opportunity_models.py | 4 + 2 files changed, 87 insertions(+) create mode 100644 api/src/db/migrations/versions/2024_10_28_add_opportunity_table_triggers.py diff --git a/api/src/db/migrations/versions/2024_10_28_add_opportunity_table_triggers.py b/api/src/db/migrations/versions/2024_10_28_add_opportunity_table_triggers.py new file mode 100644 index 000000000..268ebd29d --- /dev/null +++ b/api/src/db/migrations/versions/2024_10_28_add_opportunity_table_triggers.py @@ -0,0 +1,83 @@ +"""Add opportunity table triggers + +Revision ID: a8ebde13a18a +Revises: a2e9144cdc6b +Create Date: 2024-10-28 17:48:02.678523 + +""" + +from alembic import op + +# revision identifiers, used by Alembic. +revision = "a8ebde13a18a" +down_revision = "a2e9144cdc6b" +branch_labels = None +depends_on = None + +create_trigger_function = """ +CREATE OR REPLACE FUNCTION update_opportunity_search_queue() +RETURNS TRIGGER AS $$ +DECLARE + opp_id bigint; +BEGIN + -- Determine the opportunity_id based on the table + CASE TG_TABLE_NAME + WHEN 'link_opportunity_summary_funding_instrument' THEN + opp_id := (SELECT opportunity_id FROM api.opportunity_summary WHERE opportunity_summary_id = NEW.opportunity_summary_id); + WHEN 'link_opportunity_summary_funding_category' THEN + opp_id := (SELECT opportunity_id FROM api.opportunity_summary WHERE opportunity_summary_id = NEW.opportunity_summary_id); + WHEN 'link_opportunity_summary_applicant_type' THEN + opp_id := (SELECT opportunity_id FROM api.opportunity_summary WHERE opportunity_summary_id = NEW.opportunity_summary_id); + WHEN 'opportunity_summary' THEN + opp_id := NEW.opportunity_id; + WHEN 'current_opportunity_summary' THEN + opp_id := NEW.opportunity_id; + ELSE + opp_id := NEW.opportunity_id; + END CASE; + + INSERT INTO api.opportunity_search_index_queue (opportunity_id, has_update) + VALUES (opp_id, TRUE) + ON CONFLICT (opportunity_id) + DO UPDATE SET has_update = TRUE, updated_at = CURRENT_TIMESTAMP; + + RETURN NEW; +END; +$$ LANGUAGE plpgsql; +""" + +# List of tables that need triggers +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", +] + + +def upgrade(): + # Create the trigger function + op.execute(create_trigger_function) + + # Create triggers for each table + for table in tables: + op.execute( + f""" + CREATE TRIGGER {table}_queue_trigger + AFTER INSERT OR UPDATE ON api.{table} + FOR EACH ROW EXECUTE FUNCTION update_opportunity_search_queue(); + """ + ) + + +def downgrade(): + # Drop triggers + for table in tables: + op.execute(f"DROP TRIGGER IF EXISTS {table}_queue_trigger ON api.{table};") + + # Drop the trigger function + op.execute("DROP FUNCTION IF EXISTS update_opportunity_search_queue();") diff --git a/api/src/db/models/opportunity_models.py b/api/src/db/models/opportunity_models.py index 8dc24d28a..f6c5868e9 100644 --- a/api/src/db/models/opportunity_models.py +++ b/api/src/db/models/opportunity_models.py @@ -61,6 +61,10 @@ class Opportunity(ApiSchemaTable, TimestampMixin): back_populates="opportunity", uselist=True, cascade="all, delete-orphan" ) + opportunity_search_index_queue: Mapped["OpportunitySearchIndexQueue | None"] = relationship( + back_populates="opportunity", single_parent=True, cascade="all, delete-orphan" + ) + current_opportunity_summary: Mapped["CurrentOpportunitySummary | None"] = relationship( back_populates="opportunity", single_parent=True, cascade="all, delete-orphan" )