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


trying to add third grouping set to return average aggregate


trying to add third grouping set to return average aggregate

Author
Message
KoldCoffee
KoldCoffee
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1597 Visits: 1905
Hi, i'm building a query to return metrics that will drive 3 seperate pivot tables showing
1. Total count of LineItems per D_Type each month
2. Total count of LineItems per Status each month
3. Avg count of LineItems per Invoice each month

I am able to get the first two, but having hard time with the 3rd.

Here's some representative ddl

create table Remediation
(Invoice nvarchar(10), D_Type nvarchar(20), Status nvarchar(20), RemediationDate datetime);

insert into Remediation values
--this will create data for Jan, 2014
('501', 'Recycle', 'Pass', getdate()-30),
('501', 'Reuse', 'Pass', getdate()-30),
('501', 'Remarket', 'Fail', getdate()-30),
('501', 'Recycle', 'Fail', getdate()-30),
('502', 'Recycle', 'Pass', getdate()-30),
('502', 'Reuse', 'Pass', getdate()-30),
('502', 'Reuse', 'Fail', getdate()-30),
('502', 'Reuse', 'Fail', getdate()-30),
('502', 'Reuse', 'Fail', getdate()-30),
('502', 'Remarket', 'Pass', getdate()-30),
('502', 'Remarket', 'Pass', getdate()-30),
('502', 'Remarket', 'Pass', getdate()-30),
--this will create data for Feb, 2014
('503', 'Recycle', 'Pass', getdate()),
('503', 'Reuse', 'Fail', getdate()),
('503', 'Remarket', 'Fail', getdate()),
('504', 'Recycle', 'Pass', getdate()),
('504', 'Recycle', 'Pass', getdate()),
('504', 'Recycle', 'Pass', getdate());




my query so far returns only first 2 metrics

;with cte as
(
select
[Invoice],
[D_Type],
[Status],
left(datename(month, [RemediationDate]), 3) as Mo,
year([RemediationDate]) as Yr
From
[dbo].[Remediation]
)
select D_Type, Status, Yr, Mo, count(*) as #LineItems
from cte
group by grouping sets
(
(D_Type, Yr, Mo),
(D_Type, Yr),
(Status, Yr, Mo),
(Status, Yr)
);



how to add the average metric to this query?
matak
matak
SSC-Addicted
SSC-Addicted (453 reputation)SSC-Addicted (453 reputation)SSC-Addicted (453 reputation)SSC-Addicted (453 reputation)SSC-Addicted (453 reputation)SSC-Addicted (453 reputation)SSC-Addicted (453 reputation)SSC-Addicted (453 reputation)

Group: General Forum Members
Points: 453 Visits: 3948
Really not sure if this is what you are after. (No sample results so i cant be sure)

;with cte2 as
(
select
[Invoice],
[D_Type],
[Status],
left(datename(month, [RemediationDate]), 3) as Mo,
year([RemediationDate]) as Yr
From
#Remediation
),
cte3 as (
select D_Type, Status, Yr, Mo, count(*) as #LineItems
from cte2
group by grouping sets
(
(D_Type, Yr, Mo),
(D_Type, Yr),
(Status, Yr, Mo),
(Status, Yr)
)
)
select *, AVG(#LineItems) over (partition by D_Type, yr, mo)
from cte3


Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)

Group: General Forum Members
Points: 90958 Visits: 41151
A classic CROSSTAB makes short work of this as a single "pivot" table. Please see the following article on what a CROSSTAB IS and how it works.
http://www.sqlservercentral.com/articles/T-SQL/63681/


SELECT Month = SUBSTRING(CONVERT(CHAR(30),DATEADD(mm,DATEDIFF(mm,0,RemediationDate),0),113),4,8)
,[RecycleCount] = SUM(CASE WHEN D_Type = 'Recycle' THEN 1 ELSE 0 END)
,[ReuseCount] = SUM(CASE WHEN D_Type = 'Reuse' THEN 1 ELSE 0 END)
,[RemarketCount] = SUM(CASE WHEN D_Type = 'Remarket' THEN 1 ELSE 0 END)
,[PassCount] = SUM(CASE WHEN Status = 'Pass' THEN 1 ELSE 0 END)
,[FailCount] = SUM(CASE WHEN Status = 'Fail' THEN 1 ELSE 0 END)
,[TotalLineItems] = COUNT(*)
,[TotalInvoices] = COUNT(DISTINCT Invoice)
,[AvgLineItemsPerInvoice] = (COUNT(*)+0.0)/COUNT(DISTINCT Invoice)
FROM dbo.Remediation
GROUP BY DATEDIFF(mm,0,RemediationDate)
ORDER BY DATEDIFF(mm,0,RemediationDate)
;




Here's the output using your test data...


Month RecycleCount ReuseCount RemarketCount PassCount FailCount TotalLineItems TotalInvoices AvgLineItemsPerInvoice
-------- ------------ ----------- ------------- ----------- ----------- -------------- ------------- ---------------------------------------
Jan 2014 3 5 4 7 5 12 2 6.000000000000
Feb 2014 4 1 1 4 2 6 2 3.000000000000

(2 row(s) affected)


--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
KoldCoffee
KoldCoffee
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1597 Visits: 1905
Do you mind telling me if I could have added something to my existing query to get avg too?
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)

Group: General Forum Members
Points: 90958 Visits: 41151
KoldCoffee (2/17/2014)
Do you mind telling me if I could have added something to my existing query to get avg too?


To be honest, I've never had to use GROUPING SETS before and would have to read up on them to answer that question.

