-
Notifications
You must be signed in to change notification settings - Fork 88
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Use oss_ci_benchmark_metadata materialized view (#6167)
I'm attempting to use a new materialized view called `oss_ci_benchmark_metadata` to make it faster to query benchmark metadata. I have already added the new view manually but its definition is included in this PR for review. The old query works, but it's slower because the original table doesn't keep several important columns, i.e. benchmark name, in order https://github.com/pytorch/test-infra/blob/main/torchci/clickhouse_queries/oss_ci_benchmark_v3/query.sql#L98-L107. According to https://clickhouse.com/docs/en/sql-reference/statements/alter/order-by, it seems that we cannot add existing columns into ORDER BY. ### Testing When loading the benchmark metadata: * Slooooow https://hud.pytorch.org/benchmark/llms?repoName=pytorch%2Fpytorch * Faster https://torchci-git-fork-huydhn-use-osscibenchmarkm-96b1e1-fbopensource.vercel.app/benchmark/llms?repoName=pytorch%2Fpytorch Loading the benchmark data is still relatively slow IMO, but I will try to improve that in a separate PR.
- Loading branch information
Showing
3 changed files
with
143 additions
and
101 deletions.
There are no files selected for viewing
77 changes: 28 additions & 49 deletions
77
torchci/clickhouse_queries/oss_ci_benchmark_branches/query.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
83 changes: 31 additions & 52 deletions
83
torchci/clickhouse_queries/oss_ci_benchmark_names/query.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
84 changes: 84 additions & 0 deletions
84
torchci/clickhouse_queries/oss_ci_benchmark_v3_materialized_views/query.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,84 @@ | ||
-- This table is used to speed-up the performance of oss_ci_benchmark_names and | ||
-- and oss_ci_benchmark_branches queries | ||
CREATE TABLE benchmark.oss_ci_benchmark_metadata ( | ||
`repo` String, | ||
`benchmark_name` String, | ||
`benchmark_dtype` String, | ||
`model_name` String, | ||
`model_backend` String, | ||
`device` String, | ||
`arch` String, | ||
`metric_name` String, | ||
`head_branch` String, | ||
`head_sha` String, | ||
`workflow_id` UInt64, | ||
`timestamp` UInt64, | ||
) ENGINE = MergeTree('/clickhouse/tables/{uuid}/{shard}', '{replica}') | ||
ORDER BY | ||
( | ||
repo, | ||
benchmark_name, | ||
benchmark_dtype, | ||
model_name, | ||
model_backend, | ||
device, | ||
arch, | ||
metric_name, | ||
head_branch, | ||
workflow_id, | ||
timestamp | ||
) SETTINGS index_granularity = 8192; | ||
|
||
CREATE MATERIALIZED VIEW benchmark.oss_ci_benchmark_metadata_mv TO benchmark.oss_ci_benchmark_metadata AS | ||
SELECT | ||
repo AS repo, | ||
tupleElement(benchmark, 'name') AS benchmark_name, | ||
tupleElement(benchmark, 'dtype') AS benchmark_dtype, | ||
tupleElement(model, 'name') AS model_name, | ||
tupleElement(model, 'backend') AS model_backend, | ||
IF( | ||
empty(runners), | ||
tupleElement(benchmark, 'extra_info') [ 'device' ], | ||
tupleElement(runners [ 1 ], 'name') | ||
) AS device, | ||
IF( | ||
empty(runners), | ||
tupleElement(benchmark, 'extra_info') [ 'arch' ], | ||
tupleElement(runners [ 1 ], 'type') | ||
) AS arch, | ||
tupleElement(metric, 'name') AS metric_name, | ||
head_branch AS head_branch, | ||
head_sha AS head_sha, | ||
workflow_id AS workflow_id, | ||
timestamp AS timestamp | ||
FROM | ||
benchmark.oss_ci_benchmark_v3 | ||
WHERE | ||
timestamp >= toUnixTimestamp(toDateTime('2025-01-20 22:45:00')); | ||
|
||
-- Below is the SQL query to backfill the view with all data from 2024 onward | ||
INSERT INTO | ||
benchmark.oss_ci_benchmark_metadata | ||
SELECT | ||
repo AS repo, | ||
tupleElement(benchmark, 'name') AS benchmark_name, | ||
tupleElement(benchmark, 'dtype') AS benchmark_dtype, | ||
tupleElement(model, 'name') AS model_name, | ||
tupleElement(model, 'backend') AS model_backend, | ||
IF( | ||
empty(runners), | ||
tupleElement(benchmark, 'extra_info') [ 'device' ], | ||
tupleElement(runners [ 1 ], 'name') | ||
) AS device, | ||
IF( | ||
empty(runners), | ||
tupleElement(benchmark, 'extra_info') [ 'arch' ], | ||
tupleElement(runners [ 1 ], 'type') | ||
) AS arch, | ||
tupleElement(metric, 'name') AS metric_name, | ||
head_branch AS head_branch, | ||
head_sha AS head_sha, | ||
workflow_id AS workflow_id, | ||
timestamp AS timestamp | ||
FROM | ||
benchmark.oss_ci_benchmark_v3 |