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


dynamic billing cycle


dynamic billing cycle

Author
Message
memostone86
memostone86
SSC-Enthusiastic
SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)

Group: General Forum Members
Points: 139 Visits: 88
Hi,

We have a parameter which shows dynamically the billing cycle in the report, our billing cycle is from 21th this month-20th next month.
In the billing cycle parameter, we need to create 20 drop-downs.
we had problem to dynamically switch the year to 2011 or so. Here are two examples following:

1. Today is 4/1/2012, so first drop-down should be 3/21/2012-4/20/2012, then 2/21/2012-3/20/2012, 1/21/2012-2/20/2012, 12/21/2011-1/20/2012..(here comes the problem, how do we dynamically know if it goes to Dec, so year should be 2011)

2. If report renders at 2/12/2012, first drop-down is 1/21/2012-2/20/2012, then 12/20/2011-1/20/2012....

I've created ssrs expression for the first drop-down, but cannot implement logic of dec,2011.
=iif(day(Today)<21, format(DateAdd("m",-1,Today),"MM")&"/21/2012-"&Format(Today,"MM")&"/20/2012",Format(Today,"MM")&"/21/2012-"&format(DateAdd("m",1,Today),"MM")&"/20/2012")

Posted this on msdn forum, haven't got any update. Appreciate for the help.
Conficker
Conficker
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1247 Visits: 626
Hello,

This might help you, rather than doing into SSRS, create new datasource and use below code for your parameter


DECLARE @Day INT
SET @Day = datePart(dd,getDate())

IF @DAY < 21
BEGIN
SELECT CONVERT(VARCHAR(25),(dateAdd(MONTH, dateDiff(MONTH, 0, getDate()), 0) + 20),103)+
' - '+
CONVERT(VARCHAR(25),((dateAdd(mm,-1,getDate() ) - datePart(d,getDate()))+20),103)
END
ELSE
SELECT CONVERT(VARCHAR(25),((dateAdd(mm,-1,getDate() ) - datePart(d,getDate()))+21),103)+
' - '+
CONVERT(VARCHAR(25),((dateAdd(mm,-2,getDate() ) - datePart(d,getDate()))+20),103)




and keep amx happy!!!;-)
memostone86
memostone86
SSC-Enthusiastic
SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)

Group: General Forum Members
Points: 139 Visits: 88
Hi Conficker,

Appreciate for your inputs. The dataset you provided is the same as my ssrs expression, from which get the first drop-down. But I had some problems for the rest 19 drop-downs following because of year will change to 2011, maybe 2010 even.
Do you have any suggestions for that? Thank you.
Conficker
Conficker
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1247 Visits: 626
could explain your problem into more detail, plz?? if possible then with example??

19 drop-downs means, 19 previous months??? is that 19 different parameters??
memostone86
memostone86
SSC-Enthusiastic
SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)

Group: General Forum Members
Points: 139 Visits: 88
Sure, sorry I didn't clarify clearly. This is only one parameter, which has 20 drop-downs of 20 date range. And we can choose any of it to render report. First one is based on the date renders report, and following are previous 20 cycles(months)

For example,

1. Today is 4/2/2012, then for this parameter, there are 20 drop-downs and we can choose any of them to render report. first drop-down should be 3/21/2012-4/20/2012, then 2/21/2012-3/20/2012, 1/21/2012-2/20/2012, 12/21/2011-1/20/2012, 11/21/2011-12/20/2011, 10/21/2011-11/20/2011......and so on


2. If report renders at 2/12/2012, first drop-down is 1/21/2012-2/20/2012 because date 2/12/2012 falls into this range, then 12/21/2011-1/20/2012, 11/21/2011-12/20/2011, 10/21/2011-11/20/2011, 9/21/2011-10/20/2011.....and so on
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)

Group: General Forum Members
Points: 391464 Visits: 42833
For a SQL based solution, you can try this, but please note that it won't work for billing dates that start on the 29th, 30th, or 31st of the month.


