diff --git a/Gemfile b/Gemfile index 334559f99..d8a9b5715 100644 --- a/Gemfile +++ b/Gemfile @@ -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' diff --git a/Gemfile.lock b/Gemfile.lock index ebba3b3ba..f9e693743 100644 --- a/Gemfile.lock +++ b/Gemfile.lock @@ -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) @@ -488,6 +491,7 @@ DEPENDENCIES faraday faraday-retry friendly_id (~> 5.2.4) + fx gitlab-sidekiq-fetcher graphiql-rails graphql diff --git a/db/functions/tailorings_insert_v01.sql b/db/functions/tailorings_insert_v01.sql new file mode 100644 index 000000000..51a8a0de3 --- /dev/null +++ b/db/functions/tailorings_insert_v01.sql @@ -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$; diff --git a/db/functions/v2_policies_delete_v01.sql b/db/functions/v2_policies_delete_v01.sql new file mode 100644 index 000000000..260a2ae7b --- /dev/null +++ b/db/functions/v2_policies_delete_v01.sql @@ -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$; diff --git a/db/functions/v2_policies_insert_v01.sql b/db/functions/v2_policies_insert_v01.sql new file mode 100644 index 000000000..1d9063d45 --- /dev/null +++ b/db/functions/v2_policies_insert_v01.sql @@ -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$; diff --git a/db/functions/v2_policies_update_v01.sql b/db/functions/v2_policies_update_v01.sql new file mode 100644 index 000000000..dccc0227b --- /dev/null +++ b/db/functions/v2_policies_update_v01.sql @@ -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$; diff --git a/db/migrate/20231026190907_make_tailorings_writable.rb b/db/migrate/20231026190907_make_tailorings_writable.rb new file mode 100644 index 000000000..ad8c8fab8 --- /dev/null +++ b/db/migrate/20231026190907_make_tailorings_writable.rb @@ -0,0 +1,6 @@ +class MakeTailoringsWritable < ActiveRecord::Migration[7.0] + def change + create_function :tailorings_insert + create_trigger :tailorings_insert, on: :tailorings + end +end diff --git a/db/migrate/20231026194802_make_v2_policies_writable.rb b/db/migrate/20231026194802_make_v2_policies_writable.rb new file mode 100644 index 000000000..6157843ce --- /dev/null +++ b/db/migrate/20231026194802_make_v2_policies_writable.rb @@ -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 diff --git a/db/schema.rb b/db/schema.rb index d5ce52d23..d8c8d882e 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -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" @@ -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 diff --git a/db/triggers/tailorings_insert_v01.sql b/db/triggers/tailorings_insert_v01.sql new file mode 100644 index 000000000..895e7ceb7 --- /dev/null +++ b/db/triggers/tailorings_insert_v01.sql @@ -0,0 +1,2 @@ +CREATE TRIGGER "tailorings_insert" INSTEAD OF INSERT ON "tailorings" +FOR EACH ROW EXECUTE FUNCTION tailorings_insert(); diff --git a/db/triggers/v2_policies_delete_v01.sql b/db/triggers/v2_policies_delete_v01.sql new file mode 100644 index 000000000..90f543b8d --- /dev/null +++ b/db/triggers/v2_policies_delete_v01.sql @@ -0,0 +1,2 @@ +CREATE TRIGGER "v2_policies_delete" INSTEAD OF DELETE ON "v2_policies" +FOR EACH ROW EXECUTE FUNCTION v2_policies_delete(); diff --git a/db/triggers/v2_policies_insert_v01.sql b/db/triggers/v2_policies_insert_v01.sql new file mode 100644 index 000000000..b6aaf1454 --- /dev/null +++ b/db/triggers/v2_policies_insert_v01.sql @@ -0,0 +1,2 @@ +CREATE TRIGGER "v2_policies_insert" INSTEAD OF INSERT ON "v2_policies" +FOR EACH ROW EXECUTE FUNCTION v2_policies_insert(); diff --git a/db/triggers/v2_policies_update_v01.sql b/db/triggers/v2_policies_update_v01.sql new file mode 100644 index 000000000..89ac4898a --- /dev/null +++ b/db/triggers/v2_policies_update_v01.sql @@ -0,0 +1,2 @@ +CREATE TRIGGER "v2_policies_update" INSTEAD OF UPDATE ON "v2_policies" +FOR EACH ROW EXECUTE FUNCTION v2_policies_update();