database.sarang.net
UserID
Passwd
Database
DBMS
MySQL
PostgreSQL
Firebird
ㆍOracle
Informix
Sybase
MS-SQL
DB2
Cache
CUBRID
LDAP
ALTIBASE
Tibero
DB 문서들
스터디
Community
공지사항
자유게시판
구인|구직
DSN 갤러리
도움주신분들
Admin
운영게시판
최근게시물
Oracle Q&A 41492 게시물 읽기
No. 41492
rownum 구간 null row까지 전부 표현 가능한가요?
작성자
김기훈
작성일
2017-12-11 15:50
조회수
5,641

아래와 같이 하면 4건이 나옵니다. 총 rownum 구간은 14인데 4건에 아래는 null Row를 해서 총 Count(*)는 14건이 나오고 싶은데 방법이 없을까요?

밑에 29~~42 사이입니다.

SELECT * FROM (

SELECT ITEM_NAME,ITEM_ID , ITEM_VALUE, ROUND(WEEK_AVG,3) AS WEEK_AVG, ROUND(MONTH_AVG,3) AS MONTH_AVG, ROUND(YEAR_AVG,3) AS YEAR_AVG, ETC, CHARTGRAPH , ROWNUM AS RNUM FROM (

SELECT TRIM(ITEM_NAME) AS ITEM_NAME , TRIM(ITEM_ID) AS ITEM_ID , SUM(ITEM_VALUE) AS ITEM_VALUE, SUM(WEEK_AVG) AS WEEK_AVG, SUM(MONTH_AVG) AS MONTH_AVG, SUM(YEAR_AVG) AS YEAR_AVG, SUM(ETC) AS ETC, CHARTGRAPH FROM (

SELECT A.ITEM_NAME, 0 ITEM_VALUE, B.ITEM_ID, 0 AS WEEK_AVG, 0 AS MONTH_AVG, AVG(DECODE(ITEM_VALUE,-999,0,ITEM_VALUE)) AS YEAR_AVG, 0 ETC,'' AS CHARTGRAPH

FROM W_ITEMINFO_TB A ,

W_DAYDATA_TB B

WHERE A.ITEM_ID = B.ITEM_ID

AND B.ITEM_ID IN('W01','W66')

AND SUBSTR(B.MSR_DATE, 1,4) = TO_CHAR(SYSDATE ,'YYYY')

GROUP BY A.ITEM_NAME , B.ITEM_ID

UNION ALL

SELECT A.ITEM_NAME , 0 ITEM_VALUE , B.ITEM_ID , 0 AS WEEK_AVG , AVG(DECODE(ITEM_VALUE,-999,0,ITEM_VALUE)) AS MONTH_AVG , 0 AS YEAR_AVG ,0 ETC , '' AS CHARTGRAPH

FROM W_ITEMINFO_TB A ,

W_DAYDATA_TB B

WHERE A.ITEM_ID = B.ITEM_ID

AND B.ITEM_ID IN('W01','W66')

AND SUBSTR(B.MSR_DATE, 1,8) BETWEEN TO_CHAR(SYSDATE -31,'YYYYMMDD') AND TO_CHAR(SYSDATE ,'YYYYMMDD')

GROUP BY A.ITEM_NAME , B.ITEM_ID

UNION ALL

SELECT A.ITEM_NAME , 0 ITEM_VALUE , B.ITEM_ID , AVG(DECODE(ITEM_VALUE,-999,0,ITEM_VALUE)) AS WEEK_AVG , 0 AS MONTH_AVG , 0 AS YEAR_AVG , 0 ETC , '' AS CHARTGRAPH

FROM W_ITEMINFO_TB A ,

W_DAYDATA_TB B

WHERE A.ITEM_ID = B.ITEM_ID

AND B.ITEM_ID IN('W01','W66')

AND SUBSTR(B.MSR_DATE, 1,8) BETWEEN TO_CHAR(SYSDATE-7,'YYYYMMDD') AND TO_CHAR(SYSDATE,'YYYYMMDD')

GROUP BY A.ITEM_NAME, B.ITEM_ID

UNION ALL

SELECT A.ITEM_NAME , B.ITEM_VALUE , B.ITEM_ID , 0 AS WEEK_AVG , 0 AS MONTH_AVG , 0 AS YEAR_AVG , B.ETC , '' AS CHARTGRAPH

FROM W_ITEMINFO_TB A ,

W_DAYDATA_TB B

WHERE A.ITEM_ID = B.ITEM_ID

AND B.ITEM_ID IN('W01','W66')

AND SUBSTR(MSR_DATE, 1,8) = TO_CHAR(SYSDATE,'YYYYMMDD')

)

GROUP BY ITEM_NAME ,ITEM_ID ,CHARTGRAPH)

) A

