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


Window function on different date ranges


Window function on different date ranges

Author
Message
vip.blade
vip.blade
SSC Journeyman
SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)

Group: General Forum Members
Points: 94 Visits: 282
Hi,

I have a question regarding windowing functions. I have a sales order table with the columns "orderid", "customerid", "order_date" and "amount". I use the following query to get the amount of every customer as a additional column:



Select customerid,
orderid,
order_date,
amount,
SUM(amount) OVER (PARTITION BY customerid)

FROM sales_orders




My question is if there is a good way to add another column, which includes the SUM(amount) of the customerid, where the order_date > 2012-01-15 , something like this:



Select customerid,
orderid,
order_date,
amount,
SUM(amount) OVER (PARTITION BY customerid),
SUM(amount) OVER (PARTITION BY customerid WHERE order_date > 2012-01-15)

FROM sales_orders




I know, this is not a valid method, so do you know a way to achieve this? Can I maybe use CROSS APPLY or something like this? I know that I could use a subquery to get this, but is there maybe a way / a better way via window functions?


Best regards!
Lowell
Lowell
SSC Guru
SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)

Group: General Forum Members
Points: 75555 Visits: 40987
i think a field with a SUM+CASE statement would do the job:

SUM(CASE WHEN order_date > 2012-01-15 THEN amount ELSE 0 END ) OVER (PARTITION BY customerid )


--this passes 2012 syntax
Select customerid,
orderid,
order_date,
amount,
SUM(amount) OVER (PARTITION BY customerid),
SUM(CASE WHEN order_date > 2012-01-15 THEN amount ELSE 0 END ) OVER (PARTITION BY customerid )

FROM sales_orders



Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18523 Visits: 6431
Lowell has provided you a perfectly good solution to your question. However, you may want to also consider something like the following for performance reasons:


WITH PreAggregate AS
(
SELECT customerid
,sa1=SUM(amount)
,sa2=SUM(CASE WHEN order_date > '2012-01-15' THEN amount ELSE 0 END)
FROM sales_orders
GROUP BY customerid
)

Select customerid, orderid, order_date, amount, sa1, sa2
FROM sales_orders a
JOIN PreAggregate b ON a.customerid = b.customerid;




Reference: The Performance of the T-SQL Window Functions

Edit: Lowell, please pardon me for originally suggesting that your fine solution was the work of Luis. I didn't get Luis's post until just now. [face-slap]/face-slap]


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
Luis Cazares
Luis Cazares
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43488 Visits: 19860
dwain.c (2/5/2014)
Luis has provided you a perfectly good solution to your question.

I managed to get into your head. I hope you won't have nightmares Hehe


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18523 Visits: 6431
Luis Cazares (2/5/2014)
dwain.c (2/5/2014)
Luis has provided you a perfectly good solution to your question.

I managed to get into your head. I hope you won't have nightmares Hehe


Only if I start hearing Zombie by the Cranberries playing over and over in my head.


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
vip.blade
vip.blade
SSC Journeyman
SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)

Group: General Forum Members
Points: 94 Visits: 282
Wow, thats amazing, thanks alot! I never thought of using a CASE-Statement in a SUM() function. That helped me very much!

Is there also a way to use the FIRST_VALUE(order_date) window function this way (to show the first order_date after the 2012-01-15 and another column, which shows the first order_date without a date restriction for every customer)?



Best regards!
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18523 Visits: 6431
vip.blade (2/6/2014)
Wow, thats amazing, thanks alot! I never thought of using a CASE-Statement in a SUM() function. That helped me very much!

Is there also a way to use the FIRST_VALUE(order_date) window function this way (to show the first order_date after the 2012-01-15 and another column, which shows the first order_date without a date restriction for every customer)?



Best regards!


That does sound possible to me. I'd need some DDL and consumable sample data if you want a tested bit of code for it though.

[This is one of the very few times I've ever posted a solution without DDL and sample data to test it with]


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
vip.blade
vip.blade
SSC Journeyman
SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)

Group: General Forum Members
Points: 94 Visits: 282
dwain.c (2/6/2014)
vip.blade (2/6/2014)
Wow, thats amazing, thanks alot! I never thought of using a CASE-Statement in a SUM() function. That helped me very much!

Is there also a way to use the FIRST_VALUE(order_date) window function this way (to show the first order_date after the 2012-01-15 and another column, which shows the first order_date without a date restriction for every customer)?



Best regards!


That does sound possible to me. I'd need some DDL and consumable sample data if you want a tested bit of code for it though.

[This is one of the very few times I've ever posted a solution without DDL and sample data to test it with]




I use the [AdventureWorks2012].[Sales].[SalesOrderHeader] table for my tests:



SELECT [CustomerID]
,SalesOrderID
,[OrderDate]
,[TotalDue]
,SUM(CASE WHEN CAST([OrderDate] AS DATE) > '2008-02-20' THEN [TotalDue] ELSE 0 END) OVER (PARTITION BY CustomerID)


FROM [AdventureWorks2012].[Sales].[SalesOrderHeader]





Do you have this test database or should I provide you some more information?




Best regards and thanks alot!
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18523 Visits: 6431
Sorry but I don't have/use Adventure Works.


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
vip.blade
vip.blade
SSC Journeyman
SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)SSC Journeyman (94 reputation)

Group: General Forum Members
Points: 94 Visits: 282
Ok, so here is the DDL and some sample data:




CREATE TABLE [Sales].[SalesOrderHeader](
[SalesOrderID] [int],
[OrderDate] [datetime] NOT NULL,
[CustomerID] [int] NOT NULL,
[TotalDue] [Numeric](10,2),

CONSTRAINT [PK_SalesOrderHeader_SalesOrderID] PRIMARY KEY CLUSTERED
(
[SalesOrderID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO


INSERT INTO [AdventureWorks2012].[Sales].[SalesOrderHeader] ([SalesOrderID]
,[OrderDate]
,[CustomerID]
,[TotalDue])

VALUES ('43659','2005-07-01 00:00:00.000', '29825', 23153.23),
('43660','2005-07-02 00:00:00.000', '29825', 23111.82),
('43661','2013-08-02 00:00:00.000', '29825', 11.82),
('43662','2014-01-05 00:00:00.000', '29825', 111.22),
('43663','2007-05-05 00:00:00.000', '29826', 541.22),
('43664','2003-12-12 00:00:00.000', '29826', 1641.22),
('43665','2009-08-12 00:00:00.000', '29826', 11641.22)








If you need more sample data, please let me know.



Best regards and thanks!
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