July 13, 2016 at 1:51 pm
the nulls come from not having data for a certain year for a customer.
SELECT *
FROM (
SELECT DISTINCT cmoOrganizationID
,cmoName
,omlPartGroupID
,sum(omlExtendedPriceBase) AS total
,DATEPART(yyyy, ompOrderDate) AS Year_
FROM SalesOrders
LEFT OUTER JOIN SalesOrderLines ON omlSalesOrderID = salesorders.ompSalesOrderID
LEFT OUTER JOIN Organizations ON cmoOrganizationID = ompCustomerOrganizationID
LEFT OUTER JOIN OrganizationLocations ON cmoOrganizationID = cmlOrganizationID
AND cmlLocationID = ompShipLocationID
WHERE ompClosed = - 1
AND cmoOrganizationID IS NOT NULL
GROUP BY cmoOrganizationID
,cmoName
,ompOrderDate
,omlPartGroupID
) AS src
pivot(sum(total) FOR Year_ IN (
[2013]
,[2014]
,[2015]
,[2016]
)) piv
ORDER BY cmoOrganizationID
,cmoName
,omlPartGroupID
July 13, 2016 at 2:21 pm
Try this:
SELECT cmoOrganizationID
,cmoName
,omlPartGroupID
,sum(CASE WHEN Year_ = 2013 THEN omlExtendedPriceBase ELSE 0 END) AS [2013]
,sum(CASE WHEN Year_ = 2014 THEN omlExtendedPriceBase ELSE 0 END) AS [2014]
,sum(CASE WHEN Year_ = 2015 THEN omlExtendedPriceBase ELSE 0 END) AS [2015]
,sum(CASE WHEN Year_ = 2016 THEN omlExtendedPriceBase ELSE 0 END) AS [2016]
FROM (
SELECT cmoOrganizationID
,cmoName
,omlPartGroupID
,sum(omlExtendedPriceBase) AS total
,DATEPART(yyyy, ompOrderDate) AS Year_
FROM SalesOrders
LEFT OUTER JOIN SalesOrderLines ON omlSalesOrderID = salesorders.ompSalesOrderID
LEFT OUTER JOIN Organizations ON cmoOrganizationID = ompCustomerOrganizationID
LEFT OUTER JOIN OrganizationLocations ON cmoOrganizationID = cmlOrganizationID
AND cmlLocationID = ompShipLocationID
WHERE ompClosed = - 1
AND cmoOrganizationID IS NOT NULL
GROUP BY cmoOrganizationID
,cmoName
,omlPartGroupID
) AS src
GROUP BY cmoOrganizationID
,cmoName
,omlPartGroupID
ORDER BY cmoOrganizationID
,cmoName
,omlPartGroupID;
July 19, 2016 at 2:40 pm
If you want to display sum(omlExtendedPriceBase) as 0 if the value is null, use ISNULL(SUM(omlExtendedPriceBase),0).
SELECT *
FROM (
SELECT DISTINCT cmoOrganizationID
,cmoName
,omlPartGroupID
,ISNULL(sum(omlExtendedPriceBase),0) AS total
,DATEPART(yyyy, ompOrderDate) AS Year_
FROM SalesOrders
LEFT OUTER JOIN SalesOrderLines ON omlSalesOrderID = salesorders.ompSalesOrderID
LEFT OUTER JOIN Organizations ON cmoOrganizationID = ompCustomerOrganizationID
LEFT OUTER JOIN OrganizationLocations ON cmoOrganizationID = cmlOrganizationID
AND cmlLocationID = ompShipLocationID
WHERE ompClosed = - 1
AND cmoOrganizationID IS NOT NULL
GROUP BY cmoOrganizationID
,cmoName
,ompOrderDate
,omlPartGroupID
) AS src
pivot(sum(total) FOR Year_ IN (
[2013]
,[2014]
,[2015]
,[2016]
)) piv
ORDER BY cmoOrganizationID
,cmoName
,omlPartGroupID
July 19, 2016 at 6:59 pm
ocean3300 (7/19/2016)
If you want to display sum(omlExtendedPriceBase) as 0 if the value is null, use ISNULL(SUM(omlExtendedPriceBase),0).
That's one of the many reasons why I don't use PIVOT. A good ol' fashioned CROSSTAB, like what Luis used, will take care of that auto-magically. Please see the following URLs for why I personally never use PIVOT.
http://www.sqlservercentral.com/articles/T-SQL/63681/
http://www.sqlservercentral.com/articles/Crosstab/65048/
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply