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 GROUP BY for time periods

Oracle Database Tips by Donald BurlesonJuly 9, 2015

Question:  I am trying to write a query that selects the records which are not within a 90-day period of each other beginning with the first date. That is only those records are selected which are more than 90 day apart from each other. So for the following data set I need to group the items by time period:

CLASS, ACTIONDATE
C1,    2/12/2007
C1,    6/1/2007
C1,    5/1/2009

I need to return the following records, grouped by time period of 90 days:

CLASS ACTIONDATE
C1,    2/12/2007
C1,    6/1/2007
C1,    5/1/2009

I tried this for grouping by periods but it did not work:

SELECT actiondate,
MIN(actiondate)
OVER
(
ORDER BY actiondate
RANGE BETWEEN INTERVAL '90' DAY PRECEDING AND CURRENT ROW
)
dt
FROM tbl

 How do I write a group by clause for long time periods?


Answer: (by Laurent Schneider):  There are many ways to do a group by for time periods, namely (partition by, dimension) and a hierarchical SQL query for grouping by time periods.  There is probably more than one way to grouping by time periods in SQL, but I tried this SQL with the model clause.  For other methods for time period grouping, see my book: Advanced Oracle SQL Programming

select class,to_char(d2,'FMMM/DD/YYYY')
from (
select *
from lsc_t
model
partition by (class)
dimension by (row_number() over (partition by class order by actiondate) r)
measures (actiondate d1, to_date(null) d2)
(

d2[0]=d1[1],
d1[0]=d1[1],
d2[r>0] order by r=case when min(d1)[R>CV()]>max(d2)[any]+90 then min(d1)[R>CV()] end
)
)  

where d2 is not null
order by class,d2;

CL TO_CHAR(D2
-- ----------
C1 2/12/2007
C1 6/1/2007  
C1 5/1/2009  


I have a complete chapter on using MODEL in my book Advanced Oracle SQL Programming for grouping by time periods.  You can also do a group by for a time period with a hierarchical query:

select class, actiondate from (
select class, actiondate, min(rownum) over (partition by class)-1 m, level l, rownum r
from lsc_t
connect by actiondate > prior actiondate + 90
and class=prior class
)

where r=l+m;


CL ACTIONDATE
-- ----------
C1 02/12/2007
C1 06/01/2007
C1 05/01/2009



 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

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.