# frozen_string_literal: true class UpdateVulnerabilityReadsTriggerFunctions < Gitlab::Database::Migration[2.0] AGENT_ID_VALUE = "NEW.location->'kubernetes_resource'->>'agent_id'" CASTED_AGENT_ID_VALUE = "CAST(#{AGENT_ID_VALUE} AS bigint)" def up update_insert_or_update_vulnerability_reads_function(with_casted_cluster_agent_id: true) update_update_location_from_vulnerability_occurrences_function(with_casted_cluster_agent_id: true) end def down update_insert_or_update_vulnerability_reads_function(with_casted_cluster_agent_id: false) update_update_location_from_vulnerability_occurrences_function(with_casted_cluster_agent_id: false) end private def update_insert_or_update_vulnerability_reads_function(with_casted_cluster_agent_id: false) insert_fields = with_casted_cluster_agent_id ? 'cluster_agent_id, casted_cluster_agent_id' : 'cluster_agent_id' insert_values = with_casted_cluster_agent_id ? [AGENT_ID_VALUE, CASTED_AGENT_ID_VALUE].join(', ') : AGENT_ID_VALUE execute(<<~SQL) CREATE OR REPLACE FUNCTION insert_or_update_vulnerability_reads() RETURNS TRIGGER LANGUAGE plpgsql AS $$ DECLARE severity smallint; state smallint; report_type smallint; resolved_on_default_branch boolean; BEGIN IF (NEW.vulnerability_id IS NULL AND (TG_OP = 'INSERT' OR TG_OP = 'UPDATE')) THEN RETURN NULL; END IF; IF (TG_OP = 'UPDATE' AND OLD.vulnerability_id IS NOT NULL AND NEW.vulnerability_id IS NOT NULL) THEN RETURN NULL; END IF; SELECT vulnerabilities.severity, vulnerabilities.state, vulnerabilities.report_type, vulnerabilities.resolved_on_default_branch INTO severity, state, report_type, resolved_on_default_branch FROM vulnerabilities WHERE vulnerabilities.id = NEW.vulnerability_id; INSERT INTO vulnerability_reads (vulnerability_id, project_id, scanner_id, report_type, severity, state, resolved_on_default_branch, uuid, location_image, #{insert_fields}) VALUES (NEW.vulnerability_id, NEW.project_id, NEW.scanner_id, report_type, severity, state, resolved_on_default_branch, NEW.uuid::uuid, NEW.location->>'image', #{insert_values}) ON CONFLICT(vulnerability_id) DO NOTHING; RETURN NULL; END $$; SQL end def update_update_location_from_vulnerability_occurrences_function(with_casted_cluster_agent_id: false) execute(<<~SQL) CREATE OR REPLACE FUNCTION update_location_from_vulnerability_occurrences() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN UPDATE vulnerability_reads SET location_image = NEW.location->>'image', #{with_casted_cluster_agent_id ? "casted_cluster_agent_id = #{CASTED_AGENT_ID_VALUE}," : ''} cluster_agent_id = #{AGENT_ID_VALUE} WHERE vulnerability_id = NEW.vulnerability_id; RETURN NULL; END $$; SQL end end