Is the problem that I "pivoted" all of the data and that your really need them in the "vertical" format of your original query?

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
polkadot
polkadot
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1138 Visits: 1114
thanks so much. Yes, that's the problem! I need to pull into excel and assign columns, rows, and let excel do pivoting on the units by month And Year independently. But the data here is already in presentation form... can you help?
polkadot and KoldKoffee are same.Discuss
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)

Group: General Forum Members
Points: 90958 Visits: 41151
Thank you very much for the explanation as to why you needed the data this way. I always wonder about these things.

I believe this may be what you asked for.

WITH
cte AS
(
SELECT Invoice
,D_Type
,Status
,Yr = YEAR(RemediationDate)
,Mo = LEFT(DATENAME(mm,RemediationDate),3)
,RemediationDate
FROM dbo.Remediation
)
SELECT D_Type
,Status
,Yr
,Mo
,#LineItems = COUNT(*)
,Avg#LineItemsPerInvoice = COUNT(*)/COUNT(DISTINCT Invoice)
FROM cte
GROUP BY GROUPING SETS
(
(D_Type, Yr, Mo)
,(D_Type, Yr)
,(Status, Yr, Mo)
,(Status, Yr)
)
;



That returns the following which contains all of the same data that your good code did plus the extra column you were looking for. The key was to understand that you couldn't use the AVG aggregate because you needed to count distinct invoices to get the average by invoice by month by year.


D_Type Status Yr Mo #LineItems Avg#LineItemsPerInvoice
-------------------- -------------------- ----------- ---- ----------- -----------------------
NULL Fail 2014 Feb 2 2
NULL Pass 2014 Feb 4 2
NULL Fail 2014 Jan 5 2
NULL Pass 2014 Jan 7 3
NULL Fail 2014 NULL 7 2
NULL Pass 2014 NULL 11 2
Recycle NULL 2014 Feb 4 2
Recycle NULL 2014 Jan 3 1
Remarket NULL 2014 Feb 1 1
Remarket NULL 2014 Jan 4 2
Reuse NULL 2014 Feb 1 1
Reuse NULL 2014 Jan 5 2
Recycle NULL 2014 NULL 7 1
Remarket NULL 2014 NULL 5 1
Reuse NULL 2014 NULL 6 2

(15 row(s) affected)


As a bit of a sidebar, I now know more about GROUPING SETS and concatenated ROLLUPs than I ever wanted to know.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
KoldCoffee
KoldCoffee
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1597 Visits: 1905
Jeff, it's not quite there yet. Definitely, the problem is that I need average # of lineItems per distinct Invoice.
So, for Jan 2014, where there are12 lineitems spread over 2 distinct invoices, the average is 6. For Feb 2014 there are 6 lineitems spread over 2 distinct invoices, the average is 3. Year totals will be 18 lineitems/4 dstinct invoices=4.5 avg number of lineitems per invoice.
IMO, results should look like this:

SELECT 'D_Type', 'Status', 'Yr', 'Mo', '#LineItems', 'Avg#LineItemsPerInvoice' UNION ALL
SELECT NULL, 'Fail', '2014', 'Feb', '2', '3' UNION ALL
SELECT NULL, 'Fail', '2014', 'Jan', '5', '6' UNION ALL
SELECT NULL, 'Fail', '2014', NULL, '7', '3' UNION ALL
SELECT NULL, 'Pass', '2014', 'Feb', '4', '3' UNION ALL
SELECT NULL, 'Pass', '2014', 'Jan', '7', '6' UNION ALL
SELECT NULL, 'Pass', '2014', NULL, '11', '4.5' UNION ALL
SELECT 'Recycle', NULL, '2014', 'Feb', '4', '3' UNION ALL
SELECT 'Recycle', NULL, '2014', 'Jan', '3', '6' UNION ALL
SELECT 'Recycle', NULL, '2014', NULL, '7', '4.5' UNION ALL
SELECT 'Remarket', NULL, '2014', 'Feb', '1', '3' UNION ALL
SELECT 'Remarket', NULL, '2014', 'Jan', '4', '6' UNION ALL
SELECT 'Remarket', NULL, '2014', NULL, '5', '4.5' UNION ALL
SELECT 'Reuse', NULL, '2014', NULL, '5', '4.5' UNION ALL
SELECT 'Reuse', NULL, '2014', 'Feb', '1', '3' UNION ALL
SELECT 'Reuse', NULL, '2014', 'Jan', '5', '6'



The problem I'm having is that distinct is disallowed with the Over() clause so I can't partition like follows:

WITH
cte AS
(
SELECT Invoice
,D_Type
,Status
,Yr = YEAR(RemediationDate)
,Mo = LEFT(DATENAME(mm,RemediationDate),3)
,RemediationDate
FROM dbo.Remediation
)
SELECT D_Type
,Status
,Yr
,Mo
,#LineItems = COUNT(*)
,Avg#LineItemsPerInvoice = COUNT(*)/COUNT(DISTINCT Invoice) over (partition by yr, mo)
FROM cte
GROUP BY GROUPING SETS
(
(D_Type, Yr, Mo)
,(D_Type, Yr)
,(Status, Yr, Mo)
,(Status, Yr)
)
;




exact error is:
Msg 10759, Level 15, State 1, Line 17
Use of DISTINCT is not allowed with the OVER clause.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)SSC Guru (90K reputation)

Group: General Forum Members
Points: 90958 Visits: 41151
The real problem is the GROUPING SETS. The averages are computed based on the grouping. I'll have to think about this some other time. It's 02:10 here and I've gotta get some shuteye.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
KoldCoffee
KoldCoffee
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1597 Visits: 1905
and I always thought you were in Australia. Thanks Jeff, I'm kinda (small kinda) glad it stumped you. I'm using the wrong tool for the task, it sounds like.
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