Oracle數(shù)據(jù)庫(kù)按時(shí)間進(jìn)行分組統(tǒng)計(jì)數(shù)據(jù)的方法
Oracle按不同時(shí)間分組統(tǒng)計(jì)的sql
如下表table1:
日期(exportDate) 數(shù)量(amount) -------------- ----------- 14-2月 -08 20 10-3月 -08 2 14-4月 -08 6 14-6月 -08 75 24-10月-09 23 14-11月-09 45 04-8月 -10 5 04-9月 -10 44 04-10月-10 88
注意:為了顯示更直觀,如下查詢已皆按相應(yīng)分組排序
1.按年份分組
select to_char(exportDate,'yyyy'),sum(amount) from table1 group by to_char(exportDate,'yyyy');
年份 數(shù)量 ----------------------------- 2009 68 2010 137 2008 103
2.按月份分組
select to_char(exportDate,'yyyy-mm'),sum(amount) from table1 group by to_char(exportDate,'yyyy-mm') order by to_char(exportDate,'yyyy-mm');
月份 數(shù)量 ----------------------------- 2008-02 20 2008-03 2 2008-04 6 2008-06 75 2009-10 23 2009-11 45 2010-08 5 2010-09 44 2010-10 88
3.按季度分組
select to_char(exportDate,'yyyy-Q'),sum(amount) from table1 group by to_char(exportDate,'yyyy-Q') order by to_char(exportDate,'yyyy-Q');
季度 數(shù)量 ------------------------------ 2008-1 22 2008-2 81 2009-4 68 2010-3 49 2010-4 88
4.按周分組
select to_char(exportDate,'yyyy-IW'),sum(amount) from table1 group by to_char(exportDate,'yyyy-IW') order by to_char(exportDate,'yyyy-IW');
周 數(shù)量 ------------------------------ 2008-07 20 2008-11 2 2008-16 6 2008-24 75 2009-43 23 2009-46 45 2010-31 5 2010-35 44 2010-40 88
PS:Oracle按時(shí)間段分組統(tǒng)計(jì)
想要按時(shí)間段分組查詢,首先要了解level,connect by,oracle時(shí)間的加減.
關(guān)于level這里不多說(shuō),我只寫出一個(gè)查詢語(yǔ)句:
----level 是一個(gè)偽例 select level from dual connect by level <=10 ---結(jié)果: 1 2 3 4 5 6 7 8 9 10
oracle時(shí)間的加減看看試一下以下sql語(yǔ)句就會(huì)知道:
select sysdate -1 from dual ----結(jié)果減一天,也就24小時(shí) select sysdate-(1/2) from dual -----結(jié)果減去半天,也就12小時(shí) select sysdate-(1/24) from dual -----結(jié)果減去1 小時(shí) select sysdate-((1/24)/12) from dual ----結(jié)果減去5分鐘 select sydate-(level-1) from dual connect by level<=10 ---結(jié)果是10間隔1天的時(shí)間
下面是本次例子:
select dt, count(satisfy_degree) as num from T_DEMO i , (select sysdate - (level-1) * 2 dt from dual connect by level <= 10) d where i.satisfy_degree='satisfy_1' and i.insert_time<dt and i.insert_time> d.dt-2 group by d.dt
例子中的sysdate - (level-1) * 2得到的是一個(gè)間隔是2天的時(shí)間
group by d.dt 也就是兩天的時(shí)間間隔分組查詢
自己實(shí)現(xiàn)例子:
create table A_HY_LOCATE1 ( MOBILE_NO VARCHAR2(32), LOCATE_TYPE NUMBER(4), AREA_NO VARCHAR2(32), CREATED_TIME DATE, AREA_NAME VARCHAR2(512), );
select (sysdate-13)-(level-1)/4 from dual connect by level<=34 --從第一條時(shí)間記錄開(kāi)始(sysdate-13)為表中的最早的日期,“34”出現(xiàn)的分組數(shù)(一天按每六個(gè)小時(shí)分組 就應(yīng)該為4)
一下是按照每6個(gè)小時(shí)分組
select mobile_no,area_name,max(created_time ),dt, count(*) as num from a_hy_locate1 i , (select (sysdate-13)-(level-1)/4 dt from dual connect by level <= 34) d where i.locate_type = 1 and i.created_time<dt and i.created_time> d.dt-1/4 group by mobile_no,area_name,d.dt
另外一個(gè)方法:
--按六小時(shí)分組 select trunc(to_number(to_char(created_time, 'hh24')) / 6),count(*) from t_test where created_time > trunc(sysdate - 40) group by trunc(to_number(to_char(created_time, 'hh24')) / 6) --按12小時(shí)分組 select trunc(to_number(to_char(created_time, 'hh24')) / 6),count(*) from t_test where created_time > trunc(sysdate - 40) group by trunc(to_number(to_char(created_time, 'hh24')) / 6)
相關(guān)文章
ORACLE 11g從 11.2.0.1升級(jí)到11.2.0.4 詳細(xì)實(shí)戰(zhàn)教程
這篇文章主要介紹了ORACLE 11g從 11.2.0.1升級(jí)到11.2.0.4 詳細(xì)實(shí)戰(zhàn)教程,非常不錯(cuò),具有參考借鑒價(jià)值,需要的朋友可以參考下2017-03-03Oracle使用MyBatis中RowBounds實(shí)現(xiàn)分頁(yè)查詢功能
這篇文章主要介紹了Oracle使用MyBatis中RowBounds實(shí)現(xiàn)分頁(yè)查詢 ,本文通過(guò)實(shí)例代碼給大家介紹的非常詳細(xì),具有一定的參考借鑒價(jià)值,需要的朋友可以參考下2019-07-07