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


Rolling 12 month/Period SQL Query Logic


Rolling 12 month/Period SQL Query Logic

Author
Message
dost ind
dost ind
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 4
I want to write rolling 12 SQL query with following data , input will be FY and period no ie @FY=14, @P=3
my result should show rolling 12 months only from FY 14 3,2,1 months from year 13 - 12,11,10,9,8,7,6,5,4
how to do this .group by Dept and objsub. please help

FY   ObjSub   Dept   P_01   P_02   P_03   P_04   P_05   P_06   P_07   P_08   P_09   P_10   P_11   P_12
13   12345   1   12   14   78   87   85   555   5   5   5   5   5   5
13   12349   54   55   4545   55   5   5   5   577   7   77   77   7777   111
14   12345   1   555   55   5   55   555   555   88   88   9   8   1   8
14   12349   54   555   555   51   4   6   7444   477   788   88   221   3654   88
Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24167 Visits: 37929
dost ind (3/29/2014)
I want to write rolling 12 SQL query with following data , input will be FY and period no ie @FY=14, @P=3
my result should show rolling 12 months only from FY 14 3,2,1 months from year 13 - 12,11,10,9,8,7,6,5,4
how to do this .group by Dept and objsub. please help

FY   ObjSub   Dept   P_01   P_02   P_03   P_04   P_05   P_06   P_07   P_08   P_09   P_10   P_11   P_12
13   12345   1   12   14   78   87   85   555   5   5   5   5   5   5
13   12349   54   55   4545   55   5   5   5   577   7   77   77   7777   111
14   12345   1   555   55   5   55   555   555   88   88   9   8   1   8
14   12349   54   555   555   51   4   6   7444   477   788   88   221   3654   88


Insufficient information provided to really be of any help.

Please post the DDL (CREATE TABLE statement(s)) for the table(s) involved in the query, sample data for the table(s) as a series of INSERT INTO statements (please note that some people that may try to help may still only have SQL Server 2005), and expected results based on the sample data. The sample data should have values that will be included and excluded from the desired results.

Need help with this? Please read the first article I reference below in my signature block.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)

Group: General Forum Members
Points: 8484 Visits: 18082
Maybe this code will give you an idea.

DECLARE @FY   int=14,
   @P int=3;
   

DECLARE @Date date
SET @Date = CAST( @FY as CHAR(2)) + RIGHT( '0' + CAST( @P AS varchar(2)), 2) + '01'

SELECT @Date LastPeriod, DATEADD( MM, -11, @Date) AS FirstPeriod.

SELECT DATEADD( MM, -n, @Date)
FROM (VALUES(0),(1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11))Tally(n)
ORDER BY n DESC



As Lynn said, we can't see your information, so any further help would need some help from you. Post the information that Lynn asked and we'll be glad to help.


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
hunchback
hunchback
SSC-Enthusiastic
SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)

Group: General Forum Members
Points: 117 Visits: 639
I second Lynn regarding the needs to post DDL, sample data and expected result. Help us to be able to help you.

Regarding the problem / question I find it easier to solve if we have one row per (Dept, ObjSub, FY, period). To get there you need to unpivot the periods, have a column of [date] type to do some date calculations and then pivot the data back.


SET NOCOUNT ON;
USE tempdb;
GO
DECLARE @T TABLE (
FY smallint NOT NULL,
ObjSub smallint NOT NULL,
Dept smallint NOT NULL,
P_01 int NOT NULL,
P_02 int NOT NULL,
P_03 int NOT NULL,
P_04 int NOT NULL,
P_05 int NOT NULL,
P_06 int NOT NULL,
P_07 int NOT NULL,
P_08 int NOT NULL,
P_09 int NOT NULL,
P_10 int NOT NULL,
P_11 int NOT NULL,
P_12 int NOT NULL
);

INSERT INTO @T (
   FY,   ObjSub, Dept, P_01, P_02, P_03, P_04, P_05, P_06, P_07, P_08, P_09, P_10, P_11, P_12)
VALUES
   (13, 12345, 1, 12, 14, 78, 87, 85, 555, 5, 5, 5, 5, 5, 5),
   (14, 12345, 1, 555, 55, 5, 55, 555, 555, 88, 88, 9, 8, 1, 8),
   (13, 12349, 54, 55, 4545, 55, 5, 5, 5, 577, 7, 77, 77, 7777, 111),
   (14, 12349, 54, 555, 555, 51, 4, 6, 7444, 477, 788, 88, 221, 3654, 88);

DECLARE
   @FY smallint = 14,
   @P smallint = 3;

