SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


High-Performance Transact-SQL with Window Functions


High-Performance Transact-SQL with Window Functions

Author
Message
learnwithvideotutorials
learnwithvideotutorials
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 27
Comments posted to this topic are about the item High-Performance Transact-SQL with Window Functions

www.learn-with-video-tutorials.com - video tutorials
OldFashionGang
OldFashionGang
Grasshopper
Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)Grasshopper (19 reputation)

Group: General Forum Members
Points: 19 Visits: 388
You have chosen a strange title for the article. It`s starts with "High-Performance..." but there is no performance comparison between Windowed Functions and other approaches. The article itself is interesting and might be very cognitive, but its title is a bit confusing.
davidadlington78
davidadlington78
Grasshopper
Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)

Group: General Forum Members
Points: 10 Visits: 70
How does the optimiser handle these querys/techniques vs standard methods?
learnwithvideotutorials
learnwithvideotutorials
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 27
OldFashionGang - Thank you for your comment. Next time I will try to choose a better title

www.learn-with-video-tutorials.com - video tutorials
learnwithvideotutorials
learnwithvideotutorials
Forum Newbie
Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)Forum Newbie (9 reputation)

Group: General Forum Members
Points: 9 Visits: 27
davidadlington78 - maybe next article will be about this.

www.learn-with-video-tutorials.com - video tutorials
jshahan
jshahan
SSChasing Mays
SSChasing Mays (653 reputation)SSChasing Mays (653 reputation)SSChasing Mays (653 reputation)SSChasing Mays (653 reputation)SSChasing Mays (653 reputation)SSChasing Mays (653 reputation)SSChasing Mays (653 reputation)SSChasing Mays (653 reputation)

Group: General Forum Members
Points: 653 Visits: 2112
This is the simplest and most straight forward example for gaps and islands that I have ever seen. Thank you VERY much for posting.
katesl
katesl
SSC Veteran
SSC Veteran (237 reputation)SSC Veteran (237 reputation)SSC Veteran (237 reputation)SSC Veteran (237 reputation)SSC Veteran (237 reputation)SSC Veteran (237 reputation)SSC Veteran (237 reputation)SSC Veteran (237 reputation)

Group: General Forum Members
Points: 237 Visits: 473
/* Occam says, do we really need these new T-SQL constructs? And, when delivering a solution, anticipate that the client may ask some follow-on questions. Thus, it's often worth the I/O and table space to save the intermediate results.
*/

alter table dbo.T1 add seq int identity, prevStep int, nextStep int, stepType varchar(10)
go

update t1
set prevstep=0
where seq=1

update a
set prevstep=abs(b.col1-a.col1)
from t1 a
join t1 b
on a.seq=b.seq+1
where a.prevstep is null

update a
set nextstep=b.col1-a.col1
from t1 a
join t1 b
on a.seq=b.seq-1

update t1
set steptype =
case
when (prevstep=0 or prevstep > 1) and (nextstep > 1 or nextstep is null) then 'begin/end'
when prevstep=0 or prevstep > 1 then 'begin'
when prevstep=1 and nextstep=1 then 'middle'
else 'end'
end

IF OBJECT_ID('dbo.T1_islands', 'U') IS NOT NULL drop table t1_islands
select col1 as beginIsland
, case steptype when 'begin/end' then col1 else 0 end as endIsland
into t1_islands
from t1
where steptype like 'begin%'

update i
set endIsland=b.col1
from t1 a
join t1_islands i
on a.col1 = i.beginIsland
join t1 b
on b.seq=(select min(seq) from t1 where steptype='end' and seq > a.seq)
where i.endIsland = 0

select * from t1_islands

--find the biggest islands
select beginIsland,endIsland
from t1_islands
where endIsland-beginIsland = (select max(endIsland-beginIsland) from t1_islands)

--find the biggest gaps between islands
select max(nextstep) from t1

_________________
"Look, those sheep have been shorn."
data analyst replies, "On the sides that we can see.."
Peter E. Kierstead
Peter E. Kierstead
Mr or Mrs. 500
Mr or Mrs. 500 (532 reputation)Mr or Mrs. 500 (532 reputation)Mr or Mrs. 500 (532 reputation)Mr or Mrs. 500 (532 reputation)Mr or Mrs. 500 (532 reputation)Mr or Mrs. 500 (532 reputation)Mr or Mrs. 500 (532 reputation)Mr or Mrs. 500 (532 reputation)

Group: General Forum Members
Points: 532 Visits: 453
Dense_Rank() would be a better choice for your windowing function as it would permit duplicate values to exist in your data islands.



PeteK
I have CDO. It's like OCD but all the letters are in alphabetical order... as they should be.
dwain.c
dwain.c
SSCrazy Eights
SSCrazy Eights (9.8K reputation)SSCrazy Eights (9.8K reputation)SSCrazy Eights (9.8K reputation)SSCrazy Eights (9.8K reputation)SSCrazy Eights (9.8K reputation)SSCrazy Eights (9.8K reputation)SSCrazy Eights (9.8K reputation)SSCrazy Eights (9.8K reputation)

Group: General Forum Members
Points: 9809 Visits: 6431
OldFashionGang (12/2/2013)
You have chosen a strange title for the article. It`s starts with "High-Performance..." but there is no performance comparison between Windowed Functions and other approaches. The article itself is interesting and might be very cognitive, but its title is a bit confusing.


