Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[COST-5427] Utilize an initial cte to optimize the distribution sql. #5332

Merged
merged 7 commits into from
Oct 9, 2024

Conversation

myersCody
Copy link
Contributor

@myersCody myersCody commented Oct 1, 2024

Jira Ticket

COST-5427

Description

The introduction of the cte_narrow_dataset allows us to run all subsequent calculations on a reduced dataset instead of performing multiple scans of the daily summary table (which can be large for customers with many clusters). The new "narrow" cte allows us to remove redundancy across the other CTEs. The filtered and joined data is prepared once and reused instead of performing the same joins and filters multiple times on the daily summary table.

Analyze Results:

SET plan_cache_mode = force_custom_plan;

Old Query

---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Subquery Scan on ctl  (cost=181.69..181.82 rows=1 width=378) (actual time=7.293..9.510 rows=210 loops=1)
   ->  GroupAggregate  (cost=181.69..181.81 rows=1 width=382) (actual time=7.292..9.473 rows=210 loops=1)
         Group Key: lids.usage_start, lids.node, lids.namespace, lids.cluster_id, lids.cost_category_id, lids.data_source
         Filter: (CASE WHEN ((lids.cost_category_id IS NULL) OR (max(cat.name) <> 'Platform'::text)) THEN CASE WHEN (max((sum(lids_1.pod_effective_usage_cpu_core_hours))) <= '0'::numeric) THEN '0'::numeric ELSE ((sum(lids.pod_effective_usage_cpu_core_hours) / max((sum(lids_1.pod_effective_usage_cpu_core_hours)))) * max(pc.platform_cost)) END WHEN (max(cat.name) = 'Platform'::text) THEN ('0'::numeric - sum(((((COALESCE(lids.infrastructure_raw_cost, '0'::numeric) + COALESCE(lids.infrastructure_markup_cost, '0'::numeric)) + COALESCE(lids.cost_model_cpu_cost, '0'::numeric)) + COALESCE(lids.cost_model_memory_cost, '0'::numeric)) + COALESCE(lids.cost_model_volume_cost, '0'::numeric)))) ELSE NULL::numeric END <> '0'::numeric)
         Rows Removed by Filter: 60
         ->  Sort  (cost=181.69..181.70 rows=1 width=338) (actual time=7.248..7.342 rows=1170 loops=1)
               Sort Key: lids.usage_start, lids.node, lids.namespace, lids.cluster_id, lids.cost_category_id, lids.data_source
               Sort Method: quicksort  Memory: 359kB
               ->  Nested Loop Left Join  (cost=172.16..181.68 rows=1 width=338) (actual time=2.561..4.847 rows=1170 loops=1)
                     ->  Nested Loop  (cost=172.01..181.47 rows=1 width=306) (actual time=2.550..4.102 rows=1170 loops=1)
                           Join Filter: ((pc.usage_start = lids.usage_start) AND ((pc.cluster_id)::text = (lids.cluster_id)::text))
                           ->  Hash Join  (cost=171.74..177.75 rows=1 width=156) (actual time=2.418..2.481 rows=30 loops=1)
                                 Hash Cond: ((lids_1.usage_start = pc.usage_start) AND ((lids_1.cluster_id)::text = (pc.cluster_id)::text))
                                 ->  HashAggregate  (cost=127.54..130.04 rows=200 width=126) (actual time=1.152..1.186 rows=30 loops=1)
                                       Group Key: lids_1.usage_start, lids_1.cluster_id, lids_1.source_uuid
                                       Batches: 1  Memory Usage: 48kB
                                       ->  Hash Left Join  (cost=21.25..116.86 rows=1068 width=67) (actual time=0.046..0.918 rows=840 loops=1)
                                             Hash Cond: (lids_1.cost_category_id = cat_1.id)
                                             Filter: ((lids_1.cost_category_id IS NULL) OR (cat_1.name <> 'Platform'::text))
                                             Rows Removed by Filter: 210
                                             ->  Seq Scan on reporting_ocpusagelineitem_daily_summary_2024_09 lids_1  (cost=0.00..92.78 rows=1070 width=71) (actual time=0.015..0.708 rows=1050 loops=1)
                                                   Filter: ((usage_start >= '2024-09-01'::date) AND (usage_start <= '2024-09-30'::date) AND ((namespace)::text <> 'Worker unallocated'::text) AND ((namespace)::text <> 'Platform unallocated'::text) AND ((namespace)::text <> 'Storage unattributed'::text) AND ((namespace)::text <> 'Network unattributed'::text) AND (report_period_id = 34))
                                                   Rows Removed by Filter: 360
                                             ->  Hash  (cost=15.00..15.00 rows=500 width=36) (actual time=0.015..0.015 rows=1 loops=1)
                                                   Buckets: 1024  Batches: 1  Memory Usage: 9kB
                                                   ->  Seq Scan on reporting_ocp_cost_category cat_1  (cost=0.00..15.00 rows=500 width=36) (actual time=0.002..0.003 rows=1 loops=1)
                                 ->  Hash  (cost=44.15..44.15 rows=3 width=78) (actual time=1.254..1.257 rows=30 loops=1)
                                       Buckets: 1024  Batches: 1  Memory Usage: 11kB
                                       ->  Subquery Scan on pc  (cost=44.02..44.15 rows=3 width=78) (actual time=1.033..1.241 rows=30 loops=1)
                                             ->  GroupAggregate  (cost=44.02..44.12 rows=3 width=94) (actual time=1.033..1.236 rows=30 loops=1)
                                                   Group Key: lids_2.usage_start, lids_2.cluster_id, lids_2.source_uuid
                                                   ->  Sort  (cost=44.02..44.02 rows=3 width=129) (actual time=1.009..1.031 rows=330 loops=1)
                                                         Sort Key: lids_2.usage_start, lids_2.cluster_id, lids_2.source_uuid
                                                         Sort Method: quicksort  Memory: 71kB
                                                         ->  Nested Loop  (cost=0.43..43.99 rows=3 width=129) (actual time=0.191..0.809 rows=330 loops=1)
                                                               ->  Index Scan using reporting_ocp_cost_category_name_idx on reporting_ocp_cost_category cat_2  (cost=0.15..8.17 rows=1 width=4) (actual time=0.023..0.024 rows=1 loops=1)
                                                                     Index Cond: (name = 'Platform'::text)
                                                               ->  Index Scan using reporting_ocpusagelineitem_daily_summary__cost_category_id_idx1 on reporting_ocpusagelineitem_daily_summary_2024_09 lids_2  (cost=0.28..32.53 rows=330 width=133) (actual time=0.164..0.738 rows=330 loops=1)
                                                                     Index Cond: (cost_category_id = cat_2.id)
                                                                     Filter: ((usage_start >= '2024-09-01'::date) AND (usage_start <= '2024-09-30'::date) AND (report_period_id = 34))
                           ->  Index Scan using reporting_ocpusagelineitem_daily_summary_2024__usage_start_idx1 on reporting_ocpusagelineitem_daily_summary_2024_09 lids  (cost=0.28..3.14 rows=39 width=242) (actual time=0.011..0.044 rows=39 loops=30)
                                 Index Cond: ((usage_start = lids_1.usage_start) AND (usage_start >= '2024-09-01'::date) AND (usage_start <= '2024-09-30'::date))
                                 Filter: ((namespace IS NOT NULL) AND ((namespace)::text <> 'Worker unallocated'::text) AND ((namespace)::text <> 'Network unattributed'::text) AND ((namespace)::text <> 'Storage unattributed'::text) AND (report_period_id = 34) AND ((lids_1.cluster_id)::text = (cluster_id)::text))
                                 Rows Removed by Filter: 8
                     ->  Index Scan using reporting_ocp_cost_category_pkey on reporting_ocp_cost_category cat  (cost=0.15..0.21 rows=1 width=36) (actual time=0.000..0.000 rows=0 loops=1170)
                           Index Cond: (id = lids.cost_category_id)
 Planning Time: 5.571 ms
 Execution Time: 9.918 ms

