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


Get sum of averages - a challenge


Get sum of averages - a challenge

Author
Message
Ken Davis
Ken Davis
SSC Eights!
SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)

Group: General Forum Members
Points: 909 Visits: 491
I have a need for a query that groups data, returns averages for the groups, but also sums those averages. This has been stumping me...

A simplified version of the table is
CREATE TABLE table_1 (Curr_date DATE, Action CHAR(15), Duration FLOAT)

Data is like
INSERT Table_1 VALUES ('2013-03-29','SignOn',1000.1234);
INSERT Table_1 VALUES ('2013-03-29','GetBal',450.1234);
INSERT Table_1 VALUES ('2013-03-29','SignOn',900.1234);
INSERT Table_1 VALUES ('2013-03-29','GetBal',300.1234);
INSERT Table_1 VALUES ('2013-03-29','SignOn',1100.1234);
INSERT Table_1 VALUES ('2013-03-29','GetBal',475.1234);
INSERT Table_1 VALUES ('2013-03-29','SignOn',950.1234);
INSERT Table_1 VALUES ('2013-03-29','GetBal',320.1234);
INSERT Table_1 VALUES ('2013-03-29','SignOn',800.1234);

I can get the average action durations like this
SELECT Curr_date, Action, AVG(Duration)/1000 as Avg_Duration
FROM Table_1
WHERE Curr_date = CAST(GETDATE() as DATE)
GROUP BY Curr_date, Action

Curr_date Action Avg_Duration
2013-03-29 GetBal 0.3863734
2013-03-29 SignOn 0.9501234


But I also need to sum those averages for both actions together. So for SignOn and GetBal together the sum is about 1.34. Anyone have any good suggestions for that? Thanks!
Sean Lange
Sean Lange
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60136 Visits: 17951
Not totally sure how you want the output but this should at least get you started.


;with MyAverage as
(
SELECT Curr_date, Action, AVG(Duration)/1000 as Avg_Duration
FROM Table_1
WHERE Curr_date = CAST(GETDATE() as DATE)
GROUP BY Curr_date, Action
)

select Curr_date, Action, Avg_Duration, (select sum(AVG_Duration) from MyAverage) as SummedAverage
from MyAverage



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Ken Davis
Ken Davis
SSC Eights!
SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)

Group: General Forum Members
Points: 909 Visits: 491
That's nice and elegant. Thanks!

Starting a sql statement with WITH is new to me. I will have to look into that closer but it works great.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60136 Visits: 17951
Ken Davis (3/29/2013)
That's nice and elegant. Thanks!

Starting a sql statement with WITH is new to me. I will have to look into that closer but it works great.


It is a common table expression or CTE. You should certainly read up on them as they are quite useful.

http://msdn.microsoft.com/en-us/library/ms190766%28v=sql.105%29.aspx

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
ScottPletcher
ScottPletcher
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18891 Visits: 7406
Until you get to SQL 2012, you also have the "quick-and-dirty" version of that, using COMPUTE:


SELECT Curr_date, Action, AVG(Duration)/1000 as Avg_Duration
FROM Table_1
WHERE Curr_date = CAST(GETDATE() as DATE)
GROUP BY Curr_date, Action
-- added AVG just to show that multiple COMPUTE functions can be specified :-)
COMPUTE SUM(AVG(Duration)/1000), AVG(AVG(Duration)/1000)



It's sometimes easier just to slap on a COMPUTE than to rejigger the query ... and, as so often, in this case it avoids another full scan of the table (COMPUTE's a fun cheat, it died too young!).

Note that the COMPUTEd value(s) are a separate result set, and do not have any column heading other than the function used to create them, i.e., column is named "sum" or "avg" or "count" or whatever.

SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60136 Visits: 17951
ScottPletcher (3/29/2013)
Until you get to SQL 2012, you also have the "quick-and-dirty" version of that, using COMPUTE:


SELECT Curr_date, Action, AVG(Duration)/1000 as Avg_Duration
FROM Table_1
WHERE Curr_date = CAST(GETDATE() as DATE)
GROUP BY Curr_date, Action
-- added AVG just to show that multiple COMPUTE functions can be specified :-)
COMPUTE SUM(AVG(Duration)/1000), AVG(AVG(Duration)/1000)



It's sometimes easier just to slap on a COMPUTE than to rejigger the query ... and, as so often, in this case it avoids another full scan of the table (COMPUTE's a fun cheat, it died too young!).

Note that the COMPUTEd value(s) are a separate result set, and do not have any column heading other than the function used to create them, i.e., column is named "sum" or "avg" or "count" or whatever.


I never even think about COMPUTE. I have seen it before but never really used it. Thanks for the reminder of that long forgotten and neglected feature.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Ken Davis
Ken Davis
SSC Eights!
SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)

Group: General Forum Members
Points: 909 Visits: 491
I want to push my luck and add one more wrinkle. Say the Curr_Date column is DATETIME and the output of the MyAverage CTE express is grouped by HourOfDay like this:

