x

Join Question, need to return all "months&yr" for each project... even if 0

Simple Join Question... SQL Server

I have a table that has a running total, that looks like this:

PROJECT# / MONTH&YEAR / SPEND / CUMULATIVE SPEND

In this table, I ran across a problem where if the spend was 0 in a particular month, the cumulative spend for that project would not come across...

So, in order to remedy this, I created a table that contains all project #'s and all months&yr combos...

I wanted to join this to my original table so that every project# had a record for every single month...

But this isn't happening, I tried the left, right, inner, cross, outer...

Any ideas / suggestions?

Thanks

more ▼

asked Aug 10, 2012 at 03:12 PM in Default

avatar image

TelepathicSheep2
140 15 15 19

(comments are locked)
10|1200 characters needed characters left

2 answers: sort voted first

I've tried it like this, and it seems to work:

  1. Create your MonthYear list

  2. Cross join that with all the project IDs

  3. Left outer join the results of that against your main table.

Here's some sample code to show the idea:

 declare @MonYear table (MonYear  char(6))
 Insert into @MonYear values 
 ('012012'), ('022012'), ('032012'), ('042012'), ('052012'), ('062012')
 
 declare @ProjectID table (ProjectID int)
 INSERT INTO @ProjectID values (1), (2)
 
 declare @ProjSales table (ProjectID int, MonYear char(6), Spend money, CumulativeSpend money)
 insert into @ProjSales values 
 (1, '012012', 500.00, 500.00), (1, '042012', 500.00, 1000.00),
 (2, '012012', 100.00, 100.00), (2, '022012', 100.00, 200.00), (2, '032012', 100.00, 300.00), 
 (2, '042012', 100.00, 400.00), (2, '052012', 100.00, 500.00), (2, '062012', 100.00, 600.00)
 
 SELECT my.MonYear, pid.ProjectID, ps.Spend, ps.CumulativeSpend
 FROM (@MonYear my CROSS JOIN @ProjectID pid) LEFT OUTER JOIN @ProjSales ps ON my.MonYear = ps.MonYear AND pid.ProjectID = ps.ProjectID
 ORDER BY 1,2

And here's the output:

 MonYear ProjID  Spend   CumulativeSpend
 012012  1       500.00  500.00
 012012  2       100.00  100.00
 022012  1       NULL    NULL
 022012  2       100.00  200.00
 032012  1       NULL    NULL
 032012  2       100.00  300.00
 042012  1       500.00  1000.00
 042012  2       100.00  400.00
 052012  1       NULL    NULL
 052012  2       100.00  500.00
 062012  1       NULL    NULL
 062012  2       100.00  600.00
more ▼

answered Aug 10, 2012 at 07:45 PM

avatar image

ThomasRushton ♦♦
39.9k 20 49 52

Thanks, this is much nicer than the solution I had created - as always, your help is appreciated!

Aug 10, 2012 at 09:07 PM TelepathicSheep2
(comments are locked)
10|1200 characters needed characters left

Figured it out, I'm using a UNION to add those rows where the DATE is not equal...

more ▼

answered Aug 10, 2012 at 07:03 PM

avatar image

TelepathicSheep2
140 15 15 19

(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here

By RSS:

Answers

Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.

Topics:

x2079
x150

asked: Aug 10, 2012 at 03:12 PM

Seen: 738 times

Last Updated: Aug 10, 2012 at 09:07 PM

Copyright 2016 Redgate Software. Privacy Policy