New Query:

-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
 Subquery Scan on ctl  (cost=216.50..216.62 rows=1 width=1600) (actual time=4.368..5.370 rows=210 loops=1)
   CTE cte_narrow_dataset
     ->  Hash Left Join  (cost=21.25..113.59 rows=1170 width=295) (actual time=0.076..1.620 rows=1170 loops=1)
           Hash Cond: (lids.cost_category_id = cat.id)
           ->  Seq Scan on reporting_ocpusagelineitem_daily_summary_2024_09 lids  (cost=0.00..89.25 rows=1170 width=263) (actual time=0.056..1.473 rows=1170 loops=1)
                 Filter: ((usage_start >= '2024-09-01'::date) AND (usage_start <= '2024-09-30'::date) AND ((namespace)::text <> 'Worker unallocated'::text) AND ((namespace)::text <> 'Storage unattributed'::text) AND ((namespace)::text <> 'Network unattributed'::text) AND (report_period_id = 34))
                 Rows Removed by Filter: 240
           ->  Hash  (cost=15.00..15.00 rows=500 width=36) (actual time=0.013..0.013 rows=1 loops=1)
                 Buckets: 1024  Batches: 1  Memory Usage: 9kB
                 ->  Seq Scan on reporting_ocp_cost_category cat  (cost=0.00..15.00 rows=500 width=36) (actual time=0.011..0.011 rows=1 loops=1)
   ->  GroupAggregate  (cost=102.90..103.02 rows=1 width=1604) (actual time=4.367..5.352 rows=210 loops=1)
         Group Key: filtered.usage_start, filtered.node, filtered.namespace, filtered.cluster_id, filtered.cost_category_id, filtered.data_source
         Filter: (CASE WHEN ((filtered.cost_category_id IS NULL) OR (max(filtered.category_name) <> 'Platform'::text)) THEN CASE WHEN (max((sum(filtered_1.pod_effective_usage_cpu_core_hours))) <= '0'::numeric) THEN '0'::numeric ELSE ((sum(filtered.pod_effective_usage_cpu_core_hours) / max((sum(filtered_1.pod_effective_usage_cpu_core_hours)))) * max(pc.platform_cost)) END WHEN (max(filtered.category_name) = 'Platform'::text) THEN ('0'::numeric - sum(((((COALESCE(filtered.infrastructure_raw_cost, '0'::numeric) + COALESCE(filtered.infrastructure_markup_cost, '0'::numeric)) + COALESCE(filtered.cost_model_cpu_cost, '0'::numeric)) + COALESCE(filtered.cost_model_memory_cost, '0'::numeric)) + COALESCE(filtered.cost_model_volume_cost, '0'::numeric)))) ELSE NULL::numeric END <> '0'::numeric)
         Rows Removed by Filter: 60
         ->  Sort  (cost=102.90..102.91 rows=1 width=2752) (actual time=4.353..4.391 rows=1170 loops=1)
               Sort Key: filtered.usage_start, filtered.node, filtered.namespace, filtered.cluster_id, filtered.cost_category_id, filtered.data_source
               Sort Method: quicksort  Memory: 359kB
               ->  Hash Join  (cost=70.75..102.89 rows=1 width=2752) (actual time=2.905..3.351 rows=1170 loops=1)
                     Hash Cond: ((filtered.usage_start = pc.usage_start) AND ((filtered.cluster_id)::text = (pc.cluster_id)::text))
                     ->  CTE Scan on cte_narrow_dataset filtered  (cost=0.00..23.40 rows=1164 width=2688) (actual time=0.079..0.201 rows=1170 loops=1)
                           Filter: (namespace IS NOT NULL)
                     ->  Hash  (cost=70.74..70.74 rows=1 width=308) (actual time=2.807..2.808 rows=30 loops=1)
                           Buckets: 1024  Batches: 1  Memory Usage: 13kB
                           ->  Hash Join  (cost=64.73..70.74 rows=1 width=308) (actual time=2.788..2.799 rows=30 loops=1)
                                 Hash Cond: ((filtered_1.usage_start = pc.usage_start) AND ((filtered_1.cluster_id)::text = (pc.cluster_id)::text))
                                 ->  HashAggregate  (cost=37.96..40.46 rows=200 width=202) (actual time=0.278..0.284 rows=30 loops=1)
                                       Group Key: filtered_1.usage_start, filtered_1.cluster_id, filtered_1.source_uuid
                                       Batches: 1  Memory Usage: 48kB
                                       ->  CTE Scan on cte_narrow_dataset filtered_1  (cost=0.00..26.32 rows=1164 width=164) (actual time=0.001..0.155 rows=840 loops=1)
                                             Filter: ((cost_category_id IS NULL) OR (category_name <> 'Platform'::text))
                                             Rows Removed by Filter: 330
                                 ->  Hash  (cost=26.67..26.67 rows=6 width=154) (actual time=2.500..2.500 rows=30 loops=1)
                                       Buckets: 1024  Batches: 1  Memory Usage: 11kB
                                       ->  Subquery Scan on pc  (cost=26.40..26.67 rows=6 width=154) (actual time=2.373..2.491 rows=30 loops=1)
                                             ->  GroupAggregate  (cost=26.40..26.61 rows=6 width=170) (actual time=2.373..2.488 rows=30 loops=1)
                                                   Group Key: filtered_2.usage_start, filtered_2.cluster_id, filtered_2.source_uuid
                                                   ->  Sort  (cost=26.40..26.42 rows=6 width=268) (actual time=2.342..2.353 rows=330 loops=1)
                                                         Sort Key: filtered_2.usage_start, filtered_2.cluster_id, filtered_2.source_uuid
                                                         Sort Method: quicksort  Memory: 71kB
                                                         ->  CTE Scan on cte_narrow_dataset filtered_2  (cost=0.00..26.32 rows=6 width=268) (actual time=0.001..2.212 rows=330 loops=1)
                                                               Filter: (category_name = 'Platform'::text)
                                                               Rows Removed by Filter: 840
 Planning Time: 3.066 ms
 Execution Time: 5.587 ms

