-
Notifications
You must be signed in to change notification settings - Fork 31
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
feat(DB): RHINENG-1986 make tailorings and v2_policies writable
- Loading branch information
Showing
13 changed files
with
273 additions
and
2 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,30 @@ | ||
CREATE OR REPLACE FUNCTION tailorings_insert() RETURNS trigger LANGUAGE plpgsql AS | ||
$func$ | ||
DECLARE result_id uuid; | ||
BEGIN | ||
|
||
INSERT INTO "profiles" ( | ||
"policy_id", | ||
"account_id", | ||
"parent_profile_id", | ||
"benchmark_id", | ||
"value_overrides", | ||
"created_at", | ||
"updated_at" | ||
) SELECT | ||
NEW."policy_id", | ||
"policies"."account_id", | ||
NEW."profile_id", | ||
"canonical_profiles"."security_guide_id", | ||
NEW."value_overrides", | ||
NEW."created_at", | ||
NEW."updated_at" | ||
FROM "policies" | ||
INNER JOIN "canonical_profiles" ON "canonical_profiles"."id" = "policies"."profile_id" | ||
WHERE "policies"."id" = NEW."policy_id" RETURNING "id" INTO "result_id"; | ||
|
||
NEW."id" := "result_id"; | ||
RETURN NEW; | ||
|
||
END | ||
$func$; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,10 @@ | ||
CREATE OR REPLACE FUNCTION v2_policies_delete() RETURNS trigger LANGUAGE plpgsql AS | ||
$func$ | ||
DECLARE bo_id uuid; | ||
BEGIN | ||
DELETE FROM "policies" WHERE "id" = OLD."id" RETURNING "business_objective_id" INTO "bo_id"; | ||
-- Delete any remaining business objectives associated with the policy of no other policies use it | ||
DELETE FROM "business_objectives" WHERE "id" = "bo_id" AND (SELECT COUNT("id") FROM "policies" WHERE "business_objectives"."id" = "bo_id") = 0; | ||
RETURN OLD; | ||
END | ||
$func$; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,31 @@ | ||
CREATE OR REPLACE FUNCTION v2_policies_insert() RETURNS trigger LANGUAGE plpgsql AS | ||
$func$ | ||
DECLARE bo_id uuid; | ||
DECLARE result_id uuid; | ||
BEGIN | ||
-- Insert a new business objective record if the business_objective field is | ||
-- set to a value and return with its ID. | ||
INSERT INTO "business_objectives" ("title", "created_at", "updated_at") | ||
SELECT NEW."business_objective", NOW(), NOW() | ||
WHERE NEW."business_objective" IS NOT NULL RETURNING "id" INTO "bo_id"; | ||
|
||
INSERT INTO "policies" ( | ||
"name", | ||
"description", | ||
"compliance_threshold", | ||
"business_objective_id", | ||
"profile_id", | ||
"account_id" | ||
) VALUES ( | ||
NEW."title", | ||
NEW."description", | ||
NEW."compliance_threshold", | ||
"bo_id", | ||
NEW."profile_id", | ||
NEW."account_id" | ||
) RETURNING "id" INTO "result_id"; | ||
|
||
NEW."id" := "result_id"; | ||
RETURN NEW; | ||
END | ||
$func$; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,40 @@ | ||
CREATE OR REPLACE FUNCTION v2_policies_update() RETURNS trigger LANGUAGE plpgsql AS | ||
$func$ | ||
DECLARE "bo_id" uuid; | ||
BEGIN | ||
-- Create a new business objective record if the apropriate field is set and there is no | ||
-- existing business objective already assigned to the policy and return with its ID. | ||
INSERT INTO "business_objectives" ("title", "created_at", "updated_at") | ||
SELECT NEW."business_objective", NOW(), NOW() FROM "policies" WHERE | ||
NEW."business_objective" IS NOT NULL AND | ||
"policies"."business_objective_id" IS NULL AND | ||
"policies"."id" = OLD."id" | ||
RETURNING "id" INTO "bo_id"; | ||
|
||
-- If the previous insertion was successful, there is nothing to update, otherwise try to | ||
-- update any existing business objective assigned to the policy and return with its ID. | ||
IF "bo_id" IS NULL THEN | ||
UPDATE "business_objectives" SET "title" = NEW."business_objective", "updated_at" = NOW() | ||
FROM "policies" WHERE | ||
"policies"."business_objective_id" = "business_objectives"."id" AND | ||
"policies"."id" = OLD."id" | ||
RETURNING "business_objectives"."id" INTO "bo_id"; | ||
END IF; | ||
|
||
-- Update the policy itself, use the ID of the business objective from the previous two queries, | ||
-- if the business_objective field is set to NULL, remove the link between the two tables. | ||
UPDATE "policies" SET | ||
"name" = NEW."title", | ||
"description" = NEW."description", | ||
"compliance_threshold" = NEW."compliance_threshold", | ||
"business_objective_id" = CASE WHEN NEW."business_objective" IS NULL THEN NULL ELSE "bo_id" END | ||
WHERE "id" = OLD."id"; | ||
|
||
-- If the business_objective field is set to NULL, delete its record in the business objectives | ||
-- table using the ID retrieved during the second query. | ||
DELETE FROM "business_objectives" USING "policies" | ||
WHERE NEW."business_objective" IS NULL AND "business_objectives"."id" = "bo_id"; | ||
|
||
RETURN NEW; | ||
END | ||
$func$; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,6 @@ | ||
class MakeTailoringsWritable < ActiveRecord::Migration[7.0] | ||
def change | ||
create_function :tailorings_insert | ||
create_trigger :tailorings_insert, on: :tailorings | ||
end | ||
end |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,10 @@ | ||
class MakeV2PoliciesWritable < ActiveRecord::Migration[7.0] | ||
def change | ||
create_function :v2_policies_insert | ||
create_trigger :v2_policies_insert, on: :v2_policies | ||
create_function :v2_policies_delete | ||
create_trigger :v2_policies_delete, on: :v2_policies | ||
create_function :v2_policies_update | ||
create_trigger :v2_policies_update, on: :v2_policies | ||
end | ||
end |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
CREATE TRIGGER "tailorings_insert" INSTEAD OF INSERT ON "tailorings" | ||
FOR EACH ROW EXECUTE FUNCTION tailorings_insert(); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
CREATE TRIGGER "v2_policies_delete" INSTEAD OF DELETE ON "v2_policies" | ||
FOR EACH ROW EXECUTE FUNCTION v2_policies_delete(); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
CREATE TRIGGER "v2_policies_insert" INSTEAD OF INSERT ON "v2_policies" | ||
FOR EACH ROW EXECUTE FUNCTION v2_policies_insert(); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
CREATE TRIGGER "v2_policies_update" INSTEAD OF UPDATE ON "v2_policies" | ||
FOR EACH ROW EXECUTE FUNCTION v2_policies_update(); |