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


Apply targets to each month between two dates


Apply targets to each month between two dates

Author
Message
dcaulton73
dcaulton73
SSC Journeyman
SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)

Group: General Forum Members
Points: 89 Visits: 19
I have a table in SQL which lists a monthly target for a particular contract (tblTarget).
tblTarget has a layout like such:

ContractName StartMonth EndMonth TargetMonth1 TargetMonth2 TargetMonth3... up to.... TargetMonth12
Contract1 01//2017 12/2017 20 30 40 10
Contract2 01//2017 12/2017 25 20 19 10
Contract3 03//2017 02/2018 20 30 40 10
Contract4 06//2017 05/2018 40 40 40 40


TargetMonth1 will apply to the first month the contract started, so in the case of Contract1 it will be Jan 2017, Contract3 will be March 2017 and so on. Then each target month figure after that will need to be applied to each subsequent month. So TargetMonth2 for Contract1 will apply to Feb 2017 whereas TargetMonth2 for Contract4 will apply to June 2017 up until the EndMonth.
I need to be able to create a new table or view that I can use which will show an entry for each contract and each month that the targets will apply to, so something like this:


ContractName MonthYear Target
Contract1 01//2017 20
Contract1 02//2017 30
Contract1 03//2017 40
Contract1 04//2017 10
Contract3 03//2017 20
Contract3 04//2017 30
Contract3 05//2017 40
Contract3 06//2017 10


I've been racking my brains and haven't a clue how to do this in SQL. Any help will be appreciated.

drew.allen
drew.allen
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60621 Visits: 16019
It looks like a fairly standard UNPIVOT. What are you having difficulties with?

The main issue that I see is that you are storing your dates in a non-standard format. Or are you having trouble translating the column to the date offset?

Drew

J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
J Livingston SQL
J Livingston SQL
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44606 Visits: 41776
you have posted in " ".....what MS SQL version are you really running?
  • 0px 0px no-repeat;">»


________________________________________________________________
you can lead a user to data....but you cannot make them think
and remember....every day is a school day

dcaulton73
dcaulton73
SSC Journeyman
SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)

Group: General Forum Members
Points: 89 Visits: 19
J Livingston SQL - Tuesday, February 6, 2018 8:02 AM
you have posted in " ".....what MS SQL version are you really running?
  • »


Apoogies, using 2016.
dcaulton73
dcaulton73
SSC Journeyman
SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)

Group: General Forum Members
Points: 89 Visits: 19
drew.allen - Tuesday, February 6, 2018 8:00 AM
It looks like a fairly standard UNPIVOT. What are you having difficulties with?

The main issue that I see is that you are storing your dates in a non-standard format. Or are you having trouble translating the column to the date offset?

Drew


The date formats are no problem, I can sort those. I wasn't sure of how to turn the TargetMonth1, TargetMonth2 etc into a Jan017, Feb2017 etc and have each of the targets assigned to those months? Unfortunately Month1 isn't always going to be January and that's one of the things confusing me.
drew.allen
drew.allen
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60621 Visits: 16019
I would use the Table Value Constructor version instead of the standard UNPIVOT, because it's more flexible and you need that flexibility here. I've used a sample where the StartDate is in a datetime format, you can replace that with whatever you're using to handle the dates.

SELECT ContractName, DATEADD(MONTH, n, StartMonth), [Target]
FROM tblTarget
CROSS APPLY
(
VALUES
(0, TargetMonth1),
(1, TargetMonth2),
(2, TargetMonth3),
(11, TargetMonth12)
) v(n, [Target])


Drew

J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
dcaulton73
dcaulton73
SSC Journeyman
SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)SSC Journeyman (89 reputation)

Group: General Forum Members
Points: 89 Visits: 19
drew.allen - Tuesday, February 6, 2018 9:46 AM
I would use the Table Value Constructor version instead of the standard UNPIVOT, because it's more flexible and you need that flexibility here. I've used a sample where the StartDate is in a datetime format, you can replace that with whatever you're using to handle the dates.

SELECT ContractName, DATEADD(MONTH, n, StartMonth), [Target]
FROM tblTarget
CROSS APPLY
(
VALUES
(0, TargetMonth1),
(1, TargetMonth2),
(2, TargetMonth3),
(11, TargetMonth12)
) v(n, [Target])


Drew


This seems to have done the trick. thank you so much for your help. Would never have figured that one out for myself.
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