diff --git a/.github/workflows/benchmarking.yml b/.github/workflows/benchmarking.yml index bbdcf5ef49..ab0f2a6155 100644 --- a/.github/workflows/benchmarking.yml +++ b/.github/workflows/benchmarking.yml @@ -308,6 +308,7 @@ jobs: "image": [ "'"$image_default"'" ], "include": [{ "pg_version": 16, "region_id": "'"$region_id_default"'", "platform": "neonvm-captest-freetier", "db_size": "3gb" ,"runner": '"$runner_default"', "image": "'"$image_default"'" }, { "pg_version": 16, "region_id": "'"$region_id_default"'", "platform": "neonvm-captest-new", "db_size": "10gb","runner": '"$runner_default"', "image": "'"$image_default"'" }, + { "pg_version": 16, "region_id": "'"$region_id_default"'", "platform": "neonvm-captest-new-many-tables","db_size": "10gb","runner": '"$runner_default"', "image": "'"$image_default"'" }, { "pg_version": 16, "region_id": "'"$region_id_default"'", "platform": "neonvm-captest-new", "db_size": "50gb","runner": '"$runner_default"', "image": "'"$image_default"'" }, { "pg_version": 16, "region_id": "azure-eastus2", "platform": "neonvm-azure-captest-freetier", "db_size": "3gb" ,"runner": '"$runner_azure"', "image": "neondatabase/build-tools:pinned-bookworm" }, { "pg_version": 16, "region_id": "azure-eastus2", "platform": "neonvm-azure-captest-new", "db_size": "10gb","runner": '"$runner_azure"', "image": "neondatabase/build-tools:pinned-bookworm" }, @@ -410,7 +411,7 @@ jobs: aws-oicd-role-arn: ${{ vars.DEV_AWS_OIDC_ROLE_ARN }} - name: Create Neon Project - if: contains(fromJson('["neonvm-captest-new", "neonvm-captest-freetier", "neonvm-azure-captest-freetier", "neonvm-azure-captest-new"]'), matrix.platform) + if: contains(fromJson('["neonvm-captest-new", "neonvm-captest-new-many-tables", "neonvm-captest-freetier", "neonvm-azure-captest-freetier", "neonvm-azure-captest-new"]'), matrix.platform) id: create-neon-project uses: ./.github/actions/neon-project-create with: @@ -429,7 +430,7 @@ jobs: neonvm-captest-sharding-reuse) CONNSTR=${{ secrets.BENCHMARK_CAPTEST_SHARDING_CONNSTR }} ;; - neonvm-captest-new | neonvm-captest-freetier | neonvm-azure-captest-new | neonvm-azure-captest-freetier) + neonvm-captest-new | neonvm-captest-new-many-tables | neonvm-captest-freetier | neonvm-azure-captest-new | neonvm-azure-captest-freetier) CONNSTR=${{ steps.create-neon-project.outputs.dsn }} ;; rds-aurora) @@ -446,6 +447,26 @@ jobs: echo "connstr=${CONNSTR}" >> $GITHUB_OUTPUT + # we want to compare Neon project OLTP throughput and latency at scale factor 10 GB + # without (neonvm-captest-new) + # and with (neonvm-captest-new-many-tables) many relations in the database + - name: Create many relations before the run + if: contains(fromJson('["neonvm-captest-new-many-tables"]'), matrix.platform) + uses: ./.github/actions/run-python-test-set + with: + build_type: ${{ env.BUILD_TYPE }} + test_selection: performance + run_in_parallel: false + save_perf_report: ${{ env.SAVE_PERF_REPORT }} + extra_params: -m remote_cluster --timeout 21600 -k test_perf_many_relations + pg_version: ${{ env.DEFAULT_PG_VERSION }} + aws-oicd-role-arn: ${{ vars.DEV_AWS_OIDC_ROLE_ARN }} + env: + BENCHMARK_CONNSTR: ${{ steps.set-up-connstr.outputs.connstr }} + VIP_VAP_ACCESS_TOKEN: "${{ secrets.VIP_VAP_ACCESS_TOKEN }}" + PERF_TEST_RESULT_CONNSTR: "${{ secrets.PERF_TEST_RESULT_CONNSTR }}" + TEST_NUM_RELATIONS: 10000 + - name: Benchmark init uses: ./.github/actions/run-python-test-set with: diff --git a/test_runner/performance/many_relations/create_many_relations.sql b/test_runner/performance/many_relations/create_many_relations.sql new file mode 100644 index 0000000000..1b3673c9e1 --- /dev/null +++ b/test_runner/performance/many_relations/create_many_relations.sql @@ -0,0 +1,199 @@ +-- create a schema that simulates Neon control plane operations table +-- however use partitioned operations tables with many (e.g. 500) child partition tables per table +-- in summary we create multiple of these partitioned operations tables (with 500 childs each) - until we reach the requested number of tables + + +-- first we need some other tables that can be referenced by the operations table + +-- Table for branches +CREATE TABLE public.branches ( + id text PRIMARY KEY +); + +-- Table for endpoints +CREATE TABLE public.endpoints ( + id text PRIMARY KEY +); + +-- Table for projects +CREATE TABLE public.projects ( + id text PRIMARY KEY +); + +INSERT INTO public.branches (id) +VALUES ('branch_1'); + +-- Insert one row into endpoints +INSERT INTO public.endpoints (id) +VALUES ('endpoint_1'); + +-- Insert one row into projects +INSERT INTO public.projects (id) +VALUES ('project_1'); + +-- now we create a procedure that can create n operations tables +-- we do that in a procedure to save roundtrip latency when scaling the test to many tables +-- prefix is the base table name, e.g. 'operations_scale_1000' if we create 1000 tables +CREATE OR REPLACE PROCEDURE create_partitioned_tables(prefix text, n INT) +LANGUAGE plpgsql AS $$ +DECLARE + table_name TEXT; -- Variable to hold table names dynamically + i INT; -- Counter for the loop +BEGIN + -- Loop to create n partitioned tables + FOR i IN 1..n LOOP + table_name := format('%s_%s', prefix, i); + + -- Create the partitioned table + EXECUTE format( + 'CREATE TABLE public.%s ( + project_id character varying NOT NULL, + id uuid NOT NULL, + status integer, + action character varying NOT NULL, + error character varying, + created_at timestamp with time zone NOT NULL DEFAULT now(), + updated_at timestamp with time zone NOT NULL DEFAULT now(), + spec jsonb, + retry_at timestamp with time zone, + failures_count integer DEFAULT 0, + metadata jsonb NOT NULL DEFAULT ''{}''::jsonb, + executor_id text NOT NULL, + attempt_duration_ms integer, + metrics jsonb DEFAULT ''{}''::jsonb, + branch_id text, + endpoint_id text, + next_operation_id uuid, + compute_id text, + connection_attempt_at timestamp with time zone, + concurrency_key text, + queue_id text, + CONSTRAINT %s_pkey PRIMARY KEY (id, created_at), + CONSTRAINT %s_branch_id_fk FOREIGN KEY (branch_id) REFERENCES branches(id) ON DELETE CASCADE, + CONSTRAINT %s_endpoint_id_fk FOREIGN KEY (endpoint_id) REFERENCES endpoints(id) ON DELETE CASCADE, + CONSTRAINT %s_next_operation_id_fk FOREIGN KEY (next_operation_id, created_at) REFERENCES %s(id, created_at), + CONSTRAINT %s_project_id_fk FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE + ) PARTITION BY RANGE (created_at)', + table_name, table_name, table_name, table_name, table_name, table_name, table_name + ); + + -- Add indexes for the partitioned table + EXECUTE format('CREATE INDEX index_%s_on_next_operation_id ON public.%s (next_operation_id)', table_name, table_name); + EXECUTE format('CREATE INDEX index_%s_on_project_id ON public.%s (project_id)', table_name, table_name); + EXECUTE format('CREATE INDEX %s_branch_id ON public.%s (branch_id)', table_name, table_name); + EXECUTE format('CREATE INDEX %s_branch_id_created_idx ON public.%s (branch_id, created_at)', table_name, table_name); + EXECUTE format('CREATE INDEX %s_created_at_idx ON public.%s (created_at)', table_name, table_name); + EXECUTE format('CREATE INDEX %s_created_at_project_id_id_cond_idx ON public.%s (created_at, project_id, id)', table_name, table_name); + EXECUTE format('CREATE INDEX %s_endpoint_id ON public.%s (endpoint_id)', table_name, table_name); + EXECUTE format( + 'CREATE INDEX %s_for_redo_worker_idx ON public.%s (executor_id) WHERE status <> 1', + table_name, table_name + ); + EXECUTE format( + 'CREATE INDEX %s_project_id_status_index ON public.%s ((project_id::text), status)', + table_name, table_name + ); + EXECUTE format( + 'CREATE INDEX %s_status_not_finished ON public.%s (status) WHERE status <> 1', + table_name, table_name + ); + EXECUTE format('CREATE INDEX %s_updated_at_desc_idx ON public.%s (updated_at DESC)', table_name, table_name); + EXECUTE format( + 'CREATE INDEX %s_with_failures ON public.%s (failures_count) WHERE failures_count > 0', + table_name, table_name + ); + END LOOP; +END; +$$; + +-- next we create a procedure that can add the child partitions (one per day) to each of the operations tables +CREATE OR REPLACE PROCEDURE create_operations_partitions( + table_name TEXT, + start_date DATE, + end_date DATE +) +LANGUAGE plpgsql AS $$ +DECLARE + partition_date DATE; + partition_name TEXT; + counter INT := 0; -- Counter to track the number of tables created in the current transaction +BEGIN + partition_date := start_date; + + -- Create partitions in batches + WHILE partition_date < end_date LOOP + partition_name := format('%s_%s', table_name, to_char(partition_date,'YYYY_MM_DD')); + + EXECUTE format( + 'CREATE TABLE IF NOT EXISTS public.%s PARTITION OF public.%s + FOR VALUES FROM (''%s'') TO (''%s'')', + partition_name, + table_name, + partition_date, + partition_date + INTERVAL '1 day' + ); + + counter := counter + 1; + + -- Commit and reset counter after every 100 partitions + IF counter >= 100 THEN + COMMIT; + counter := 0; -- Reset the counter + END IF; + + -- Advance to the next day + partition_date := partition_date + INTERVAL '1 day'; + END LOOP; + + -- Final commit for remaining partitions + IF counter > 0 THEN + COMMIT; + END IF; + + -- Insert synthetic rows into each partition + EXECUTE format( + 'INSERT INTO %I ( + project_id, + branch_id, + endpoint_id, + id, + status, + action, + created_at, + updated_at, + spec, + metadata, + executor_id, + failures_count + ) + SELECT + ''project_1'', -- project_id + ''branch_1'', -- branch_id + ''endpoint_1'', -- endpoint_id + ''e8bba687-0df9-4291-bfcd-7d5f6aa7c158'', -- unique id + 1, -- status + ''SYNTHETIC_ACTION'', -- action + gs::timestamp + interval ''0 ms'', -- created_at + gs::timestamp + interval ''1 minute'', -- updated_at + ''{"key": "value"}'', -- spec (JSONB) + ''{"metadata_key": "metadata_value"}'', -- metadata (JSONB) + ''executor_1'', -- executor_id + 0 -- failures_count + FROM generate_series(%L, %L::DATE - INTERVAL ''1 day'', INTERVAL ''1 day'') AS gs', + table_name, start_date, end_date + ); + + -- Commit the inserted rows + COMMIT; +END; +$$; + +-- we can now create partitioned tables using something like +-- CALL create_partitioned_tables('operations_scale_1000' ,10); + +-- and we can create the child partitions for a table using something like +-- CALL create_operations_partitions( +-- 'operations_scale_1000_1', +-- '2000-01-01', -- Start date +-- ('2000-01-01'::DATE + INTERVAL '1 day' * 500)::DATE -- End date (start date + number of days) +-- ); diff --git a/test_runner/performance/test_perf_many_relations.py b/test_runner/performance/test_perf_many_relations.py new file mode 100644 index 0000000000..0ee0efe8b9 --- /dev/null +++ b/test_runner/performance/test_perf_many_relations.py @@ -0,0 +1,66 @@ +import os +from pathlib import Path + +import pytest +from fixtures.compare_fixtures import RemoteCompare +from fixtures.log_helper import log + + +def get_num_relations(default: int = 1000) -> list[int]: + # We parametrize each run with scale specifying the number of wanted child partitions. + # Databases are pre-created and passed through BENCHMARK_CONNSTR env variable. + scales = os.getenv("TEST_NUM_RELATIONS", default=str(default)) + rv = [] + for s in scales.split(","): + scale = int(s) + rv.append(scale) + return rv + + +@pytest.mark.parametrize("num_relations", get_num_relations()) +@pytest.mark.remote_cluster +def test_perf_many_relations(remote_compare: RemoteCompare, num_relations: int): + """ + Test creating many relations in a single database. + We use partitioned tables with child tables, indexes and constraints to have a realistic schema. + Also we include some common data types like text, uuid, timestamp, JSONB, etc. + + see many_relations/create_many_relations.sql + """ + env = remote_compare + + # prepare some base tables and the plpgsql procedures that we use to create the tables + sql_file = Path(__file__).parent / "many_relations" / "create_many_relations.sql" + env.pg_bin.run_capture(["psql", env.pg.connstr(), "-f", str(sql_file)]) + + num_parent_tables = num_relations // 500 + 1 + log.info(f"Creating {num_relations} relations in {num_parent_tables} parent tables") + + log.info(f"Creating {num_parent_tables} parent tables") + sql = f"CALL create_partitioned_tables('operations_scale_{num_relations}', {num_parent_tables})" + log.info(sql) + env.pg_bin.run_capture(["psql", env.pg.connstr(), "-c", sql]) + + current_table = 0 + num_relations_remaining = num_relations + + # now run and measure the actual relation creation + while num_relations_remaining > 0: + current_table += 1 + parent_table_name = f"operations_scale_{num_relations}_{current_table}" + if num_relations_remaining > 500: + num_relations_to_create = 500 + else: + num_relations_to_create = num_relations_remaining + num_relations_remaining -= num_relations_to_create + log.info( + f"Creating {num_relations_to_create} child tables in partitioned parent table '{parent_table_name}'" + ) + sql = f"CALL create_operations_partitions( '{parent_table_name}', '2000-01-01', ('2000-01-01'::DATE + INTERVAL '1 day' * {num_relations_to_create})::DATE)" + log.info(sql) + with env.zenbenchmark.record_duration( + f"CREATE_TABLE/{current_table}/{num_relations_to_create}" + ): + env.pg_bin.run_capture( + ["psql", env.pg.connstr(options="-cstatement_timeout=1000s "), "-c", sql] + )