Skip to content
This repository was archived by the owner on Sep 30, 2024. It is now read-only.

Conversation

nathan-downs
Copy link
Contributor

@nathan-downs nathan-downs commented Aug 3, 2023

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:

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.

The aggregatedCodyUsageEventsQuery is timing out for dotcom. These changes are cte optimization steps.
Add indexes to event_logs table to increase query performance.
@cla-bot cla-bot bot added the cla-signed label Aug 3, 2023
@nathan-downs nathan-downs requested a review from dadlerj August 3, 2023 06:36
@nathan-downs
Copy link
Contributor Author

Post indexing:

GroupAggregate  (cost=143236.25..143579.65 rows=270 width=158) (actual time=459.643..576.456 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.003..0.004 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.009..0.010 rows=5 loops=1)
  ->  Sort  (cost=143236.10..143239.97 rows=1547 width=62) (actual time=459.585..463.691 rows=33514 loops=1)
        Sort Key: event_logs.name
        Sort Method: external merge  Disk: 3056kB
        ->  Gather  (cost=1000.16..143154.15 rows=1547 width=62) (actual time=12.305..388.071 rows=33514 loops=1)
              Workers Planned: 2
              Workers Launched: 2
              ->  Parallel Seq Scan on event_logs  (cost=0.17..141999.45 rows=645 width=62) (actual time=7.982..386.843 rows=11171 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: 382182
                    SubPlan 9
                      ->  Function Scan on unnest  (cost=0.00..0.13 rows=13 width=32) (actual time=0.022..0.023 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.010..0.012 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.001 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.003..0.005 rows=9 loops=1)
Planning Time: 0.762 ms
Execution Time: 577.530 ms

@dadlerj
Copy link
Member

dadlerj commented Aug 4, 2023

Thanks! Filtering out the completion:started events before running the query is exactly what I would have started with too.

Two questions/notes:

  1. Just to check, I think an index on name won't be able to handle lower(name) (since the resulting values are technically different). Googling turned up this: https://stackoverflow.com/questions/3980050/how-do-i-create-an-index-in-postgresql-based-on-lowercase-only. I would probably ask in the #chat-databases channel to get input on this (I am not an expert on this at all and may be completely wrong)

  2. How many rows are in your test database? The differences don't look that significant to me... A 5% reduction from 610ms to 577ms? I'm surprised that leaving out the completion events doesn't have a bigger impact (not to mention the index, or even if the index isn't working due to the lower() function).

@nathan-downs
Copy link
Contributor Author

  1. Ah, good point! We're just using the lower() to do a case insensitive match for "cody" or "Cody" so we can replace lower(name) like '%%cody%%' with name like '%%cody%%' and name like '%%Cody%%' separately.
  2. The db sizes were replicas of s2.

@nathan-downs
Copy link
Contributor Author

nathan-downs commented Aug 4, 2023

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

@nathan-downs
Copy link
Contributor Author

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.
@nathan-downs
Copy link
Contributor Author

New testing:
Replicated 40M records with a random +/- 1 month interval jitter, down to the minute of change, but it's fairly rudimentary so there are some larger clusters.

No index:

Group  (cost=1421455.44..1421455.45 rows=1 width=50) (actual time=50910.906..50911.683 rows=0 loops=1)
  Group Key: name
  ->  Sort  (cost=1421455.44..1421455.45 rows=1 width=50) (actual time=50910.905..50911.682 rows=0 loops=1)
        Sort Key: name
        Sort Method: quicksort  Memory: 25kB
        ->  Gather  (cost=1000.00..1421455.43 rows=1 width=50) (actual time=50909.561..50910.337 rows=0 loops=1)
              Workers Planned: 2
              Workers Launched: 2
              ->  Parallel Seq Scan on test_table_large  (cost=0.00..1420455.33 rows=1 width=50) (actual time=50883.266..50883.267 rows=0 loops=3)
                    Filter: (name % 'recipe:rewrite'::text)
                    Rows Removed by Filter: 13333333