Curr_date HourOfDay Action Avg_Duration
2013-03-29 07 SignOn 0.950123
2013-03-29 07 GetBal 0.386373
2013-03-29 08 SignOn 0.891234
2013-03-29 08 GetlBal 0.423432
2013-03-29 09 SignOn 0.912342
2013-03-29 09 GetBal 0.372323

And I need to sum those average durations within each hour. So the output would look like:

Curr_date HourOfDay Action Avg_Duration SummedAverage
2013-03-29 07 SignOn 0.950123 1.336496
2013-03-29 07 GetBal 0.386373 1.336496
2013-03-29 08 SignOn 0.891234 1.314666
2013-03-29 08 GetlBal 0.423432 1.314666
2013-03-29 09 SignOn 0.912342 1.284665
2013-03-29 09 GetBal 0.372323 1.284665

Any tricks you can show me there?
Sean Lange
Sean Lange
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60136 Visits: 17951
Ken Davis (3/29/2013)
I want to push my luck and add one more wrinkle. Say the Curr_Date column is DATETIME and the output of the MyAverage CTE express is grouped by HourOfDay like this:

Curr_date HourOfDay Action Avg_Duration
2013-03-29 07 SignOn 0.950123
2013-03-29 07 GetBal 0.386373
2013-03-29 08 SignOn 0.891234
2013-03-29 08 GetlBal 0.423432
2013-03-29 09 SignOn 0.912342
2013-03-29 09 GetBal 0.372323

And I need to sum those average durations within each hour. So the output would look like:

Curr_date HourOfDay Action Avg_Duration SummedAverage
2013-03-29 07 SignOn 0.950123 1.336496
2013-03-29 07 GetBal 0.386373 1.336496
2013-03-29 08 SignOn 0.891234 1.314666
2013-03-29 08 GetlBal 0.423432 1.314666
2013-03-29 09 SignOn 0.912342 1.284665
2013-03-29 09 GetBal 0.372323 1.284665

Any tricks you can show me there?


Can you post ALL of the requirements? Also it would be helpful if you could post your data in a consumable format. Notice in my first post you don't have to do any extra work to get data because I posted it.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Ken Davis
Ken Davis
SSC Eights!
SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)SSC Eights! (909 reputation)

Group: General Forum Members
Points: 909 Visits: 491
Understood. I won't add any more requirements.

The table:

CREATE TABLE table_1(
[Curr_date] [datetime] NULL,
[Action] [char](15) NULL,
[Duration] [float] NULL
)


Some data:

INSERT INTO Table_1
(Curr_date,Action,Duration)
SELECT 'Mar 29 2013 7:05AM','SignOn ','1000.12' UNION ALL
SELECT 'Mar 29 2013 7:30AM','GetBal ','450.123' UNION ALL
SELECT 'Mar 29 2013 8:15AM','SignOn ','900.123' UNION ALL
SELECT 'Mar 29 2013 8:32AM','GetBal ','300.123' UNION ALL
SELECT 'Mar 29 2013 8:45AM','SignOn ','1100.12' UNION ALL
SELECT 'Mar 29 2013 9:10AM','GetBal ','475.123' UNION ALL
SELECT 'Mar 29 2013 9:12AM','SignOn ','950.123' UNION ALL
SELECT 'Mar 29 2013 9:38AM','GetBal ','320.123' UNION ALL
SELECT 'Mar 29 2013 9:49AM','SignOn ','800.123'


Here is what I am trying.

;with MyAverage as
(
SELECT CAST(Curr_date as DATE) as CurrentDate, DATEPART(hour, Curr_date) as HourOfDay, Action, AVG(Duration)/1000 as Avg_Duration
FROM Table_1
WHERE CAST(Curr_date as Date) = CAST(GETDATE() as DATE)
GROUP BY DATEPART(hour, Curr_date), Action, Curr_date
)
SELECT CurrentDate, HourOfDay, Action, Avg_Duration, (SELECT sum(AVG_Duration) FROM MyAverage) as SummedAverage
FROM MyAverage


You can see what that returns. My goal is to get 6 rows, 2 for each hour, with the SignOn and GetBal averages added together. So with this data SummedAverage will be about 1.45 for the 7:00 hour.
Thanks for your time.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)SSC Guru (60K reputation)

Group: General Forum Members
Points: 60136 Visits: 17951
Thanks having ddl and data makes this a lot easier to deal with. I think you want something like this.


;with MyNewAverage as
(
select Action, Duration, Curr_date, DATEPART(hour, Curr_date) as HourOfDay, AVG(Duration)/1000 as Avg_Duration
from table_1
group by Action, Duration, Curr_date, DATEPART(hour, Curr_date)
)
SELECT HourOfDay, Action, sum(Avg_Duration), (SELECT sum(AVG_Duration) FROM MyNewAverage where DATEPART(hour, cast(Curr_date as datetime)) = m.HourOfDay) as SummedAverage
FROM MyNewAverage m
group by HourOfDay, Action
order by HourOfDay, Action



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
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