Testing

  • Smoke tests should be good enough to test these.

Release Notes

  • proposed release note
* [COST-5427](https://issues.redhat.com/browse/COST-5427) Optimize the distribution sql by adding a filtered cte

@myersCody myersCody added the ocp-smoke-tests pr_check will build the image and run ocp + ocp on [clouds] smoke tests label Oct 1, 2024
@myersCody
Copy link
Contributor Author

/retest

Copy link

codecov bot commented Oct 2, 2024

Codecov Report

All modified and coverable lines are covered by tests ✅

Project coverage is 94.0%. Comparing base (490f19b) to head (79d3820).
Report is 1 commits behind head on main.

Additional details and impacted files
@@          Coverage Diff          @@
##            main   #5332   +/-   ##
=====================================
  Coverage   94.0%   94.0%           
=====================================
  Files        375     375           
  Lines      31616   31616           
  Branches    4658    4658           
=====================================
  Hits       29730   29730           
  Misses      1205    1205           
  Partials     681     681           

@myersCody
Copy link
Contributor Author

@lcouzens
Copy link
Contributor

lcouzens commented Oct 4, 2024

I tried loading some large customer data for this but I don't think I can scale large enough to really see the impact. That said based on the explains its certainly not worse! I say we roll with it and take the improvement!

@lcouzens lcouzens marked this pull request as ready for review October 9, 2024 09:51
@lcouzens lcouzens requested review from a team as code owners October 9, 2024 09:51
@lcouzens lcouzens enabled auto-merge (squash) October 9, 2024 09:56
@lcouzens lcouzens merged commit b760cd3 into main Oct 9, 2024
13 of 14 checks passed
@lcouzens lcouzens deleted the COST-5427-query-optimizations branch October 9, 2024 11:37
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
ocp-smoke-tests pr_check will build the image and run ocp + ocp on [clouds] smoke tests smokes-required
Projects
None yet
Development

Successfully merging this pull request may close these issues.

3 participants