I have to agree with the above. In your article, you indicate that this:


SELECT orderid, custid, val,
CAST(100. * val / SUM(val) OVER(PARTITION BY custid) AS NUMERIC(5, 2)) AS pctcust,
val - AVG(val) OVER(PARTITION BY custid) AS diffcust,
CAST(100. * val / SUM(val) OVER() AS NUMERIC(5, 2)) AS pctall,
val - AVG(val) OVER() AS diffall
FROM dbo.tb_OrderValues;




Is equivalent to this:


WITH CustAggregates AS
(
SELECT custid, SUM(val) AS sumval, AVG(val) AS avgval
FROM dbo.tb_OrderValues
GROUP BY custid
),
GrandAggregates AS
(
SELECT SUM(val) AS sumval, AVG(val) AS avgval
FROM dbo.tb_OrderValues
)
SELECT O.orderid, O.custid, O.val,
CAST(100. * O.val / CA.sumval AS NUMERIC(5, 2)) AS pctcust,
O.val - CA.avgval AS diffcust,
CAST(100. * O.val / GA.sumval AS NUMERIC(5, 2)) AS pctall,
O.val - GA.avgval AS diffall
FROM dbo.tb_OrderValues AS O
JOIN CustAggregates AS CA
ON O.custid = CA.custid
CROSS JOIN GrandAggregates AS GA;




Which from the perspective of output results is true. Now try the following 1,000,000 row test harness:


IF OBJECT_ID('tb_OrderValues') IS NOT NULL
DROP TABLE tb_OrderValues;
GO

CREATE TABLE tb_OrderValues(
orderid int,
custid int,
empid int,
shipperid int,
orderdate datetime,
requireddate datetime,
shippeddate datetime,
qty int,
val numeric(12, 2)
);

WITH Tally (n) AS
(
SELECT TOP 1000 ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM sys.all_columns a CROSS JOIN sys.all_columns b
)
INSERT INTO tb_OrderValues
SELECT a.n, b.n, 100*a.n, 100*b.n
,CAST('2006-01-01' AS DATETIME)+a.n-1
,CAST('2006-01-01' AS DATETIME)+a.n+60
,CAST('2006-01-01' AS DATETIME)+a.n+30
,1+ABS(CHECKSUM(NEWID()))%100
,1+ABS(CHECKSUM(NEWID()))%1000
FROM Tally a
CROSS APPLY Tally b;

DECLARE
@orderid int,
@custid int,
@pctcust NUMERIC(5,2),
@diffcust numeric(12, 2),
@pctall NUMERIC(5,2),
@diffall numeric(12, 2),
@shippeddate datetime,
@qty int,
@val numeric(12, 2);


PRINT 'Pre-aggregate';
SET STATISTICS TIME ON;
WITH CustAggregates AS
(
SELECT custid, SUM(val) AS sumval, AVG(val) AS avgval
FROM dbo.tb_OrderValues
GROUP BY custid
),
GrandAggregates AS
(
SELECT SUM(val) AS sumval, AVG(val) AS avgval
FROM dbo.tb_OrderValues
)
SELECT @orderid=O.orderid, @custid=O.custid, @val=O.val,
@pctcust=CAST(100. * O.val / CA.sumval AS NUMERIC(5, 2)), -- AS pctcust,
@diffcust=O.val - CA.avgval, -- AS diffcust,
@pctall=CAST(100. * O.val / GA.sumval AS NUMERIC(5, 2)), -- AS pctall,
@diffall=O.val - GA.avgval -- AS diffall
FROM dbo.tb_OrderValues AS O
JOIN CustAggregates AS CA
ON O.custid = CA.custid
CROSS JOIN GrandAggregates AS GA;
SET STATISTICS TIME OFF;

PRINT 'Aggregate window functions';
SET STATISTICS TIME ON;
SELECT @orderid=orderid, @custid=custid, @val=val,
@pctcust=CAST(100. * val / SUM(val) OVER(PARTITION BY custid) AS NUMERIC(5, 2)), -- AS pctcust,
@diffcust=val - AVG(val) OVER(PARTITION BY custid), -- AS diffcust,
@pctall=CAST(100. * val / SUM(val) OVER() AS NUMERIC(5, 2)), -- AS pctall,
@diffall=val - AVG(val) OVER() --AS diffall
FROM dbo.tb_OrderValues;
SET STATISTICS TIME OFF;

GO
DROP TABLE tb_OrderValues;




The timing results produce the following:


(1000000 row(s) affected)
Pre-aggregate

SQL Server Execution Times:
CPU time = 4494 ms, elapsed time = 2507 ms.
Aggregate window functions

SQL Server Execution Times:
CPU time = 11716 ms, elapsed time = 8533 ms.



Which indicates the approach that pre-aggregates is more that 70% faster than the window aggregates.

I've generally found this to be the case.

You should write every query as if it will be executed 1,000,000 times per day on 1,000,000 rows of data.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
John Chapman
John Chapman
Valued Member
Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)Valued Member (69 reputation)

Group: General Forum Members
Points: 69 Visits: 172
Having just skimmed over this posting, I'm not sure that this is relevant, but have you looked at the "quirky update" method. Yes, it's a bit dirty, but if you must have performance, then it's worth trying.
See: Solving the Running Total and Ordinal Rank Problems: http://www.sqlservercentral.com/articles/T-SQL/68467
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