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


Report adds a new year's data to the right of the report - way to automate?


Report adds a new year's data to the right of the report - way to automate?

Author
Message
jamey8420
jamey8420
SSC Rookie
SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)

Group: General Forum Members
Points: 29 Visits: 135
I have a report that is laid out as such:

Client | 2003 Fees Billed | 2004 Fees Billed | ... | 2013 Fees Billed | 2014 Fees Billed

ABC 500 1000 750 250
XYZ 333 800 243 889


Currently, I'm running this report manually each month, and capturing any new fees billed to the specific clients. I'd like to automate this report and get me out of doing it each month. I capture the amount billed for the total time period (2003 - 2014) and then break out each year by itself. As we are rolling over to 2014, a new column of data will need to be added. And going forward as 2015 comes around, etc...these will also be new columns added to the right of 2014.

I'd like to automate this if possible, but I'm not quite sure how to accomplish this. I know I could add the future years to the report now, add code for the years for when data does exist, and only show those future years if data is there. However, that's probably not the most efficient or clean.


Current SQL Code for the report

select distinct client, year, ISNULL(sum(fees_billed),0) as fees_billed
into #a
from client c
join whse w on c.client= w.client
and begdt>=‘1/1/2003’ and enddt<=‘12/31/2013’
group by client, year
order by 1, 3

select distinct client, year, ISNULL(sum(fees_billed),0) as fees_billed
into #b
from client c
join whse w on c.client= w.client
and begdt>=‘1/1/2003’ and enddt<=‘12/31/2003’
group by client, year
order by 1, 3

select distinct client, year, ISNULL(sum(fees_billed),0) as fees_billed
into #c
from client c
join whse w on c.client= w.client
and begdt>=‘1/1/2004’ and enddt<=‘12/31/2004’
group by client, year
order by 1, 3

etc....for the following years

select #a.*, #b.begdt+’03’, ISNULL(#b.fees_billed,0), #c.begdt+’04’, ISNULL(#c.fees_billed,0),
#d.begdt+’05’, ISNULL(#d.fees_billed,0), #e.begdt+’06’, ISNULL(#e.fees_billed,0), #f.begdt+’07’, ISNULL(#f.fees_billed,0), #g.begdt+’08’, ISNULL(#g.fees_billed,0),
#h.begdt+’09’, ISNULL(#h.fees_billed,0), #i.begdt+’10’, ISNULL(#i.fees_billed,0), #j.begdt+’11’, ISNULL(#j.fees_billed,0), #k.begdt+’12’, ISNULL(#k.fees_billed,0), #l.begdt+’13’, ISNULL(#l.fees_billed,0)
from #a
left outer join #b on #a.client = #b.client and left(#a.begdt,6) = left(#b.begdt,6)
left outer join #c on #a.client = #c.client and left(#a.begdt,6) = left(#c.begdt,6)
left outer join #d on #a.client = #d.client and left(#a.begdt,6) = left(#d.begdt,6)
left outer join #e on #a.client = #e.client and left(#a.begdt,6) = left(#e.begdt,6)
left outer join #f on #a.client = #f.client and left(#a.begdt,6) = left(#f.begdt,6)
left outer join #g on #a.client = #g.client and left(#a.begdt,6) = left(#g.begdt,6)
left outer join #h on #a.client = #h.client and left(#a.begdt,6) = left(#h.begdt,6)
left outer join #i on #a.client = #i.client and left(#a.begdt,6) = left(#i.begdt,6)
left outer join #j on #a.client = #j.client and left(#a.begdt,6) = left(#j.begdt,6)
left outer join #k on #a.client = #k.client and left(#a.begdt,6) = left(#k.begdt,6)
left outer join #l on #a.client = #l.client and left(#a.begdt,6) = left(#l.begdt,6)
order by 1




If anyone has an idea of how to "elegantly program" this, it would be truly appreciated.

Thanks!
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8566 Visits: 18143
Your code seems really unefficient and unconsistent. Here's a better option to do it.

SELECT client,
SUM( CASE WHEN year = 2003 THEN fees_billed ELSE 0 END) as fees_billed_2003,
SUM( CASE WHEN year = 2004 THEN fees_billed ELSE 0 END) as fees_billed_2004,
SUM( CASE WHEN year = 2005 THEN fees_billed ELSE 0 END) as fees_billed_2005,
--and so on
SUM( CASE WHEN year = 2013 THEN fees_billed ELSE 0 END) as fees_billed_2013
FROM client c
JOIN whse w on c.client= w.client
--and begdt>=‘1/1/2004’ and enddt<=‘12/31/2013’
GROUP BY client
ORDER BY client


It's still static code but it will go through your table just once. From here, you can make the T-SQL dynamic, but you might still need to change the report front-end.
To convert the code into dynamic code, read the following articles:
http://www.sqlservercentral.com/articles/T-SQL/63681/
http://www.sqlservercentral.com/articles/Crosstab/65048/


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
pietlinden
pietlinden
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2185 Visits: 12548
The other way to do it is to use a Matrix in SSRS. You could base your report on a stored procedure that accepts the date range you want and you're off to the races.

Just depends on what you need.
jamey8420
jamey8420
SSC Rookie
SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)SSC Rookie (29 reputation)

Group: General Forum Members
Points: 29 Visits: 135
pietlinden,
Thanks for the suggestion on the Matrix report - this was just what I needed.
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