Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

SQL Grouping by Timestamp

Expert Oracle Database Tips by Donald BurlesonDecember 1, 2015

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.

 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster