-
Notifications
You must be signed in to change notification settings - Fork 1.3k
internal/event_logs: optimize ping cte #55538
Conversation
The aggregatedCodyUsageEventsQuery is timing out for dotcom. These changes are cte optimization steps.
Add indexes to event_logs table to increase query performance.
Post indexing:
|
This reverts commit 47965ec.
…nto nd/fix-ping-query-performance
Thanks! Filtering out the completion:started events before running the query is exactly what I would have started with too. Two questions/notes:
|
|
Looks like I just need to add a separate index for it to be able to use the lower() function: https://www.postgresql.org/docs/current/indexes-expressional.html |
todo: change this back to a single index on name. |
It's computationally expensive to have an index on both the column and the lower(column) simuiltaneously. We need the index on the column so we're going to take the computational hit in the where clause. There is already timestamp, removing redundant migration.
New testing: No index:
GIN index:
|
The aggregatedCodyUsageEventsQuery is timing out for dotcom. These changes are cte optimization steps. ## Test plan Extract query from most expensive ping-supporting query, [aggregatedCodyUsageEventsQuery](https://sourcegraph.sourcegraph.com/github.com/sourcegraph/sourcegraph/-/blob/internal/database/event_logs.go?L1594), analyze original query: ``` GroupAggregate (cost=143042.53..143382.23 rows=270 width=158) (actual time=492.653..608.924 rows=87 loops=1) Group Key: event_logs.name, (date_trunc('month'::text, '2023-08-01 17:00:00-07'::timestamp with time zone)), ((date_trunc('week'::text, ('2023-08-01 17:00:00-07'::timestamp with time zone + '1 day'::interval)) - '1 day'::interval)), (date_trunc('day'::text, '2023-08-01 17:00:00-07'::timestamp with time zone)) CTE code_generation_keys -> Function Scan on unnest key (cost=0.00..0.09 rows=9 width=32) (actual time=0.005..0.007 rows=9 loops=1) CTE explanation_keys -> Function Scan on unnest key_1 (cost=0.00..0.05 rows=5 width=32) (actual time=0.012..0.013 rows=5 loops=1) -> Sort (cost=143042.38..143046.21 rows=1530 width=62) (actual time=492.526..496.803 rows=33511 loops=1) Sort Key: event_logs.name Sort Method: external merge Disk: 3056kB -> Gather (cost=1000.16..142961.45 rows=1530 width=62) (actual time=12.381..418.370 rows=33511 loops=1) Workers Planned: 2 Workers Launched: 2 -> Parallel Seq Scan on event_logs (cost=0.17..141808.45 rows=638 width=62) (actual time=10.540..417.177 rows=11170 loops=3) Filter: ((name !~~ '%completion:suggested%'::text) AND (name !~~ '%completion:started%'::text) AND (name !~~ '%CTA%'::text) AND (name !~~ '%Cta%'::text) AND (NOT (hashed SubPlan 9)) AND (lower(name) ~~ '%cody%'::text) AND ("timestamp" >= (date_trunc('month'::text, '2023-08-01 17:00:00-07'::timestamp with time zone) - '1 mon'::interval))) Rows Removed by Filter: 382174 SubPlan 9 -> Function Scan on unnest (cost=0.00..0.13 rows=13 width=32) (actual time=0.007..0.008 rows=13 loops=3) SubPlan 8 -> CTE Scan on explanation_keys explanation_keys_3 (cost=0.00..0.10 rows=5 width=32) (actual time=0.000..0.001 rows=5 loops=1) SubPlan 7 -> CTE Scan on explanation_keys explanation_keys_2 (cost=0.00..0.10 rows=5 width=32) (actual time=0.014..0.016 rows=5 loops=1) SubPlan 6 -> CTE Scan on explanation_keys explanation_keys_1 (cost=0.00..0.10 rows=5 width=32) (actual time=0.000..0.001 rows=5 loops=1) SubPlan 5 -> CTE Scan on code_generation_keys code_generation_keys_1 (cost=0.00..0.18 rows=9 width=32) (actual time=0.000..0.002 rows=9 loops=1) SubPlan 4 -> CTE Scan on explanation_keys (cost=0.00..0.10 rows=5 width=32) (actual time=0.000..0.001 rows=5 loops=1) SubPlan 3 -> CTE Scan on code_generation_keys (cost=0.00..0.18 rows=9 width=32) (actual time=0.007..0.010 rows=9 loops=1) Planning Time: 1.556 ms Execution Time: 610.143 ms ``` Add indexes and analyze again in comments. (cherry picked from commit 41e5cf3)
I'm curious -- what were the final numbers on this query? |
The aggregatedCodyUsageEventsQuery is timing out for dotcom. These changes are cte optimization steps. ## Test plan Extract query from most expensive ping-supporting query, [aggregatedCodyUsageEventsQuery](https://sourcegraph.sourcegraph.com/github.com/sourcegraph/sourcegraph/-/blob/internal/database/event_logs.go?L1594), analyze original query: ``` GroupAggregate (cost=143042.53..143382.23 rows=270 width=158) (actual time=492.653..608.924 rows=87 loops=1) Group Key: event_logs.name, (date_trunc('month'::text, '2023-08-01 17:00:00-07'::timestamp with time zone)), ((date_trunc('week'::text, ('2023-08-01 17:00:00-07'::timestamp with time zone + '1 day'::interval)) - '1 day'::interval)), (date_trunc('day'::text, '2023-08-01 17:00:00-07'::timestamp with time zone)) CTE code_generation_keys -> Function Scan on unnest key (cost=0.00..0.09 rows=9 width=32) (actual time=0.005..0.007 rows=9 loops=1) CTE explanation_keys -> Function Scan on unnest key_1 (cost=0.00..0.05 rows=5 width=32) (actual time=0.012..0.013 rows=5 loops=1) -> Sort (cost=143042.38..143046.21 rows=1530 width=62) (actual time=492.526..496.803 rows=33511 loops=1) Sort Key: event_logs.name Sort Method: external merge Disk: 3056kB -> Gather (cost=1000.16..142961.45 rows=1530 width=62) (actual time=12.381..418.370 rows=33511 loops=1) Workers Planned: 2 Workers Launched: 2 -> Parallel Seq Scan on event_logs (cost=0.17..141808.45 rows=638 width=62) (actual time=10.540..417.177 rows=11170 loops=3) Filter: ((name !~~ '%completion:suggested%'::text) AND (name !~~ '%completion:started%'::text) AND (name !~~ '%CTA%'::text) AND (name !~~ '%Cta%'::text) AND (NOT (hashed SubPlan 9)) AND (lower(name) ~~ '%cody%'::text) AND ("timestamp" >= (date_trunc('month'::text, '2023-08-01 17:00:00-07'::timestamp with time zone) - '1 mon'::interval))) Rows Removed by Filter: 382174 SubPlan 9 -> Function Scan on unnest (cost=0.00..0.13 rows=13 width=32) (actual time=0.007..0.008 rows=13 loops=3) SubPlan 8 -> CTE Scan on explanation_keys explanation_keys_3 (cost=0.00..0.10 rows=5 width=32) (actual time=0.000..0.001 rows=5 loops=1) SubPlan 7 -> CTE Scan on explanation_keys explanation_keys_2 (cost=0.00..0.10 rows=5 width=32) (actual time=0.014..0.016 rows=5 loops=1) SubPlan 6 -> CTE Scan on explanation_keys explanation_keys_1 (cost=0.00..0.10 rows=5 width=32) (actual time=0.000..0.001 rows=5 loops=1) SubPlan 5 -> CTE Scan on code_generation_keys code_generation_keys_1 (cost=0.00..0.18 rows=9 width=32) (actual time=0.000..0.002 rows=9 loops=1) SubPlan 4 -> CTE Scan on explanation_keys (cost=0.00..0.10 rows=5 width=32) (actual time=0.000..0.001 rows=5 loops=1) SubPlan 3 -> CTE Scan on code_generation_keys (cost=0.00..0.18 rows=9 width=32) (actual time=0.007..0.010 rows=9 loops=1) Planning Time: 1.556 ms Execution Time: 610.143 ms ``` Add indexes and analyze again in comments. <br> Backport 41e5cf3 from #55538 --------- Co-authored-by: Nathan Downs <85511556+nathan-downs@users.noreply.github.com>
The best I could determine on an equal footing comparison. Marginal actual time improvements on my test box, but looks like good logical improvements. Before refactor and functional keys:
After refactor and functional keys:
|
The aggregatedCodyUsageEventsQuery is timing out for dotcom. These changes are cte optimization steps.
Test plan
Extract query from most expensive ping-supporting query, aggregatedCodyUsageEventsQuery, analyze original query:
Add indexes and analyze again in comments.