Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Handling Nulls in a PIVOT Expand / Collapse
Author
Message
Posted Monday, July 7, 2014 2:22 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, August 29, 2014 2:24 PM
Points: 14, Visits: 62
I have the following schema, data, and query to produce a PIVOT output, but I'm struggling with how to handle the nulls that are coming up... any idea how to use ISNULL or some other method? Thanks!

create table names (SalesPerson varchar(50),
Product varchar(50),
SalesAmount money);

insert names values ('Bob', 'Oranges', 100.00);
insert names values ('Bob', 'Pickles', 140.00);
insert names values ('Bob', 'Bananas', 200.00);
insert names values ('Bob', 'Apples', 125.00);
insert names values ('Bob', 'Oranges', 130.00);
insert names values ('Sue', 'Pickles', 155.00);
insert names values ('Sue', 'Bananas', 300.00);
insert names values ('Sue', 'Apples', 75.00);
insert names values ('Ed', 'Oranges', 80.00);
insert names values ('Ed', 'Pickles', 120.00);
insert names values ('Sue', 'Bananas', 220.00);
insert names values ('Ed', 'Apples', 175.00);
insert names values ('Jim', 'Oranges', 130.00);
insert names values ('Jim', 'Pickles', 160.00);
insert names values ('Ed', 'Bananas', 80.00);
insert names values ('Sue', 'Apples', 185.00);
insert names values ('Jim', 'Apples', 185.00);
insert names values ('Sid', 'Oranges', 185.00);
insert names values ('Sue', 'Apples', 185.00);
insert names values ('Jim', 'Bananas', 185.00);
insert names values ('Bob', 'Oranges', 100.00);
insert names values ('Bob', 'Pickles', 140.00);
insert names values ('Bob', 'Bananas', 200.00);
insert names values ('Bob', 'Apples', 125.00);
insert names values ('Sue', 'Pickles', 155.00);
insert names values ('Sue', 'Bananas', 300.00);
insert names values ('Sue', 'Apples', 75.00);
insert names values ('Ed', 'Oranges', 80.00);
insert names values ('Ed', 'Pickles', 120.00);
insert names values ('Sid', 'Apples', 75.00);
insert names values ('Jim', 'Grapes', 80.00);
insert names values ('Ed', 'Beans', 120.00);
insert names values ('Sid', 'Beans', 140.00);
insert names values ('Bob', 'Melons', 200.00);
insert names values ('Bob', 'Beans', 125.00);
insert names values ('Sue', 'Grapes', 130.00);
insert names values ('Sue', 'Apples', 75.00);
insert names values ('Jim', 'Grapes', 80.00);
insert names values ('Ed', 'Beans', 120.00);
insert names values ('Sue', 'Melons', 220.00);
insert names values ('Ed', 'Grapes', 175.00);
insert names values ('Sid', 'Grapes', 130.00);
insert names values ('Sid', 'Pickles', 160.00);
insert names values ('Ed', 'Beans', 80.00);
insert names values ('Sue', 'Apples', 185.00);
insert names values ('Sid', 'Melons', 185.00);
insert names values ('Ed', 'Melons', 185.00);
insert names values ('Sid', 'Melons', 185.00);
insert names values ('Sue', 'Grapes', 185.00);
insert names values ('Sue', 'Beans', 185.00);
insert names values ('Jim', 'Bananas', 185.00);

SELECT SalesPerson, [Oranges] AS Oranges, [Pickles] AS Pickles,
[Bananas] AS Bananas, [Apples] AS Apples,
[Grapes] AS Grapes, [Melons] AS Melons, [Beans] AS Beans
FROM
(SELECT SalesPerson, Product, SalesAmount
FROM names ) ps
PIVOT
(
SUM (SalesAmount)
FOR Product IN
( [Oranges], [Pickles], [Bananas], [Apples], [Grapes], [Melons], [Beans] )
)
AS pvt


SALESPERSON ORANGES PICKLES BANANAS APPLES GRAPES MELONS BEANS
Bob 330 280 400 250 (null) 200 125
Ed 160 240 80 175 175 185 320
Jim 130 160 370 185 160 (null) (null)
Sid 185 160 (null) 75 130 370 140
Sue (null) 310 820 780 315 220 185