Planning Time: 2.423 ms
Execution Time: 50911.828 ms

GIN index:

Group  (cost=1421455.39..1421455.86 rows=2 width=50) (actual time=25157.908..25159.635 rows=2 loops=1)
  Group Key: name
  ->  Gather Merge  (cost=1421455.39..1421455.85 rows=4 width=50) (actual time=25157.907..25159.628 rows=6 loops=1)
        Workers Planned: 2
        Workers Launched: 2
        ->  Sort  (cost=1420455.36..1420455.37 rows=2 width=50) (actual time=25130.682..25130.689 rows=2 loops=3)
              Sort Key: name
              Sort Method: quicksort  Memory: 25kB
              Worker 0:  Sort Method: quicksort  Memory: 25kB
              Worker 1:  Sort Method: quicksort  Memory: 25kB
              ->  Partial HashAggregate  (cost=1420455.33..1420455.35 rows=2 width=50) (actual time=25130.568..25130.575 rows=2 loops=3)
                    Group Key: name
                    Batches: 1  Memory Usage: 24kB
                    Worker 0:  Batches: 1  Memory Usage: 24kB
                    Worker 1:  Batches: 1  Memory Usage: 24kB
                    ->  Parallel Seq Scan on test_table_large  (cost=0.00..1378788.67 rows=16666667 width=50) (actual time=0.477..23526.638 rows=13333333 loops=3)
Planning Time: 0.223 ms
Execution Time: 25160.389 ms

@nathan-downs nathan-downs marked this pull request as ready for review August 10, 2023 01:49
@nathan-downs nathan-downs enabled auto-merge (squash) August 10, 2023 02:01
@nathan-downs nathan-downs requested a review from a team August 10, 2023 02:05
@nathan-downs nathan-downs merged commit 41e5cf3 into main Aug 10, 2023
@nathan-downs nathan-downs deleted the nd/fix-ping-query-performance branch August 10, 2023 02:26
github-actions bot pushed a commit that referenced this pull request Aug 10, 2023
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)
@camdencheek
Copy link
Member

I'm curious -- what were the final numbers on this query?

sanderginn pushed a commit that referenced this pull request Aug 10, 2023
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>
@nathan-downs nathan-downs restored the nd/fix-ping-query-performance branch August 11, 2023 18:07
@nathan-downs
Copy link
Contributor Author

nathan-downs commented Aug 11, 2023

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:

Group  (cost=1000.45..56021.91 rows=1 width=25) (actual time=223.578..224.582 rows=0 loops=1)
  Group Key: name
  ->  Gather Merge  (cost=1000.45..56021.90 rows=1 width=25) (actual time=223.578..224.574 rows=0 loops=1)
        Workers Planned: 2
        Workers Launched: 2
        ->  Parallel Index Only Scan using event_logs_name_timestamp on test_table_large  (cost=0.43..55021.76 rows=1 width=25) (actual time=221.166..221.166 rows=0 loops=3)
              Filter: (name ~~ '%recipe:rewrite%'::text)
              Rows Removed by Filter: 1333333
              Heap Fetches: 0
