Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


temporary tablesvs derived table


temporary tablesvs derived table

Author
Message
kevin_nikolai
kevin_nikolai
SSC Veteran
SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)SSC Veteran (227 reputation)

Group: General Forum Members
Points: 227 Visits: 511
The following query uses a temporary table.
Northwind.dbo.Categories = 8 rows,
Northwind.dbo.Products = 77 rows

SELECT GETDATE() as Time
GO
CREATE TABLE #Temp_Example (
[CategoryID] INT NOT NULL,
[Category_Count] INT NOT NULL
)

INSERT INTO #Temp_Example (CategoryID, Category_Count)
SELECT C.CategoryID, COUNT(*) AS Category_Count
FROM Categories C
INNER JOIN Products P ON C.CategoryID = P.CategoryID
GROUP BY C.CategoryID, C.CATEGORYNAME

SELECT C.CategoryID, C.CategoryName, P.ProductName, P.UnitPrice, #Temp_Example.Category_Count
FROM Categories C
INNER JOIN Products P ON C.CategoryID = P.CategoryID
INNER JOIN #Temp_Example ON C.CategoryID = #Temp_Example.CategoryID
ORDER BY C.CategoryName

DROP TABLE #Temp_Example
GO
SELECT GETDATE() as Time


--Duration = 80-110

==================

The following query uses a derived table.
Northwind.dbo.Categories = 8 rows,
Northwind.dbo.Products = 77 rows


SELECT GETDATE() as Time
GO
SELECT C.CategoryID, C.CategoryName, P.ProductName, P.UnitPrice, CT.Category_Count
FROM Categories C
INNER JOIN Products P ON C.CategoryID = P.CategoryID
INNER JOIN (
SELECT C.CategoryID, COUNT(*) AS Category_Count
FROM Categories C
INNER JOIN Products P ON C.CategoryID = P.CategoryID
GROUP BY C.CategoryID, C.CategoryName
)CT ON C.CategoryID = CT.CategoryID
ORDER BY C.CategoryName
GO
SELECT GETDATE() as Time


--Duration = 50-80


***
By using derived tables instead of temporary tables, you reduce disk I/O thereby improving the application's performance

Question: Any suggestions ?



Regards
Kevin
sonyt65@yahoo.com
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)

Group: General Forum Members
Points: 54631 Visits: 40391
1. I see no difference in the time when measured properly...

--SELECT GETDATE() as Time
--GO
SET STATISTICS TIME ON
CREATE TABLE #Temp_Example (
[CategoryID] INT NOT NULL,
[Category_Count] INT NOT NULL
)

INSERT INTO #Temp_Example (CategoryID, Category_Count)
SELECT C.CategoryID, COUNT(*) AS Category_Count
FROM Categories C
INNER JOIN Products P ON C.CategoryID = P.CategoryID
GROUP BY C.CategoryID, C.CATEGORYNAME

SELECT C.CategoryID, C.CategoryName, P.ProductName, P.UnitPrice, #Temp_Example.Category_Count
FROM Categories C
INNER JOIN Products P ON C.CategoryID = P.CategoryID
INNER JOIN #Temp_Example ON C.CategoryID = #Temp_Example.CategoryID
ORDER BY C.CategoryName

DROP TABLE #Temp_Example
SET STATISTICS TIME OFF
GO
--SELECT GETDATE() as Time

PRINT REPLICATE('=',100)
-- --Duration = 80-110
--
-- ==================

-- The following query uses a derived table.
-- Northwind.dbo.Categories = 8 rows,
-- Northwind.dbo.Products = 77 rows


-- SELECT GETDATE() as Time
-- GO
SET STATISTICS TIME ON
SELECT C.CategoryID, C.CategoryName, P.ProductName, P.UnitPrice, CT.Category_Count
FROM Categories C
INNER JOIN Products P ON C.CategoryID = P.CategoryID
INNER JOIN (
SELECT C.CategoryID, COUNT(*) AS Category_Count
FROM Categories C
INNER JOIN Products P ON C.CategoryID = P.CategoryID
GROUP BY C.CategoryID, C.CategoryName
)CT ON C.CategoryID = CT.CategoryID
ORDER BY C.CategoryName
SET STATISTICS TIME OFF
-- GO
-- SELECT GETDATE() as Time


--Duration = 50-80



2. There will probably be a little difference in time because you've included an INSERT in the first set. 2nd set only has one operation.

3. The following statement you posted....
By using derived tables instead of temporary tables, you reduce disk I/O thereby improving the application's performance
... is true ONLY if you intend to use the calculation saved in the Temp Table once.

4. For complex joins with aggragates, it is sometimes MUCH cheaper to use your first method even if the results in the Temp table will only be used once. It just didn't turn out that way for your simple example. Divide and Conquer is a powerful and effective method to greatly enhance the performance of queries.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
RBarryYoung
RBarryYoung
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10356 Visits: 9517
As I said the first time you asked this question:

What is the preferred option, temporary table or derived table.
The general thinking is to prefer derived tables because they leave the optimizer with more freedom to optimize. However, experience also shows that the more complex the query, the less likely the optimizer is going to make the best choices. Consequently, for significantly complex queries, converting one or more derived tables to temporary tables serves both as a way to force certain decisions on the optimizer and as a way to simplify the query, thus allowing the optimizer to make better decisions with what remains. The catch here is that if you convert the wrong derived table to a temporary table, then you end up forcing a bad choice on the optimizer, thus making the overall performance worse instead of better.

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search