Skip to content

Commit

Permalink
RHINENG-14390: rewrite on_system_update trigger without locking
Browse files Browse the repository at this point in the history
add indexes for filtering system counts in advisory_account_data
  • Loading branch information
psegedy committed Nov 22, 2024
1 parent e31fd67 commit 2894eb2
Show file tree
Hide file tree
Showing 2 changed files with 85 additions and 20 deletions.
73 changes: 73 additions & 0 deletions database_admin/migrations/132_on_system_update_no_lock.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,73 @@
CREATE OR REPLACE FUNCTION on_system_update()
-- this trigger updates advisory_account_data when server changes its stale flag
RETURNS TRIGGER
AS
$system_update$
DECLARE
was_counted BOOLEAN;
should_count BOOLEAN;
change INT;
BEGIN
-- Ignore not yet evaluated systems
IF TG_OP != 'UPDATE' OR NEW.last_evaluation IS NULL THEN
RETURN NEW;
END IF;

was_counted := OLD.stale = FALSE;
should_count := NEW.stale = FALSE;

-- Determine what change we are performing
IF was_counted and NOT should_count THEN
change := -1;
ELSIF NOT was_counted AND should_count THEN
change := 1;
ELSE
-- No change
RETURN NEW;
END IF;

-- find advisories linked to the server
WITH to_update_advisories AS (
SELECT aad.advisory_id,
aad.rh_account_id,
case when sa.status_id = 0 then change else 0 end as systems_installable_change,
change as systems_applicable_change
FROM advisory_account_data aad
JOIN system_advisories sa ON aad.advisory_id = sa.advisory_id
-- Filter advisory_account_data only for advisories affectign this system & belonging to system account
WHERE aad.rh_account_id = NEW.rh_account_id
AND sa.system_id = NEW.id AND sa.rh_account_id = NEW.rh_account_id
ORDER BY aad.advisory_id),
-- update existing rows
update AS (
UPDATE advisory_account_data aad
SET systems_installable = aad.systems_installable + ta.systems_installable_change,
systems_applicable = aad.systems_applicable + ta.systems_applicable_change
FROM to_update_advisories ta
WHERE aad.advisory_id = ta.advisory_id
AND aad.rh_account_id = NEW.rh_account_id
)
-- If we have system affected && no exisiting advisory_account_data entry, we insert new rows
INSERT
INTO advisory_account_data (advisory_id, rh_account_id, systems_installable, systems_applicable)
SELECT sa.advisory_id, NEW.rh_account_id,
case when sa.status_id = 0 then 1 else 0 end as systems_installable,
1 as systems_applicable
FROM system_advisories sa
WHERE sa.system_id = NEW.id AND sa.rh_account_id = NEW.rh_account_id
AND change > 0
-- create only rows which are not already in to_update_advisories
AND (NEW.rh_account_id, sa.advisory_id) NOT IN (
SELECT ta.rh_account_id, ta.advisory_id
FROM to_update_advisories ta
)
ON CONFLICT (advisory_id, rh_account_id) DO UPDATE
SET systems_installable = advisory_account_data.systems_installable + EXCLUDED.systems_installable,
systems_applicable = advisory_account_data.systems_applicable + EXCLUDED.systems_applicable;
RETURN NEW;
END;
$system_update$ LANGUAGE plpgsql;

-- indexes for filtering systems_applicable, systems_installable
CREATE INDEX ON advisory_account_data (systems_applicable);
CREATE INDEX ON advisory_account_data (systems_installable);
32 changes: 12 additions & 20 deletions database_admin/schema/create_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@ CREATE TABLE IF NOT EXISTS schema_migrations


INSERT INTO schema_migrations
VALUES (131, false);
VALUES (132, false);

-- ---------------------------------------------------------------------------
-- Functions
Expand Down Expand Up @@ -107,38 +107,26 @@ BEGIN
RETURN NEW;
END IF;

-- find advisories linked to the server and lock them
-- find advisories linked to the server
WITH to_update_advisories AS (
SELECT aad.advisory_id,
aad.rh_account_id,
-- Desired count depends on old count + change
aad.systems_installable + case when sa.status_id = 0 then change else 0 end as systems_installable_dst,
aad.systems_applicable + change as systems_applicable_dst
case when sa.status_id = 0 then change else 0 end as systems_installable_change,
change as systems_applicable_change
FROM advisory_account_data aad
JOIN system_advisories sa ON aad.advisory_id = sa.advisory_id
-- Filter advisory_account_data only for advisories affectign this system & belonging to system account
WHERE aad.rh_account_id = NEW.rh_account_id
AND sa.system_id = NEW.id AND sa.rh_account_id = NEW.rh_account_id
ORDER BY aad.advisory_id FOR UPDATE OF aad),
-- Where count > 0, update existing rows
ORDER BY aad.advisory_id),
-- update existing rows
update AS (
UPDATE advisory_account_data aad
SET systems_installable = ta.systems_installable_dst,
systems_applicable = ta.systems_applicable_dst
SET systems_installable = aad.systems_installable + ta.systems_installable_change,
systems_applicable = aad.systems_applicable + ta.systems_applicable_change
FROM to_update_advisories ta
WHERE aad.advisory_id = ta.advisory_id
AND aad.rh_account_id = NEW.rh_account_id
AND (ta.systems_installable_dst > 0 OR ta.systems_applicable_dst > 0)
),
-- Where count = 0, delete existing rows
delete AS (
DELETE
FROM advisory_account_data aad
USING to_update_advisories ta
WHERE aad.rh_account_id = ta.rh_account_id
AND aad.advisory_id = ta.advisory_id
AND ta.systems_installable_dst <= 0
AND ta.systems_applicable_dst <= 0
)
-- If we have system affected && no exisiting advisory_account_data entry, we insert new rows
INSERT
Expand Down Expand Up @@ -950,6 +938,10 @@ GRANT SELECT, INSERT, UPDATE, DELETE ON advisory_account_data TO listener;
-- vmaas_sync needs to update stale mark, which creates and deletes advisory_account_data
GRANT SELECT, INSERT, UPDATE, DELETE ON advisory_account_data TO vmaas_sync;

-- indexes for filtering systems_applicable, systems_installable
CREATE INDEX ON advisory_account_data (systems_applicable);
CREATE INDEX ON advisory_account_data (systems_installable);

-- repo
CREATE TABLE IF NOT EXISTS repo
(
Expand Down

0 comments on commit 2894eb2

Please sign in to comment.