Planning Time: 8.180 ms
Execution Time: 224.615 ms
GroupAggregate  (cost=294528.19..316060.21 rows=49 width=157) (actual time=7272.248..7905.475 rows=6 loops=1)
  Group Key: test_table_large.name, (date_trunc('month'::text, '2023-08-11 17:00:00-07'::timestamp with time zone)), (timezone('UTC'::text, (date_trunc('week'::text, ('2023-08-11 17:00:00-07'::timestamp with time zone + '1 day'::interval)) - '1 day'::interval))), (date_trunc('day'::text, '2023-08-11 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.019..0.019 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.002..0.004 rows=5 loops=1)
  ->  Gather Merge  (cost=294528.05..300513.03 rows=51388 width=61) (actual time=2221.634..2447.750 rows=1400000 loops=1)
        Workers Planned: 2
        Workers Launched: 2
        ->  Sort  (cost=293528.03..293581.56 rows=21412 width=61) (actual time=2214.206..2270.025 rows=466667 loops=3)
              Sort Key: test_table_large.name
              Sort Method: external merge  Disk: 39544kB
              Worker 0:  Sort Method: external merge  Disk: 34656kB
              Worker 1:  Sort Method: external merge  Disk: 34136kB
              ->  Parallel Seq Scan on test_table_large  (cost=0.00..291987.85 rows=21412 width=61) (actual time=0.089..1893.175 rows=466667 loops=3)
                    Filter: ((name !~~ '%%CTA%%'::text) AND (name !~~ '%%Cta%%'::text) AND (lower(name) ~~ '%%cody%%'::text) AND ("timestamp" >= date_trunc('month'::text, timezone('UTC'::text, "timestamp"))) AND (name <> ALL ('{CodyVSCodeExtension:CodySavedLogin:executed,web:codyChat:tryOnPublicCode,web:codyEditorWidget:viewed,web:codyChat:pageViewed,CodyConfigurationPageViewed,ClickedOnTryCodySearchCTA,TryCodyWebOnboardingDisplayed,AboutGetCodyPopover,TryCodyWeb,CodySurveyToastViewed,SiteAdminCodyPageViewed,CodyUninstalled,SpeakToACodyEngineerCTA}'::text[])))
                    Rows Removed by Filter: 866667
  SubPlan 3
    ->  CTE Scan on code_generation_keys  (cost=0.00..0.18 rows=9 width=32) (actual time=0.020..0.021 rows=9 loops=1)
  SubPlan 4
    ->  CTE Scan on code_generation_keys code_generation_keys_1  (cost=0.00..0.18 rows=9 width=32) (never executed)
  SubPlan 5
    ->  CTE Scan on code_generation_keys code_generation_keys_2  (cost=0.00..0.18 rows=9 width=32) (actual time=0.000..0.001 rows=9 loops=1)
  SubPlan 6
    ->  CTE Scan on explanation_keys  (cost=0.00..0.10 rows=5 width=32) (actual time=0.002..0.003 rows=5 loops=1)
  SubPlan 7
    ->  CTE Scan on explanation_keys explanation_keys_1  (cost=0.00..0.10 rows=5 width=32) (never executed)
  SubPlan 8
    ->  CTE Scan on explanation_keys explanation_keys_2  (cost=0.00..0.10 rows=5 width=32) (actual time=0.000..0.000 rows=5 loops=1)
Planning Time: 0.478 ms
Execution Time: 7911.833 ms

After refactor and functional keys:

GroupAggregate  (cost=1184344.10..3454344.63 rows=49 width=157) (actual time=7050.634..7604.670 rows=6 loops=1)
  Group Key: test_table_large.name, (date_trunc('month'::text, '2023-08-11 17:00:00-07'::timestamp with time zone)), ((date_trunc('week'::text, ('2023-08-11 17:00:00-07'::timestamp with time zone + '1 day'::interval)) - '1 day'::interval)), (date_trunc('day'::text, '2023-08-11 17:00:00-07'::timestamp with time zone))
  ->  Sort  (cost=1184344.10..1187677.43 rows=1333333 width=61) (actual time=2404.047..2543.760 rows=1425000 loops=1)
        Sort Key: test_table_large.name
        Sort Method: external merge  Disk: 109952kB
        ->  Index Scan using idx_is_cody_active_event on test_table_large  (cost=0.43..948439.09 rows=1333333 width=61) (actual time=0.404..2010.557 rows=1425000 loops=1)
              Index Cond: (iscodyactiveevent(name) = true)
              Filter: ("timestamp" >= (date_trunc('month'::text, '2023-08-11 17:00:00-07'::timestamp with time zone) - '1 mon'::interval))
Planning Time: 4.104 ms
Execution Time: 7622.388 ms

Sign up for free to subscribe to this conversation on GitHub. Already have an account? Sign in.
Projects
None yet
Development

Successfully merging this pull request may close these issues.

4 participants