July 6, 2017 at 9:55 am
Hi Guys
Aprreciate your help with this. I am trying to tune the following query: It is part of a stored proc.
SELECT s.SupplierID, c.Carrier as Supplier FROM (SELECT DISTINCT SupplierID FROM CPT_SUBDC_Analysis UNION ALL SELECT DISTINCT SupplierID FROM CPT.dbo.CPT_SUBDC_Analysis) s
LEFT OUTER JOIN Carrier c ON c.CarrierID = s.SupplierID
GROUP BY s.SupplierID, c.Carrier
ORDER BY c.Carrier
This is currently running quite frequently. It takes on average 2 minutus to run.
Most of the cost is with this - SELECT DISTINCT SupplierID FROM CPT_SUBDC_Analysis UNION ALL SELECT DISTINCT SupplierID FROM CPT.dbo.CPT_SUBDC_Analysis
Is there another way to use this in the query?
Many thanks in advance.
July 6, 2017 at 10:02 am
ss-457805 - Thursday, July 6, 2017 9:55 AMHi Guys
Aprreciate your help with this. I am trying to tune the following query: It is part of a stored proc.
SELECT s.SupplierID, c.Carrier as Supplier FROM (SELECT DISTINCT SupplierID FROM CPT_SUBDC_Analysis UNION ALL SELECT DISTINCT SupplierID FROM CPT.dbo.CPT_SUBDC_Analysis) s
LEFT OUTER JOIN Carrier c ON c.CarrierID = s.SupplierID
GROUP BY s.SupplierID, c.Carrier
ORDER BY c.Carrier
This is currently running quite frequently. It takes on average 2 minutus to run.Most of the cost is with this - SELECT DISTINCT SupplierID FROM CPT_SUBDC_Analysis UNION ALL SELECT DISTINCT SupplierID FROM CPT.dbo.CPT_SUBDC_Analysis
Is there another way to use this in the query?
Many thanks in advance.
You could try sorting the two concatenated sets only once:SELECT s.SupplierID, c.Carrier as Supplier
FROM (
SELECT DISTINCT SupplierID
FROM (
SELECT SupplierID
FROM CPT_SUBDC_Analysis
UNION ALL
SELECT SupplierID
FROM CPT.dbo.CPT_SUBDC_Analysis
) d
) s
LEFT OUTER JOIN Carrier c
ON c.CarrierID = s.SupplierID
GROUP BY s.SupplierID, c.Carrier
ORDER BY c.Carrier
Also, see UNION without the ALL operator. I prefer the version above.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
July 6, 2017 at 11:47 am
Why are you using DISTINCT and UNION ALL? That might be the the reason you need the GROUP BY.
SELECT s.SupplierID,
c.Carrier as Supplier
FROM (SELECT SupplierID FROM CPT_SUBDC_Analysis
UNION
SELECT SupplierID FROM CPT.dbo.CPT_SUBDC_Analysis) s
LEFT OUTER JOIN Carrier c ON c.CarrierID = s.SupplierID
ORDER BY c.Carrier
Anyway, to get better help, post DDL and execution plans as shown in the following article: How to Post Performance Problems - SQLServerCentral
July 6, 2017 at 11:49 am
With the DISTINCT aggregation operation in addition to the GROUP BY operation but no filtering at all, you're going to be somewhat dependent on hardware (mostly memory & disk) to make this run fast. Any chance of some type of WHERE clause? Do you really have to have ALL the data?
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
July 6, 2017 at 2:17 pm
July 10, 2017 at 4:25 am
ss-457805 - Thursday, July 6, 2017 2:16 PMThanks Luis and Chris for your suggestions. Both your query returns in same time. It take about 1 min 15 sec. Big improvement from the orginial query.
Grant - we cannot use the where clause it needs all the data. No wonder it's doing an index scan on on the whole table. Please find attached the execution plan
-- Using Paul White's superfast "DISTINCT"
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
July 10, 2017 at 11:13 am
Thanks Chris. This is awesome. It's pretty instant.
Thanks for the link as well. Added to my favourites. 🙂
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply