Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Stored procedure responsible for Profile status transitions now covers all cases #3295

Merged
merged 2 commits into from
May 10, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
65 changes: 65 additions & 0 deletions database/migrations/000054_profile_status_after_insert.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,65 @@
-- Copyright 2023 Stacklok, Inc
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.

-- Start to make sure the function and trigger are either both added or none
BEGIN;

-- Replace the update_profile_status() function to the one from migration 00007
CREATE OR REPLACE FUNCTION update_profile_status() RETURNS TRIGGER AS $$
DECLARE
v_profile_id UUID;
BEGIN
-- Fetch the profile_id for the current rule_eval_id
SELECT profile_id INTO v_profile_id
FROM rule_evaluations
WHERE id = NEW.rule_eval_id;

-- keep error if profile had errored
IF (NEW.status = 'error') THEN
UPDATE profile_status SET profile_status = 'error', last_updated = NOW()
WHERE profile_id = v_profile_id;
-- only mark profile run as skipped if every evaluation was skipped
ELSEIF (NEW.status = 'skipped') THEN
UPDATE profile_status SET profile_status = 'skipped', last_updated = NOW()
WHERE profile_id = v_profile_id AND NOT EXISTS (SELECT * FROM rule_evaluations res INNER JOIN rule_details_eval rde ON res.id = rde.rule_eval_id WHERE res.profile_id = v_profile_id AND rde.status != 'skipped');
-- mark status as successful if all evaluations are successful or skipped
ELSEIF NOT EXISTS (
SELECT *
FROM rule_evaluations res
INNER JOIN rule_details_eval rde ON res.id = rde.rule_eval_id
WHERE res.profile_id = v_profile_id AND rde.status != 'success' AND rde.status != 'skipped'
) THEN
UPDATE profile_status SET profile_status = 'success', last_updated = NOW()
WHERE profile_id = v_profile_id;
-- mark profile as successful if it was pending and the new status is success
ELSEIF (NEW.status = 'success') THEN
UPDATE profile_status SET profile_status = 'success', last_updated = NOW() WHERE profile_id = v_profile_id AND profile_status = 'pending';
-- CHANGE: this is the only branch that changed from the original version in this migration
-- mark status as failed if it was successful or pending or skipped and the new status is failure
-- and there are no errors
ELSIF (NEW.status = 'failure') AND NOT EXISTS (
SELECT *
FROM rule_evaluations res
INNER JOIN rule_details_eval rde ON res.id = rde.rule_eval_id
WHERE res.profile_id = v_profile_id AND rde.status = 'error'
) THEN
UPDATE profile_status SET profile_status = 'failure', last_updated = NOW()
WHERE profile_id = v_profile_id AND (profile_status = 'success' OR profile_status = 'pending' OR profile_status = 'skipped') AND NEW.status = 'failure';
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;

-- transaction commit
COMMIT;
139 changes: 139 additions & 0 deletions database/migrations/000054_profile_status_after_insert.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,139 @@
-- Copyright 2023 Stacklok, Inc
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.

-- Start to make sure the function and trigger are either both added or none
BEGIN;

CREATE OR REPLACE FUNCTION update_profile_status() RETURNS TRIGGER AS $$
DECLARE
v_status eval_status_types;
v_profile_id UUID;
v_other_error boolean;
v_other_failed boolean;
v_other_success boolean;
v_other_skipped boolean;
v_pending boolean;
BEGIN
-- Fetch the profile_id for the current rule_eval_id
SELECT profile_id INTO v_profile_id
FROM rule_evaluations
WHERE id = NEW.rule_eval_id;

-- The next five statements calculate whether there are, for this
-- profile, any rules in evaluations in status 'error', 'failure',
-- 'success', and 'skipped', respectively. This allows to write the
-- subsequent CASE statement in a more compact and readable fashion.
--
-- The consequence is that this version of the stored procedure adds
-- some load w.r.t. to previous one by unconditionally executing
-- these statements, but this should not be a problem, as all five
-- queries hit the same rows, so they'll likely hit the cache.

SELECT EXISTS (
SELECT 1 FROM rule_details_eval rde
INNER JOIN rule_evaluations res ON res.id = rde.rule_eval_id
WHERE res.profile_id = v_profile_id
AND rde.status = 'error'
) INTO v_other_error;

SELECT EXISTS (
SELECT 1 FROM rule_details_eval rde
INNER JOIN rule_evaluations res ON res.id = rde.rule_eval_id
WHERE res.profile_id = v_profile_id
AND rde.status = 'failure'
) INTO v_other_failed;

SELECT EXISTS (
SELECT 1 FROM rule_details_eval rde
INNER JOIN rule_evaluations res ON res.id = rde.rule_eval_id
WHERE res.profile_id = v_profile_id
AND rde.status = 'success'
) INTO v_other_success;

SELECT EXISTS (
SELECT 1 FROM rule_details_eval rde
INNER JOIN rule_evaluations res ON res.id = rde.rule_eval_id
WHERE res.profile_id = v_profile_id
AND rde.status = 'skipped'
) INTO v_other_skipped;

SELECT NOT EXISTS (
SELECT 1 FROM rule_details_eval rde
INNER JOIN rule_evaluations res ON res.id = rde.rule_eval_id
WHERE res.profile_id = v_profile_id
) INTO v_pending;

CASE
-- A single rule in error state means policy is in error state
WHEN NEW.status = 'error' THEN
v_status := 'error';

-- No rule in error state and at least one rule in failure state
-- means policy is in error state
WHEN NEW.STATUS = 'failure' AND v_other_error THEN
v_status := 'error';
WHEN NEW.STATUS = 'failure' THEN
v_status := 'failure';

-- No rule in error or failure state and at least one rule in
-- success state means policy is in success state
WHEN NEW.STATUS = 'success' AND v_other_error THEN
v_status := 'error';
WHEN NEW.STATUS = 'success' AND v_other_failed THEN
v_status := 'failure';
WHEN NEW.STATUS = 'success' THEN
v_status := 'success';

-- No rule in error, failure, or success state and at least one
-- rule in skipped state means policy is in skipped state
WHEN NEW.STATUS = 'skipped' AND v_other_error THEN
v_status := 'error';
WHEN NEW.STATUS = 'skipped' AND v_other_failed THEN
v_status := 'failure';
WHEN NEW.STATUS = 'skipped' AND v_other_success THEN
v_status := 'success';
WHEN NEW.STATUS = 'skipped' THEN
v_status := 'skipped';

-- No rule evaluations means the policy is pending evaluation
WHEN v_pending THEN
v_status := 'pending';

-- This should never happen, if yes, make it visible
ELSE
v_status := 'error';
RAISE WARNING 'default case should not happen';
END CASE;

-- This turned out to be very useful during debugging
-- RAISE LOG '% % % % % % % => %',
-- v_other_error,
-- v_other_failed,
-- v_other_success,
-- v_other_skipped,
-- v_pending,
-- OLD.status,
-- NEW.status,
-- v_status;

UPDATE profile_status
SET profile_status = v_status, last_updated = NOW()
WHERE profile_id = v_profile_id;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

-- transaction commit
COMMIT;
Loading
Loading