Skip to content

Commit

Permalink
feat(DB): RHINENG-1986 make tailorings and v2_policies writable
Browse files Browse the repository at this point in the history
  • Loading branch information
skateman committed Oct 30, 2023
1 parent 242fdd1 commit bd2b8ac
Show file tree
Hide file tree
Showing 13 changed files with 273 additions and 2 deletions.
3 changes: 2 additions & 1 deletion Gemfile
Original file line number Diff line number Diff line change
Expand Up @@ -25,8 +25,9 @@ gem 'rack', '>= 2.1.4'
gem 'rswag-api'
gem 'rswag-ui'

# Database view management
# Database view, function and trigger management
gem 'scenic'
gem 'fx'

# Config YAML files for all environments
gem 'config'
Expand Down
4 changes: 4 additions & 0 deletions Gemfile.lock
Original file line number Diff line number Diff line change
Expand Up @@ -175,6 +175,9 @@ GEM
ffi (1.15.5)
friendly_id (5.2.5)
activerecord (>= 4.0.0)
fx (0.8.0)
activerecord (>= 6.0.0)
railties (>= 6.0.0)
gitlab-sidekiq-fetcher (0.9.0)
json (>= 2.5)
sidekiq (~> 6.1)
Expand Down Expand Up @@ -488,6 +491,7 @@ DEPENDENCIES
faraday
faraday-retry
friendly_id (~> 5.2.4)
fx
gitlab-sidekiq-fetcher
graphiql-rails
graphql
Expand Down
30 changes: 30 additions & 0 deletions db/functions/tailorings_insert_v01.sql
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$;
10 changes: 10 additions & 0 deletions db/functions/v2_policies_delete_v01.sql
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$;
31 changes: 31 additions & 0 deletions db/functions/v2_policies_insert_v01.sql
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$;
40 changes: 40 additions & 0 deletions db/functions/v2_policies_update_v01.sql
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$;
6 changes: 6 additions & 0 deletions db/migrate/20231026190907_make_tailorings_writable.rb
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
10 changes: 10 additions & 0 deletions db/migrate/20231026194802_make_v2_policies_writable.rb
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
133 changes: 132 additions & 1 deletion db/schema.rb
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,7 @@
#
# It's strongly recommended that you check this file into your version control system.

ActiveRecord::Schema[7.0].define(version: 2023_10_24_145940) do
ActiveRecord::Schema[7.0].define(version: 2023_10_26_194802) do
# These are extensions that must be enabled in order to support this database
enable_extension "dblink"
enable_extension "pgcrypto"
Expand Down Expand Up @@ -337,4 +337,135 @@
FROM policy_hosts
GROUP BY policy_hosts.policy_id) sq ON ((sq.policy_id = policies.id)));
SQL
create_function :tailorings_insert, sql_definition: <<-'SQL'
CREATE OR REPLACE FUNCTION public.tailorings_insert()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
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
$function$
SQL
create_function :v2_policies_insert, sql_definition: <<-'SQL'
CREATE OR REPLACE FUNCTION public.v2_policies_insert()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
DECLARE bo_id uuid;
DECLARE result_id uuid;
BEGIN
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
$function$
SQL
create_function :v2_policies_delete, sql_definition: <<-'SQL'
CREATE OR REPLACE FUNCTION public.v2_policies_delete()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
DECLARE bo_id uuid;
BEGIN
SELECT "business_objective_id" INTO "bo_id" FROM "policies" WHERE "id" = OLD."id";
DELETE FROM "policies" WHERE "id" = OLD."id";
DELETE FROM "business_objectives" WHERE "id" = bo_id;
RETURN OLD;
END
$function$
SQL
create_function :v2_policies_update, sql_definition: <<-'SQL'
CREATE OR REPLACE FUNCTION public.v2_policies_update()
RETURNS trigger
LANGUAGE plpgsql
AS $function$
DECLARE "bo_id" uuid;
BEGIN
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 "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 "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";
DELETE FROM "business_objectives" USING "policies"
WHERE NEW."business_objective" IS NULL AND "business_objectives"."id" = "bo_id";
RETURN NEW;
END
$function$
SQL


create_trigger :tailorings_insert, sql_definition: <<-SQL
CREATE TRIGGER tailorings_insert INSTEAD OF INSERT ON public.tailorings FOR EACH ROW EXECUTE FUNCTION tailorings_insert()
SQL
create_trigger :v2_policies_insert, sql_definition: <<-SQL
CREATE TRIGGER v2_policies_insert INSTEAD OF INSERT ON public.v2_policies FOR EACH ROW EXECUTE FUNCTION v2_policies_insert()
SQL
create_trigger :v2_policies_delete, sql_definition: <<-SQL
CREATE TRIGGER v2_policies_delete INSTEAD OF DELETE ON public.v2_policies FOR EACH ROW EXECUTE FUNCTION v2_policies_delete()
SQL
create_trigger :v2_policies_update, sql_definition: <<-SQL
CREATE TRIGGER v2_policies_update INSTEAD OF UPDATE ON public.v2_policies FOR EACH ROW EXECUTE FUNCTION v2_policies_update()
SQL
end
2 changes: 2 additions & 0 deletions db/triggers/tailorings_insert_v01.sql
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();
2 changes: 2 additions & 0 deletions db/triggers/v2_policies_delete_v01.sql
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();
2 changes: 2 additions & 0 deletions db/triggers/v2_policies_insert_v01.sql
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();
2 changes: 2 additions & 0 deletions db/triggers/v2_policies_update_v01.sql
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();

0 comments on commit bd2b8ac

Please sign in to comment.