Skip to content

Add migration to swap partitioned web_hook_logs

What does this MR do?

Related issue: #323677 (closed)

This is the fourth step for partitioning the web_hook_logs table (&5558 (closed)), in which we swap the partitioned and non-partitioned tables.

We still keep the non-partitioned table around (web_hook_logs_archived); In the next milestone we'll finish the process with dropping the non-partitioned table and the related sync trigger and function.

Migrations

db:migrate
== 20210424115725 SwapPartitionedWebHookLogs: migrating =======================
-- execute("DROP TRIGGER IF EXISTS table_sync_trigger_b99eb6998c ON web_hook_logs")
   -> 0.0012s
-- execute("DROP FUNCTION IF EXISTS table_sync_function_29bc99d6db()")
   -> 0.0008s
-- replace_table("ALTER TABLE "web_hook_logs"
ALTER COLUMN "id" DROP DEFAULT;
ALTER TABLE "web_hook_logs_part_0c5294f417"
ALTER COLUMN "id" SET DEFAULT nextval('"web_hook_logs_id_seq"'::regclass);
ALTER SEQUENCE "web_hook_logs_id_seq"
OWNED BY "web_hook_logs_part_0c5294f417"."id";
ALTER TABLE "web_hook_logs"
RENAME TO "web_hook_logs_archived";
ALTER TABLE "web_hook_logs_archived"
RENAME CONSTRAINT "web_hook_logs_pkey" TO "web_hook_logs_archived_pkey";
ALTER TABLE "web_hook_logs_part_0c5294f417"
RENAME TO "web_hook_logs";
ALTER TABLE "web_hook_logs"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_pkey" TO "web_hook_logs_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_000000"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_000000_pkey" TO "web_hook_logs_000000_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_000000"
RENAME TO "web_hook_logs_000000";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202104"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_202104_pkey" TO "web_hook_logs_202104_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202104"
RENAME TO "web_hook_logs_202104";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202105"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_202105_pkey" TO "web_hook_logs_202105_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202105"
RENAME TO "web_hook_logs_202105";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202106"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_202106_pkey" TO "web_hook_logs_202106_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202106"
RENAME TO "web_hook_logs_202106";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202107"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_202107_pkey" TO "web_hook_logs_202107_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202107"
RENAME TO "web_hook_logs_202107";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202108"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_202108_pkey" TO "web_hook_logs_202108_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202108"
RENAME TO "web_hook_logs_202108";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202109"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_202109_pkey" TO "web_hook_logs_202109_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202109"
RENAME TO "web_hook_logs_202109";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202110"
RENAME CONSTRAINT "web_hook_logs_part_0c5294f417_202110_pkey" TO "web_hook_logs_202110_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_part_0c5294f417_202110"
RENAME TO "web_hook_logs_202110"")
-- execute("CREATE  FUNCTION table_sync_function_29bc99d6db()\nRETURNS TRIGGER AS\n$$\nBEGIN\nIF (TG_OP = 'DELETE') THEN\n  DELETE FROM web_hook_logs_archived where id = OLD.id;\nELSIF (TG_OP = 'UPDATE') THEN\n  UPDATE web_hook_logs_archived\n  SET web_hook_id = NEW.web_hook_id,\n    trigger = NEW.trigger,\n    url = NEW.url,\n    request_headers = NEW.request_headers,\n    request_data = NEW.request_data,\n    response_headers = NEW.response_headers,\n    response_body = NEW.response_body,\n    response_status = NEW.response_status,\n    execution_duration = NEW.execution_duration,\n    internal_error_message = NEW.internal_error_message,\n    created_at = NEW.created_at,\n    updated_at = NEW.updated_at\n  WHERE web_hook_logs_archived.id = NEW.id;\nELSIF (TG_OP = 'INSERT') THEN\n  INSERT INTO web_hook_logs_archived (id,\n    web_hook_id,\n    trigger,\n    url,\n    request_headers,\n    request_data,\n    response_headers,\n    response_body,\n    response_status,\n    execution_duration,\n    internal_error_message,\n    created_at,\n    updated_at)\n  VALUES (NEW.id,\n    NEW.web_hook_id,\n    NEW.trigger,\n    NEW.url,\n    NEW.request_headers,\n    NEW.request_data,\n    NEW.response_headers,\n    NEW.response_body,\n    NEW.response_status,\n    NEW.execution_duration,\n    NEW.internal_error_message,\n    NEW.created_at,\n    NEW.updated_at);\nEND IF;\nRETURN NULL;\n\nEND\n$$ LANGUAGE PLPGSQL\n")
   -> 0.0017s
-- execute("COMMENT ON FUNCTION table_sync_function_29bc99d6db IS 'Partitioning migration: table sync for web_hook_logs table'")
   -> 0.0009s
-- current_schema()
   -> 0.0003s
-- execute("CREATE TRIGGER table_sync_trigger_b99eb6998c\nAFTER INSERT OR UPDATE OR DELETE ON web_hook_logs\nFOR EACH ROW\nEXECUTE FUNCTION table_sync_function_29bc99d6db()\n")
   -> 0.0012s
== 20210424115725 SwapPartitionedWebHookLogs: migrated (0.0301s) ==============
Schema after db:migrate
gitlabhq_development=# \d web_hook_logs
                                              Table "public.web_hook_logs"
         Column         |            Type             | Collation | Nullable |                  Default
------------------------+-----------------------------+-----------+----------+-------------------------------------------
 id                     | bigint                      |           | not null | nextval('web_hook_logs_id_seq'::regclass)
 web_hook_id            | integer                     |           | not null |
 trigger                | character varying           |           |          |
 url                    | character varying           |           |          |
 request_headers        | text                        |           |          |
 request_data           | text                        |           |          |
 response_headers       | text                        |           |          |
 response_body          | text                        |           |          |
 response_status        | character varying           |           |          |
 execution_duration     | double precision            |           |          |
 internal_error_message | character varying           |           |          |
 updated_at             | timestamp without time zone |           | not null |
 created_at             | timestamp without time zone |           | not null |
Partition key: RANGE (created_at)
Indexes:
    "web_hook_logs_pkey" PRIMARY KEY, btree (id, created_at)
    "index_web_hook_logs_part_on_created_at_and_web_hook_id" btree (created_at, web_hook_id)
    "index_web_hook_logs_part_on_web_hook_id" btree (web_hook_id)
Foreign-key constraints:
    "fk_rails_bb3355782d" FOREIGN KEY (web_hook_id) REFERENCES web_hooks(id) ON DELETE CASCADE
Triggers:
    table_sync_trigger_b99eb6998c AFTER INSERT OR DELETE OR UPDATE ON web_hook_logs FOR EACH ROW EXECUTE PROCEDURE table_sync_function_29bc99d6db()
Number of partitions: 8 (Use \d+ to list them.)
gitlabhq_development=# \d web_hook_logs_archived
                         Table "public.web_hook_logs_archived"
         Column         |            Type             | Collation | Nullable | Default
------------------------+-----------------------------+-----------+----------+---------
 id                     | integer                     |           | not null |
 web_hook_id            | integer                     |           | not null |
 trigger                | character varying           |           |          |
 url                    | character varying           |           |          |
 request_headers        | text                        |           |          |
 request_data           | text                        |           |          |
 response_headers       | text                        |           |          |
 response_body          | text                        |           |          |
 response_status        | character varying           |           |          |
 execution_duration     | double precision            |           |          |
 internal_error_message | character varying           |           |          |
 created_at             | timestamp without time zone |           | not null |
 updated_at             | timestamp without time zone |           | not null |
Indexes:
    "web_hook_logs_archived_pkey" PRIMARY KEY, btree (id)
    "index_web_hook_logs_on_created_at_and_web_hook_id" btree (created_at, web_hook_id)
    "index_web_hook_logs_on_web_hook_id" btree (web_hook_id)
Foreign-key constraints:
    "fk_rails_666826e111" FOREIGN KEY (web_hook_id) REFERENCES web_hooks(id) ON DELETE CASCADE

All tables are defined as we'd expect them.


db:rollback
== 20210424115725 SwapPartitionedWebHookLogs: reverting =======================
-- execute("DROP TRIGGER IF EXISTS table_sync_trigger_b99eb6998c ON web_hook_logs")
   -> 0.0023s
-- execute("DROP FUNCTION IF EXISTS table_sync_function_29bc99d6db()")
   -> 0.0014s
-- replace_table("ALTER TABLE "web_hook_logs"
ALTER COLUMN "id" DROP DEFAULT;
ALTER TABLE "web_hook_logs_archived"
ALTER COLUMN "id" SET DEFAULT nextval('"web_hook_logs_id_seq"'::regclass);
ALTER SEQUENCE "web_hook_logs_id_seq"
OWNED BY "web_hook_logs_archived"."id";
ALTER TABLE "web_hook_logs"
RENAME TO "web_hook_logs_part_0c5294f417";
ALTER TABLE "web_hook_logs_part_0c5294f417"
RENAME CONSTRAINT "web_hook_logs_pkey" TO "web_hook_logs_part_0c5294f417_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_000000"
RENAME CONSTRAINT "web_hook_logs_000000_pkey" TO "web_hook_logs_part_0c5294f417_000000_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_000000"
RENAME TO "web_hook_logs_part_0c5294f417_000000";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202104"
RENAME CONSTRAINT "web_hook_logs_202104_pkey" TO "web_hook_logs_part_0c5294f417_202104_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202104"
RENAME TO "web_hook_logs_part_0c5294f417_202104";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202105"
RENAME CONSTRAINT "web_hook_logs_202105_pkey" TO "web_hook_logs_part_0c5294f417_202105_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202105"
RENAME TO "web_hook_logs_part_0c5294f417_202105";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202106"
RENAME CONSTRAINT "web_hook_logs_202106_pkey" TO "web_hook_logs_part_0c5294f417_202106_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202106"
RENAME TO "web_hook_logs_part_0c5294f417_202106";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202107"
RENAME CONSTRAINT "web_hook_logs_202107_pkey" TO "web_hook_logs_part_0c5294f417_202107_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202107"
RENAME TO "web_hook_logs_part_0c5294f417_202107";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202108"
RENAME CONSTRAINT "web_hook_logs_202108_pkey" TO "web_hook_logs_part_0c5294f417_202108_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202108"
RENAME TO "web_hook_logs_part_0c5294f417_202108";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202109"
RENAME CONSTRAINT "web_hook_logs_202109_pkey" TO "web_hook_logs_part_0c5294f417_202109_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202109"
RENAME TO "web_hook_logs_part_0c5294f417_202109";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202110"
RENAME CONSTRAINT "web_hook_logs_202110_pkey" TO "web_hook_logs_part_0c5294f417_202110_pkey";
ALTER TABLE "gitlab_partitions_dynamic"."web_hook_logs_202110"
RENAME TO "web_hook_logs_part_0c5294f417_202110";
ALTER TABLE "web_hook_logs_archived"
RENAME TO "web_hook_logs";
ALTER TABLE "web_hook_logs"
RENAME CONSTRAINT "web_hook_logs_archived_pkey" TO "web_hook_logs_pkey"")
-- execute("CREATE  FUNCTION table_sync_function_29bc99d6db()\nRETURNS TRIGGER AS\n$$\nBEGIN\nIF (TG_OP = 'DELETE') THEN\n  DELETE FROM web_hook_logs_part_0c5294f417 where id = OLD.id;\nELSIF (TG_OP = 'UPDATE') THEN\n  UPDATE web_hook_logs_part_0c5294f417\n  SET web_hook_id = NEW.web_hook_id,\n    trigger = NEW.trigger,\n    url = NEW.url,\n    request_headers = NEW.request_headers,\n    request_data = NEW.request_data,\n    response_headers = NEW.response_headers,\n    response_body = NEW.response_body,\n    response_status = NEW.response_status,\n    execution_duration = NEW.execution_duration,\n    internal_error_message = NEW.internal_error_message,\n    updated_at = NEW.updated_at,\n    created_at = NEW.created_at\n  WHERE web_hook_logs_part_0c5294f417.id = NEW.id;\nELSIF (TG_OP = 'INSERT') THEN\n  INSERT INTO web_hook_logs_part_0c5294f417 (id,\n    web_hook_id,\n    trigger,\n    url,\n    request_headers,\n    request_data,\n    response_headers,\n    response_body,\n    response_status,\n    execution_duration,\n    internal_error_message,\n    updated_at,\n    created_at)\n  VALUES (NEW.id,\n    NEW.web_hook_id,\n    NEW.trigger,\n    NEW.url,\n    NEW.request_headers,\n    NEW.request_data,\n    NEW.response_headers,\n    NEW.response_body,\n    NEW.response_status,\n    NEW.execution_duration,\n    NEW.internal_error_message,\n    NEW.updated_at,\n    NEW.created_at);\nEND IF;\nRETURN NULL;\n\nEND\n$$ LANGUAGE PLPGSQL\n")
   -> 0.0030s
-- execute("COMMENT ON FUNCTION table_sync_function_29bc99d6db IS 'Partitioning migration: table sync for web_hook_logs table'")
   -> 0.0014s
-- current_schema()
   -> 0.0008s
-- execute("CREATE TRIGGER table_sync_trigger_b99eb6998c\nAFTER INSERT OR UPDATE OR DELETE ON web_hook_logs\nFOR EACH ROW\nEXECUTE FUNCTION table_sync_function_29bc99d6db()\n")
   -> 0.0018s
== 20210424115725 SwapPartitionedWebHookLogs: reverted (0.0522s) ==============
Schema after db:rollback
gitlabhq_development=# \d web_hook_logs
                                              Table "public.web_hook_logs"
         Column         |            Type             | Collation | Nullable |                  Default
------------------------+-----------------------------+-----------+----------+-------------------------------------------
 id                     | integer                     |           | not null | nextval('web_hook_logs_id_seq'::regclass)
 web_hook_id            | integer                     |           | not null |
 trigger                | character varying           |           |          |
 url                    | character varying           |           |          |
 request_headers        | text                        |           |          |
 request_data           | text                        |           |          |
 response_headers       | text                        |           |          |
 response_body          | text                        |           |          |
 response_status        | character varying           |           |          |
 execution_duration     | double precision            |           |          |
 internal_error_message | character varying           |           |          |
 created_at             | timestamp without time zone |           | not null |
 updated_at             | timestamp without time zone |           | not null |
Indexes:
    "web_hook_logs_pkey" PRIMARY KEY, btree (id)
    "index_web_hook_logs_on_created_at_and_web_hook_id" btree (created_at, web_hook_id)
    "index_web_hook_logs_on_web_hook_id" btree (web_hook_id)
Foreign-key constraints:
    "fk_rails_666826e111" FOREIGN KEY (web_hook_id) REFERENCES web_hooks(id) ON DELETE CASCADE
Triggers:
    table_sync_trigger_b99eb6998c AFTER INSERT OR DELETE OR UPDATE ON web_hook_logs FOR EACH ROW EXECUTE PROCEDURE table_sync_function_29bc99d6db()
gitlabhq_development=# \d web_hook_logs_part_0c5294f417
                     Table "public.web_hook_logs_part_0c5294f417"
         Column         |            Type             | Collation | Nullable | Default
------------------------+-----------------------------+-----------+----------+---------
 id                     | bigint                      |           | not null |
 web_hook_id            | integer                     |           | not null |
 trigger                | character varying           |           |          |
 url                    | character varying           |           |          |
 request_headers        | text                        |           |          |
 request_data           | text                        |           |          |
 response_headers       | text                        |           |          |
 response_body          | text                        |           |          |
 response_status        | character varying           |           |          |
 execution_duration     | double precision            |           |          |
 internal_error_message | character varying           |           |          |
 updated_at             | timestamp without time zone |           | not null |
 created_at             | timestamp without time zone |           | not null |
Partition key: RANGE (created_at)
Indexes:
    "web_hook_logs_part_0c5294f417_pkey" PRIMARY KEY, btree (id, created_at)
    "index_web_hook_logs_part_on_created_at_and_web_hook_id" btree (created_at, web_hook_id)
    "index_web_hook_logs_part_on_web_hook_id" btree (web_hook_id)
Foreign-key constraints:
    "fk_rails_bb3355782d" FOREIGN KEY (web_hook_id) REFERENCES web_hooks(id) ON DELETE CASCADE
Number of partitions: 8 (Use \d+ to list them.)

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

Merge request reports