declare @BillDate datetime;
declare @StartDay int;
set @StartDay = 21; -- Beginning day of billing cycle, this code will not work properly for billing dates starting 29 - 31
set @BillDate = cast('20120401' as datetime); -- Test date
select @BillDate;

with e2 (
N
) as (
select 1 union all select 1
)
,e10 (
N
) as (
select 1 union all select 1 union all select 1 union all select 1 union all select 1
union all select 1 union all select 1 union all select 1 union all select 1 union all select 1
)
,e20 (
N
) as (
select row_number() over (order by (select null)) from e2 a cross join e10 b
)
--select N from e20;
select
convert(varchar(10),dateadd(dd, @StartDay - 1, dateadd(mm, datediff(mm, 0, dateadd(dd, -N * @StartDay,@BillDate)), 0)),101) + ' - ' +
convert(varchar(10),dateadd(dd, -1, dateadd(mm, 1, dateadd(dd, @StartDay - 1, dateadd(mm, datediff(mm, 0, dateadd(dd, -N * @StartDay,@BillDate)), 0)))),101)
from e20



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)
Conficker
Conficker
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1247 Visits: 626
DECLARE @Day INT
SET @Day = datePart(dd,getDate())

DECLARE @i INT
SET @i = 0

CREATE TABLE #temp1
(para VARCHAR(50))

WHILE (@i<20)
BEGIN
IF @DAY < 21
BEGIN
INSERT INTO #temp1
SELECT CONVERT(VARCHAR(25),((dateAdd(mm,-(@i+0),getDate() ) - datePart(d,getDate()))+21),103)+
' - '+
CONVERT(VARCHAR(25),((dateAdd(mm,-(@i+1),getDate() ) - datePart(d,getDate()))+20),103)

END
ELSE
BEGIN
INSERT INTO #temp1
SELECT CONVERT(VARCHAR(25),((dateAdd(mm,-(@i+1),getDate() ) - datePart(d,getDate()))+21),103)+
' - '+
CONVERT(VARCHAR(25),((dateAdd(mm,-(@i+2),getDate() ) - datePart(d,getDate()))+20),103)


END
SET @i = @i+1
END


SELECT * FROM #temp1
DROP TABLE #temp1



here we go ...!Smile
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)

Group: General Forum Members
Points: 391464 Visits: 42833
Conficker (4/2/2012)
DECLARE @Day INT
SET @Day = datePart(dd,getDate())

DECLARE @i INT
SET @i = 0

CREATE TABLE #temp1
(para VARCHAR(50))

WHILE (@i<20)
BEGIN
IF @DAY < 21
BEGIN
INSERT INTO #temp1
SELECT CONVERT(VARCHAR(25),((dateAdd(mm,-(@i+0),getDate() ) - datePart(d,getDate()))+21),103)+
' - '+
CONVERT(VARCHAR(25),((dateAdd(mm,-(@i+1),getDate() ) - datePart(d,getDate()))+20),103)

END
ELSE
BEGIN
INSERT INTO #temp1
SELECT CONVERT(VARCHAR(25),((dateAdd(mm,-(@i+1),getDate() ) - datePart(d,getDate()))+21),103)+
' - '+
CONVERT(VARCHAR(25),((dateAdd(mm,-(@i+2),getDate() ) - datePart(d,getDate()))+20),103)


END
SET @i = @i+1
END


SELECT * FROM #temp1
DROP TABLE #temp1



here we go ...!Smile


Why use a while loop? You will find the code I provided just as efficient and much more scalable.

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)
memostone86
memostone86
SSC-Enthusiastic
SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)SSC-Enthusiastic (139 reputation)

Group: General Forum Members
Points: 139 Visits: 88
Thank you Lynn and Conficker, your solutions both worked.

BTW, is there a button to mark as a answer? I didn't find it.
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)SSC Guru (391K reputation)

Group: General Forum Members
Points: 391464 Visits: 42833
Glad to help.

And no, there is no button to mark the thread as answered. The thread will stay open and others may come along and offer other suggestions or even ask additional questions regarding the solutions.

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