Post #1590101
Posted Monday, July 7, 2014 2:38 PM This worked for the OP Answer marked as solution


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 7:07 PM
Points: 3,559, Visits: 7,679
You can use ISNULL() on each column pivoted (ISNULL([Oranges], 0) as Oranges) or you could try a pre-aggregated Cross tab which might give you a performance boost.

SELECT SalesPerson,
SUM( CASE WHEN Product = 'Oranges' THEN SalesAmount ELSE 0 END) Oranges,
SUM( CASE WHEN Product = 'Pickles' THEN SalesAmount ELSE 0 END) Pickles,
SUM( CASE WHEN Product = 'Bananas' THEN SalesAmount ELSE 0 END) Bananas,
SUM( CASE WHEN Product = 'Apples' THEN SalesAmount ELSE 0 END) Apples,
SUM( CASE WHEN Product = 'Grapes' THEN SalesAmount ELSE 0 END) Grapes,
SUM( CASE WHEN Product = 'Melons' THEN SalesAmount ELSE 0 END) Melons,
SUM( CASE WHEN Product = 'Beans' THEN SalesAmount ELSE 0 END) Beans
FROM (
SELECT SalesPerson,
Product,
SUM( SalesAmount) SalesAmount
FROM names
GROUP BY SalesPerson,
Product) t
GROUP BY SalesPerson

Reference: http://www.sqlservercentral.com/articles/T-SQL/63681/



Luis C.
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?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1590111
Posted Tuesday, July 8, 2014 8:33 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, August 29, 2014 2:24 PM
Points: 14, Visits: 62
This works also from the article you attached... again, Thanks!

SELECT SalesPerson, COALESCE([Oranges],0) AS Oranges,
COALESCE([Pickles],0) AS Pickles,
COALESCE([Bananas],0) AS Bananas,
COALESCE([Apples],0) AS Apples,
COALESCE([Grapes],0) AS Grapes,
COALESCE([Melons],0) AS Melons,
COALESCE([Beans],0) AS Beans

FROM
(SELECT SalesPerson, Product, SalesAmount
FROM names) ps
PIVOT (SUM(SalesAmount)
FOR Product IN ([Oranges], [Pickles], [Bananas], [Apples], [Grapes], [Melons], [Beans])
) AS pvt


SALESPERSON ORANGES PICKLES BANANAS APPLES GRAPES MELONS BEANS
Bob 330 280 400 250 0 200 125
Ed 160 240 80 175 175 185 320
Jim 130 160 370 185 160 0 0
Sid 185 160 0 75 130 370 140
Sue 0 310 820 780 315 220 185
Post #1590393
Posted Tuesday, July 8, 2014 9:08 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, August 29, 2014 2:24 PM
Points: 14, Visits: 62
Of course to further take advantage of the above we could add a totalling function:

SELECT SalesPerson, COALESCE([Oranges],0) AS Oranges,
COALESCE([Pickles],0) AS Pickles,
COALESCE([Bananas],0) AS Bananas,
COALESCE([Apples],0) AS Apples,
COALESCE([Grapes],0) AS Grapes,
COALESCE([Melons],0) AS Melons,
COALESCE([Beans],0) AS Beans,
COALESCE([Oranges],0) +
COALESCE([Pickles],0) +
COALESCE([Bananas],0) +
COALESCE([Apples],0) +
COALESCE([Grapes],0) +
COALESCE([Melons],0) +
COALESCE([Beans],0) AS Total
FROM
(SELECT SalesPerson, Product, SalesAmount
FROM names) ps
PIVOT (SUM(SalesAmount)
FOR Product IN ([Oranges], [Pickles], [Bananas], [Apples], [Grapes], [Melons], [Beans])
) AS pvt
Post #1590408
Posted Tuesday, July 8, 2014 9:30 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 7:07 PM
Points: 3,559, Visits: 7,679
That's the beauty of cross tabs. When you need more information than a simple pivot will give, the cross tabs approach will be more flexible and cross tabs shows more performance improvement. You could add counts or other without a new pivot, just add the corresponding columns.

