Skip to content

Add new column target_id to audit_events table

Tan Le requested to merge 220322-add-target-id-column-to-audit-events into master

What does this MR do?

This MR adds a new column target_id to audit_events table. We currently write this piece information in a serializes hash and store in details column. This schema makes it hard to query and we are slowly extracting fields in details hash out into separate columns.

There is currently no application write to this new column. We will roll out application write in the following release to avoid downtime since this is a post-migration.

Databases

== 20200819113644 AddTargetIdToAuditEvents: reverting =========================
-- remove_column("audit_events", :target_id)
   -> 0.0017s
-- execute("CREATE OR REPLACE FUNCTION table_sync_function_2be879775d()\nRETURNS TRIGGER AS\n$$\nBEGIN\nIF (TG_OP = 'DELETE') THEN\n  DELETE FROM audit_events_part_5fc467ac26 where id = OLD.id;\nELSIF (TG_OP = 'UPDATE') THEN\n  UPDATE audit_events_part_5fc467ac26\n  SET author_id = NEW.author_id,\n    type = NEW.type,\n    entity_id = NEW.entity_id,\n    entity_type = NEW.entity_type,\n    details = NEW.details,\n    ip_address = NEW.ip_address,\n    author_name = NEW.author_name,\n    entity_path = NEW.entity_path,\n    target_details = NEW.target_details,\n    target_type = NEW.target_type,\n    created_at = NEW.created_at\n  WHERE audit_events_part_5fc467ac26.id = NEW.id;\nELSIF (TG_OP = 'INSERT') THEN\n  INSERT INTO audit_events_part_5fc467ac26 (id,\n    author_id,\n    type,\n    entity_id,\n    entity_type,\n    details,\n    ip_address,\n    author_name,\n    entity_path,\n    target_details,\n    target_type,\n    created_at)\n  VALUES (NEW.id,\n    NEW.author_id,\n    NEW.type,\n    NEW.entity_id,\n    NEW.entity_type,\n    NEW.details,\n    NEW.ip_address,\n    NEW.author_name,\n    NEW.entity_path,\n    NEW.target_details,\n    NEW.target_type,\n    NEW.created_at);\nEND IF;\nRETURN NULL;\n\nEND\n$$ LANGUAGE PLPGSQL\n")
   -> 0.0066s
-- remove_column("audit_events_part_5fc467ac26", :target_id)
   -> 0.0036s
== 20200819113644 AddTargetIdToAuditEvents: reverted (0.0194s) ================

== 20200819113644 AddTargetIdToAuditEvents: migrating =========================
-- add_column("audit_events", :target_id, :bigint)
   -> 0.0011s
-- add_column("audit_events_part_5fc467ac26", :target_id, :bigint)
   -> 0.0031s
-- execute("CREATE OR REPLACE FUNCTION table_sync_function_2be879775d()\nRETURNS TRIGGER AS\n$$\nBEGIN\nIF (TG_OP = 'DELETE') THEN\n  DELETE FROM audit_events_part_5fc467ac26 where id = OLD.id;\nELSIF (TG_OP = 'UPDATE') THEN\n  UPDATE audit_events_part_5fc467ac26\n  SET author_id = NEW.author_id,\n    type = NEW.type,\n    entity_id = NEW.entity_id,\n    entity_type = NEW.entity_type,\n    details = NEW.details,\n    ip_address = NEW.ip_address,\n    author_name = NEW.author_name,\n    entity_path = NEW.entity_path,\n    target_details = NEW.target_details,\n    target_type = NEW.target_type,\n    target_id = NEW.target_id,\n    created_at = NEW.created_at\n  WHERE audit_events_part_5fc467ac26.id = NEW.id;\nELSIF (TG_OP = 'INSERT') THEN\n  INSERT INTO audit_events_part_5fc467ac26 (id,\n    author_id,\n    type,\n    entity_id,\n    entity_type,\n    details,\n    ip_address,\n    author_name,\n    entity_path,\n    target_details,\n    target_type,\n    target_id,\n    created_at)\n  VALUES (NEW.id,\n    NEW.author_id,\n    NEW.type,\n    NEW.entity_id,\n    NEW.entity_type,\n    NEW.details,\n    NEW.ip_address,\n    NEW.author_name,\n    NEW.entity_path,\n    NEW.target_details,\n    NEW.target_type,\n    NEW.target_id,\n    NEW.created_at);\nEND IF;\nRETURN NULL;\n\nEND\n$$ LANGUAGE PLPGSQL\n")
   -> 0.0019s
== 20200819113644 AddTargetIdToAuditEvents: migrated (0.0093s) ================

Does this MR meet the acceptance criteria?

Conformity

Availability and Testing

Security

If this MR contains changes to processing or storing of credentials or tokens, authorization and authentication methods and other items described in the security review guidelines:

  • [-] Label as security and @ mention @gitlab-com/gl-security/appsec
  • [-] The MR includes necessary changes to maintain consistency between UI, API, email, or other methods
  • [-] Security reports checked/validated by a reviewer from the AppSec team

Mentions #220322 (closed)

Edited by Tan Le

Merge request reports