Question: I need to calculate avg of data
for every time interval between start date and end date using a
TIMESTAMP column.
I want the aggregated data for every 30 minutes. If I use a
"group by" on 30, it will group only on that same time not at the
interval level.
I want to write a SQL to "group by" for continuous timestamp
intervals. How can I "group by" like this for a timestamp?
Answer: I
would look at the numtoyminterval built-in function. For working
examples of advanced "group by", you can download working examples
from the Laurent Schneider book code depot on
Advanced SQL Programming.
SQL expert and Rampant author, Laurent Schneider provides the
following:
I tried to provide a generic answer that will cover any kind of
interval, either in seconds or in months:
create table t as
select
systimestamp-numtodsinterval(dbms_random.value*365,'DAY') ts,
dbms_random.value
from dual connect by level<=100000;
Interval in year/month:
var intervalmonth number;
-- 3 months period
exec :intervalmonth := 3;
Code:
select
timestamp '2000-01-01
00:00:00.00' -
numtoyminterval(
trunc(
(
extract(year
from (timestamp '2000-01-01 00:00:00.00' - ts) year(4)
to month)*12+
extract(month from (timestamp
'2000-01-01 00:00:00.00' - ts) year(4)
to month)+1
)/:intervalmonth
)*:intervalmonth,
'MONTH'
)
from_ts,
timestamp '2000-01-01
00:00:00.00' -
numtoyminterval(
trunc(
(
extract(year
from (timestamp '2000-01-01 00:00:00.00' - ts) year(4) to
month)*12+
extract(month from (timestamp
'2000-01-01 00:00:00.00' - ts) year(4) to
month)+1
)/:intervalmonth-1
)*:intervalmonth,
'MONTH'
)
-
interval '0.000001' second to_ts,
avg(value),
count(*)
from t group by
timestamp '2000-01-01 00:00:00.00' -
numtoyminterval(
trunc(
(
extract(year
from (timestamp '2000-01-01 00:00:00.00' - ts) year(4) to
month)*12+
extract(month from (timestamp
'2000-01-01 00:00:00.00' - ts) year(4) to
month)+1
)/:intervalmonth
)*:intervalmonth,
'MONTH'
),
timestamp
'2000-01-01 00:00:00.00' -
numtoyminterval(
trunc(
(
extract(year
from (timestamp '2000-01-01 00:00:00.00' - ts) year(4) to
month)*12+
extract(month from (timestamp
'2000-01-01 00:00:00.00' - ts) year(4) to
month)+1
)/:intervalmonth-1
)*:intervalmonth,
'MONTH'
)
-
interval '0.000001' second
order by 1;
FROM_TS
TO_TS AVG(VALUE) COUNT(*)
--------------------------- --------------------------- ----------
----------
2009-10-01 00:00:00.000000 2009-12-31
23:59:59.999999 .505167046 12502
2010-01-01
00:00:00.000000 2010-03-31 23:59:59.999999 .500472614 24474
2010-04-01 00:00:00.000000 2010-06-30
23:59:59.999999 .504024801 25232
2010-07-01
00:00:00.000000 2010-09-30 23:59:59.999999 .500543903 25106
2010-10-01 00:00:00.000000 2010-12-31
23:59:59.999999 .501932508 12686
Interval in day/second:
var intervalsecond number;
-- 30 minutes period
exec :intervalsecond := 1800;
Code:
select
timestamp '2000-01-01
00:00:00.00' -
numtodsinterval(
trunc(
(
extract(day
from (timestamp '2000-01-01 00:00:00.00' - ts) day(9) to
second)*86400+
extract(hour from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)*3600+
extract(minute from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)*60+
extract(second from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)
)/:intervalsecond
)*:intervalsecond,
'SECOND'
)
from_ts,
timestamp '2000-01-01 00:00:00.00' -
numtodsinterval(
trunc(
(
extract(day
from (timestamp '2000-01-01 00:00:00.00' - ts) day(9) to
second)*86400+
extract(hour from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)*3600+
extract(minute from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)*60+
extract(second from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)
)/:intervalsecond-1
)*:intervalsecond,
'SECOND'
) -
interval
'0.000001' second to_ts
,avg(value),count(*)
from
t
where ts > systimestamp - interval '2' hour
group
by timestamp '2000-01-01 00:00:00.00' -
numtodsinterval(
trunc(
(
extract(day
from (timestamp '2000-01-01 00:00:00.00' - ts) day(9) to
second)*86400+
extract(hour from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)*3600+
extract(minute from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)*60+
extract(second from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)
)/:intervalsecond
)*:intervalsecond,
'SECOND'
),
timestamp
'2000-01-01 00:00:00.00' -
numtodsinterval(
trunc(
(
extract(day
from (timestamp '2000-01-01 00:00:00.00' - ts) day(9) to
second)*86400+
extract(hour from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)*3600+
extract(minute from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)*60+
extract(second from (timestamp
'2000-01-01 00:00:00.00' - ts) day(9) to
second)
)/:intervalsecond-1
)*:intervalsecond,
'SECOND'
) -
interval
'0.000001' second
order by 1;
FROM_TS TO_TS AVG(VALUE)
COUNT(*)
--------------------------- ---------------------------
---------- ----------
2010-12-01 09:00:00.000000 2010-12-01
09:29:59.999999 .459474639 10
2010-12-01
09:30:00.000000 2010-12-01 09:59:59.999999 .498984407 3
2010-12-01 10:00:00.000000 2010-12-01
10:29:59.999999 .552010521 4
2010-12-01
10:30:00.000000 2010-12-01 10:59:59.999999 .35517415 6
|
|
Get the Complete
Oracle SQL Tuning Information
The landmark book
"Advanced Oracle
SQL Tuning The Definitive Reference" is
filled with valuable information on Oracle SQL Tuning.
This book includes scripts and tools to hypercharge Oracle 11g
performance and you can
buy it
for 30% off directly from the publisher.
|