, (select rownum from dual connect by rownum <= 14)

WHERE A.RNUM BETWEEN 29 AND 42

 

이 글에 대한 댓글이 총 2건 있습니다.

SELECT *
  FROM (-- 아우터 조인 기준 --
        SELECT (:page - 1) * 14 + LEVEL AS rnum
          FROM dual
         CONNECT BY ROWNUM <= 14
        )
  LEFT OUTER JOIN
       (-- 기존 쿼리 개선 --
        SELECT *
          FROM (SELECT item_id
                     , item_name
                     , SUM(DECODE(d, 1, item_value)) item_value
                     , AVG(DECODE(w, 1, v)) week_avg
                     , AVG(DECODE(m, 1, v)) month_avg
                     , AVG(v) year_avg
                     , SUM(DECODE(d, 1, etc)) etc
                     , '' chartgraph
                     , ROW_NUMBER() OVER(ORDER BY item_id) rnum
                  FROM (SELECT b.item_id
                             , a.item_name
                             , b.item_value
                             , b.etc
                             , DECODE(b.item_value, -999, 0, b.item_value) v
                             , CASE WHEN TO_CHAR(sysdate -  0, 'yyyymmdd')
                                                  <= b.msr_date THEN 1 END d
                             , CASE WHEN TO_CHAR(sysdate -  7, 'yyyymmdd')
                                                  <= b.msr_date THEN 1 END w
                             , CASE WHEN TO_CHAR(sysdate - 31, 'yyyymmdd')
                                                  <= b.msr_date THEN 1 END m
                          FROM w_iteminfo_tb a
                             , w_daydata_tb  b
                         WHERE a.item_id = b.item_id
                           AND b.item_id IN ('W01','W66')
                           AND b.msr_date > TO_CHAR(sysdate, 'yyyy')
                           AND b.msr_date < TO_CHAR(sysdate + 1, 'yyyymmdd')
                        )
                 GROUP BY item_id, item_name
                )
         WHERE rnum BETWEEN (:page - 1) * 14 + 1 AND :page * 14
        ) b
    ON a.rnum = b.rnum
 ORDER BY a.rnum
;

마농(manon94)님이 2017-12-12 08:50에 작성한 댓글입니다.

마농님은 도대체 어떤 분이신가요? 대한민국 쿼리 선생님이신가요?

 

이렇게까지 상세하게 해주셔서 너무 감사합니다. 고맙습니다. 마농님 

김기훈님이 2017-12-12 10:16에 작성한 댓글입니다. Edit
[Top]
No.
제목
작성자
작성일
조회
41495시작과 끝정보 시간계산 [7]
오라클초보
2017-12-14
5993
414949억건 업테이트와 인서트
엑소
2017-12-13
5694
41493오라클 복구 여부 확인좀 부탁드립니다. [1]
복구확인
2017-12-12
5422
41492rownum 구간 null row까지 전부 표현 가능한가요? [2]
김기훈
2017-12-11
5641
41490누적합계 구하는 쿼리 질문 드립니다. [1]
하하하하
2017-12-04
6277
41489샘플스키마 [1]
부글부글
2017-12-04
5324
41488연속된 건수 구하는 쿼리 문의 드립니다. [2]
꼬르
2017-11-29
5709
Valid XHTML 1.0!
All about the DATABASE... Copyleft 1999-2023 DSN, All rights reserved.
작업시간: 0.054초, 이곳 서비스는
	PostgreSQL v16.1로 자료를 관리합니다