WITH C1 AS (
SELECT
   CAST(CAST((((U.FY * 100) + STUFF(U.period, 1, 2, '')) * 100) + 1 AS char(8)) AS date) AS dt,
   U.ObjSub,
   U.Dept,
   val
FROM
   @T
   UNPIVOT
   (
   val
   FOR period IN (P_01, P_02, P_03, P_04, P_05, P_06, P_07, P_08, P_09, P_10, P_11, P_12)
   Wink AS U
)
, C2 AS (
SELECT
YEAR(dt) AS FY,
'P_' + RIGHT('00' + LTRIM(MONTH(dt)), 2) AS period,
ObjSub,
Dept,
val
FROM
   C1
WHERE
   dt BETWEEN DATEADD([month], -11, CAST(CAST((((@FY * 100) + @P) * 100) + 1 AS char(8)) AS date))
   AND CAST(CAST((((@FY * 100) + @P) * 100) + 1 AS char(8)) AS date)
)
SELECT
   *
FROM
   C2
   PIVOT
   (
   MAX(val)
   FOR period IN (P_01, P_02, P_03, P_04, P_05, P_06, P_07, P_08, P_09, P_10, P_11, P_12)
   Wink AS P
ORDER BY
   Dept,
   ObjSub,
   FY;
GO

/*

FY   ObjSub   Dept   P_01   P_02   P_03   P_04   P_05   P_06   P_07   P_08   P_09   P_10   P_11   P_12
2013   12345   1   NULL   NULL   NULL   87   85   555   5   5   5   5   5   5
2014   12345   1   555   55   5   NULL   NULL   NULL   NULL   NULL   NULL   NULL   NULL   NULL
2013   12349   54   NULL   NULL   NULL   5   5   5   577   7   77   77   7777   111
2014   12349   54   555   555   51   NULL   NULL   NULL   NULL   NULL   NULL   NULL   NULL   NULL

*/



Since you are using SS 2012 or greater then you could use the function DATEFROMPARTS to convert the values (FY, Stuff(period, 1, 2, ''), 1) to a date.



wBob
wBob
SSC Rookie
SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)SSC Rookie (31 reputation)

Group: General Forum Members
Points: 31 Visits: 576
I think this query would be a lot easier if you had a normalized table structure ( FY, ObjSub, Dept, Period, Value ) and a calendar table, but if that is your structure, then something like this might work for you:

DECLARE @t TABLE ( FY INT, ObjSub INT, Dept INT, P_01 INT, P_02 INT, P_03 INT, P_04 INT, P_05 INT, P_06 INT, P_07 INT, P_08 INT, P_09 INT, P_10 INT, P_11 INT, P_12 INT, 
   PRIMARY KEY ( ObjSub, FY, Dept )
   Wink

INSERT INTO @t VALUES
   ( 13, 12345, 1, 12, 14, 78, 87, 85, 555, 5, 5, 5, 5, 5, 5 ),
   ( 13, 12349, 54, 55, 4545, 55, 5, 5, 5, 577, 7, 77, 77, 7777, 111 ),
   ( 14, 12345, 1, 555, 55, 5, 55, 555, 555, 88, 88, 9, 8, 1, 8 ),
   ( 14, 12349, 54, 555, 555, 51, 4, 6, 7444, 477, 788, 88, 221, 3654, 88 )


DECLARE @FY INT = 14, @P INT = 3

;WITH cte AS
(
SELECT 1 xlevel, FY, ObjSub, Dept,
   @P x,
   CHOOSE ( @P, P_01, P_02, P_03, P_04, P_05, P_06, P_07, P_08, P_09, P_10, P_11, P_12 ) y
FROM @t
WHERE FY = @FY
--and ObjSub = 12345

UNION ALL

SELECT xlevel + 1, IIF ( x - 1 = 0, c.FY - 1, c.FY ), t.ObjSub, t.Dept,
   IIF ( x - 1 = 0, 12, x - 1 ),
   CHOOSE ( IIF ( x - 1 = 0, 12, x - 1 ), P_01, P_02, P_03, P_04, P_05, P_06, P_07, P_08, P_09, P_10, P_11, P_12 ) y
FROM cte c
   INNER JOIN @t t ON c.ObjSub = t.ObjSub
      AND c.Dept = t.Dept
WHERE t.FY = IIF ( x - 1 = 0, c.FY - 1, c.FY )
AND xlevel < 12
)
SELECT *
FROM cte
ORDER BY ObjSub, Dept, FY DESC, x DESC


Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24167 Visits: 37929
It is nice that people are willing to take shots in the dark to help solve the problem. It would also be nice if the OP would provide us with the information we need to provide a better, and tested, solution to the problem.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
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