SELECT SalesPerson,
SUM( CASE WHEN Product = 'Oranges' THEN SalesAmount ELSE 0 END) Oranges,
SUM( CASE WHEN Product = 'Oranges' THEN SalesCount ELSE 0 END) OrangesCnt,
SUM( CASE WHEN Product = 'Pickles' THEN SalesAmount ELSE 0 END) Pickles,
SUM( CASE WHEN Product = 'Pickles' THEN SalesCount ELSE 0 END) PicklesCnt,
SUM( CASE WHEN Product = 'Bananas' THEN SalesAmount ELSE 0 END) Bananas,
SUM( CASE WHEN Product = 'Bananas' THEN SalesCount ELSE 0 END) BananasCnt,
SUM( CASE WHEN Product = 'Apples' THEN SalesAmount ELSE 0 END) Apples,
SUM( CASE WHEN Product = 'Apples' THEN SalesCount ELSE 0 END) ApplesCnt,
SUM( CASE WHEN Product = 'Grapes' THEN SalesAmount ELSE 0 END) Grapes,
SUM( CASE WHEN Product = 'Grapes' THEN SalesCount ELSE 0 END) GrapesCnt,
SUM( CASE WHEN Product = 'Melons' THEN SalesAmount ELSE 0 END) Melons,
SUM( CASE WHEN Product = 'Melons' THEN SalesCount ELSE 0 END) MelonsCnt,
SUM( CASE WHEN Product = 'Beans' THEN SalesAmount ELSE 0 END) Beans,
SUM( CASE WHEN Product = 'Beans' THEN SalesCount ELSE 0 END) BeansCnt,
SUM( SalesAmount) Total,
SUM( SalesCount) TotalCnt
FROM (
SELECT SalesPerson,
Product,
SUM( SalesAmount) SalesAmount,
COUNT( *) SalesCount
FROM names
GROUP BY SalesPerson,
Product) t
GROUP BY SalesPerson




Luis C.
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?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1590412
Posted Tuesday, July 8, 2014 1:10 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, August 29, 2014 2:24 PM
Points: 14, Visits: 62
Yes... I can see now where Cross Tabs are more versatile... e.g. finding averages like below (and I'm sure there's a better way to write this):

SELECT SalesPerson,
SUM( CASE WHEN Product = 'Oranges' THEN SalesAmount ELSE 0 END) Oranges,
SUM( CASE WHEN Product = 'Oranges' THEN (SalesAmount/SalesCount) ELSE 0 END) Oranges_Ave,
SUM( CASE WHEN Product = 'Pickles' THEN SalesAmount ELSE 0 END) Pickles,
SUM( CASE WHEN Product = 'Pickles' THEN (SalesAmount/SalesCount) ELSE 0 END) Pickles_Ave,
SUM( CASE WHEN Product = 'Bananas' THEN SalesAmount ELSE 0 END) Bananas,
SUM( CASE WHEN Product = 'Bananas' THEN (SalesAmount/SalesCount) ELSE 0 END) Bananas_Ave,
SUM( CASE WHEN Product = 'Apples' THEN SalesAmount ELSE 0 END) Apples,
SUM( CASE WHEN Product = 'Apples' THEN (SalesAmount/SalesCount) ELSE 0 END) Apples_Ave,
SUM( CASE WHEN Product = 'Grapes' THEN SalesAmount ELSE 0 END) Grapes,
SUM( CASE WHEN Product = 'Grapes' THEN (SalesAmount/SalesCount) ELSE 0 END) Grapes_Ave,
SUM( CASE WHEN Product = 'Melons' THEN SalesAmount ELSE 0 END) Melons,
SUM( CASE WHEN Product = 'Melons' THEN (SalesAmount/SalesCount) ELSE 0 END) Melons_Ave,
SUM( CASE WHEN Product = 'Beans' THEN SalesAmount ELSE 0 END) Beans,
SUM( CASE WHEN Product = 'Beans' THEN (SalesAmount/SalesCount) ELSE 0 END) Beans_Ave,
SUM( SalesAmount) Total,
SUM( SalesCount) TotalCnt
FROM (
SELECT SalesPerson,
Product,
SUM( SalesAmount) SalesAmount,
COUNT( *) SalesCount
FROM names
GROUP BY SalesPerson,
Product) t
GROUP BY SalesPerson
Post #1590479
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse