PRODUCT_NAME LASTED BUG_ID
-------------------- -------------------- ----------
Open RoundFile 2010-06-01 1234
Visual TurboBuilder 2010-02-16 3456
ReConsider 2010-01-01 5678
. 하지만 이 결과는 가장 최근 버그로 나열된 행의 BUG_ID가 가장 최근 버그가 아님이 확인됨
PRODUCT_NAME LASTED BUG_ID
-------------------- -------------------- ----------
Open RoundFile 2009-12-19 1234 -- bug_id가 1234인 행의
Open RoundFile 2010-06-01 2248 -- date_reported는 2010-06-01 이 아님
Visual TurboBuilder 2010-02-16 3456
Visual TurboBuilder 2010-02-10 4077
Visual TurboBuilder 2010-02-16 5150
ReConsider 2010-01-01 5678
ReConsider 2009-11-09 8063
. 샘플 데이터 생성(Oracle 기준)
-- 0. Oracle Version Check
SELECT * FROM V$VERSION;
BANNER
---------------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - 64bit
PL/SQL Release 10.2.0.3.0 - Production
-- 1. Create Table
DROP TABLE BUGS_PRODUCTS;
DROP TABLE BUGS;
DROP TABLE PRODUCTS;
DROP TABLE ACCOUNTS;
CREATE TABLE ACCOUNTS (ACCOUNT_ID NUMBER,
ACCOUNT_NAME VARCHAR(20),
FIRST_NAME VARCHAR(20),
LAST_NAME VARCHAR(20),
EMAIL VARCHAR(100),
PASSWORD_HASH CHAR(64),
PORTRAIT_IMAGE BLOB,
HOURLY_RATE NUMERIC(9,2),
PRIMARY KEY (ACCOUNT_ID));
CREATE TABLE PRODUCTS(PRODUCT_ID NUMBER,
PRODUCT_NAME VARCHAR2(1000),
PRIMARY KEY (PRODUCT_ID));
CREATE TABLE BUGS(BUG_ID NUMBER,
DATE_REPORTED DATE NOT NULL,
SUMMARY VARCHAR(280),
DESCRIPTION VARCHAR2(80),
RESOLUTION VARCHAR2(80),
REPORTED_BY NUMBER NOT NULL,
ASSIGNED_TO NUMBER,
VERIFIED_BY NUMBER,
STATUS VARCHAR2(20) DEFAULT 'NEW' NOT NULL ,
PRIORITY VARCHAR2(20),
HOURS NUMERIC(9,2),
PRIMARY KEY (BUG_ID),
FOREIGN KEY (REPORTED_BY) REFERENCES ACCOUNTS(ACCOUNT_ID));
CREATE TABLE BUGS_PRODUCTS(BUG_ID NUMBER NOT NULL,
PRODUCT_ID NUMBER NOT NULL,
PRIMARY KEY (BUG_ID, PRODUCT_ID),
FOREIGN KEY (BUG_ID) REFERENCES BUGS(BUG_ID),
FOREIGN KEY (PRODUCT_ID) REFERENCES PRODUCTS(PRODUCT_ID));
-- 2. Insert Data
INSERT INTO ACCOUNTS(ACCOUNT_ID) VALUES(9901);
INSERT INTO ACCOUNTS(ACCOUNT_ID) VALUES(9902);
INSERT INTO ACCOUNTS(ACCOUNT_ID) VALUES(9903);
INSERT INTO ACCOUNTS(ACCOUNT_ID) VALUES(9904);
INSERT INTO ACCOUNTS(ACCOUNT_ID) VALUES(9905);
INSERT INTO ACCOUNTS(ACCOUNT_ID) VALUES(9906);
INSERT INTO ACCOUNTS(ACCOUNT_ID) VALUES(9907);
INSERT INTO PRODUCTS(PRODUCT_ID, PRODUCT_NAME) VALUES(1, 'Open RoundFile');
INSERT INTO PRODUCTS(PRODUCT_ID, PRODUCT_NAME) VALUES(2, 'Visual TurboBuilder');
INSERT INTO PRODUCTS(PRODUCT_ID, PRODUCT_NAME) VALUES(3, 'ReConsider');
INSERT INTO BUGS(BUG_ID, DATE_REPORTED, REPORTED_BY) VALUES(1234, TO_DATE('20091219', 'YYYYMMDD'), 9901);
INSERT INTO BUGS(BUG_ID, DATE_REPORTED, REPORTED_BY) VALUES(2248, TO_DATE('20100601', 'YYYYMMDD'), 9902);
INSERT INTO BUGS(BUG_ID, DATE_REPORTED, REPORTED_BY) VALUES(3456, TO_DATE('20100216', 'YYYYMMDD'), 9903);
INSERT INTO BUGS(BUG_ID, DATE_REPORTED, REPORTED_BY) VALUES(4077, TO_DATE('20100210', 'YYYYMMDD'), 9904);
INSERT INTO BUGS(BUG_ID, DATE_REPORTED, REPORTED_BY) VALUES(5150, TO_DATE('20100216', 'YYYYMMDD'), 9905);
INSERT INTO BUGS(BUG_ID, DATE_REPORTED, REPORTED_BY) VALUES(5678, TO_DATE('20100101', 'YYYYMMDD'), 9906);
INSERT INTO BUGS(BUG_ID, DATE_REPORTED, REPORTED_BY) VALUES(8063, TO_DATE('20091109', 'YYYYMMDD'), 9907);
INSERT INTO BUGS_PRODUCTS(BUG_ID, PRODUCT_ID) VALUES(1234, 1);
INSERT INTO BUGS_PRODUCTS(BUG_ID, PRODUCT_ID) VALUES(2248, 1);
INSERT INTO BUGS_PRODUCTS(BUG_ID, PRODUCT_ID) VALUES(3456, 2);
INSERT INTO BUGS_PRODUCTS(BUG_ID, PRODUCT_ID) VALUES(4077, 2);
INSERT INTO BUGS_PRODUCTS(BUG_ID, PRODUCT_ID) VALUES(5150, 2);
INSERT INTO BUGS_PRODUCTS(BUG_ID, PRODUCT_ID) VALUES(5678, 3);
INSERT INTO BUGS_PRODUCTS(BUG_ID, PRODUCT_ID) VALUES(8063, 3);
COMMIT;
col PRODUCT_NAME format a20
col LASTED format a20
SELECT A.PRODUCT_NAME,
MAX(TO_CHAR(C.DATE_REPORTED, 'YYYY-MM-DD')) AS LASTED
FROM PRODUCTS A,
BUGS_PRODUCTS B,
BUGS C
WHERE A.PRODUCT_ID = B.PRODUCT_ID
AND B.BUG_ID = C.BUG_ID
GROUP BY A.PRODUCT_NAME
;
PRODUCT_NAME LASTED
-------------------- --------------------
Open RoundFile 2010-06-01
ReConsider 2010-01-01
Visual TurboBuilder 2010-02-16
SELECT A.PRODUCT_NAME,
MAX(TO_CHAR(C.DATE_REPORTED, 'YYYY-MM-DD')) AS LASTED,
C.BUG_ID
FROM PRODUCTS A,
BUGS_PRODUCTS B,
BUGS C
WHERE A.PRODUCT_ID = B.PRODUCT_ID
AND B.BUG_ID = C.BUG_ID
GROUP BY A.PRODUCT_NAME
;
C.BUG_ID
*
ERROR at line 3:
ORA-00979: not a GROUP BY expression
col PRODUCT_NAME format a20
col LASTED format a20
SELECT A.PRODUCT_NAME,
MAX(TO_CHAR(C.DATE_REPORTED, 'YYYY-MM-DD')) AS LASTED
FROM PRODUCTS A,
BUGS_PRODUCTS B,
BUGS C
WHERE A.PRODUCT_ID = B.PRODUCT_ID
AND B.BUG_ID = C.BUG_ID
GROUP BY A.PRODUCT_NAME
;
PRODUCT_NAME LASTED
-------------------- --------------------
Open RoundFile 2010-06-01
ReConsider 2010-01-01
Visual TurboBuilder 2010-02-16
SELECT A.PRODUCT_NAME,
MAX(TO_CHAR(C.DATE_REPORTED, 'YYYY-MM-DD')) AS LASTED,
C.BUG_ID
FROM PRODUCTS A,
BUGS_PRODUCTS B,
BUGS C
WHERE A.PRODUCT_ID = B.PRODUCT_ID
AND B.BUG_ID = C.BUG_ID
GROUP BY A.PRODUCT_NAME
;
C.BUG_ID
*
ERROR at line 3:
ORA-00979: not a GROUP BY expression
SELECT A.PRODUCT_NAME,
MAX(TO_CHAR(C.DATE_REPORTED, 'YYYY-MM-DD')) AS LASTED,
MIN(TO_CHAR(C.DATE_REPORTED, 'YYYY-MM-DD')) AS EARLIEST
C.BUG_ID
FROM PRODUCTS A,
BUGS_PRODUCTS B,
BUGS C
WHERE A.PRODUCT_ID = B.PRODUCT_ID
AND B.BUG_ID = C.BUG_ID
GROUP BY A.PRODUCT_NAME;
SELECT A.PRODUCT_NAME,
SUM(C.HOURS) AS TOTAL_PROJECT_ESTIMATE,
C.BUG_ID
FROM PRODUCTS A,
BUGS_PRODUCTS B,
BUGS C
WHERE A.PRODUCT_ID = B.PRODUCT_ID
AND B.BUG_ID = C.BUG_ID
GROUP BY A.PRODUCT_NAME;
SELECT A.REPORTED_BY,
B.ACCOUNT_NAME
FROM BUGS A,
ACCOUNTS B
WHERE A.REPORTED_BY = B.ACCOUNT_ID
GROUP BY A.REPORTED_BY;
col PRODUCT_NAME format a20
col LASTED format a20
SELECT A.PRODUCT_NAME,
MAX(TO_CHAR(C.DATE_REPORTED, 'YYYY-MM-DD')) AS LASTED
FROM PRODUCTS A,
BUGS_PRODUCTS B,
BUGS C
WHERE A.PRODUCT_ID = B.PRODUCT_ID
AND B.BUG_ID = C.BUG_ID
GROUP BY A.PRODUCT_NAME
;
PRODUCT_NAME LASTED
-------------------- --------------------
Open RoundFile 2010-06-01
ReConsider 2010-01-01
Visual TurboBuilder 2010-02-16
col PRODUCT_NAME format a20
col LASTED format a20
SELECT A_1.PRODUCT_NAME,
TO_CHAR(C_1.DATE_REPORTED, 'YYYY-MM-DD') AS LASTED,
C_1.BUG_ID
FROM PRODUCTS A_1,
BUGS_PRODUCTS B_1,
BUGS C_1
WHERE A_1.PRODUCT_ID = B_1.PRODUCT_ID
AND B_1.BUG_ID = C_1.BUG_ID
AND NOT EXISTS (SELECT 1
FROM BUGS_PRODUCTS B_2,
BUGS C_2
WHERE B_2.BUG_ID = C_2.BUG_ID
AND B_1.PRODUCT_ID = B_2.PRODUCT_ID
AND C_1.DATE_REPORTED < C_2.DATE_REPORTED)
;
PRODUCT_NAME LASTED BUG_ID
-------------------- -------------------- ----------
Open RoundFile 2010-06-01 2248
Visual TurboBuilder 2010-02-16 3456
Visual TurboBuilder 2010-02-16 5150
ReConsider 2010-01-01 5678
SELECT T.PRODUCT_NAME,
TO_CHAR(T.LASTED, 'YYYY-MM-DD') LASTED,
C_2.BUG_ID
FROM (SELECT A_1.PRODUCT_ID,
A_1.PRODUCT_NAME,
MAX(C_1.DATE_REPORTED) AS LASTED
FROM PRODUCTS A_1,
BUGS_PRODUCTS B_1,
BUGS C_1
WHERE A_1.PRODUCT_ID = B_1.PRODUCT_ID
AND B_1.BUG_ID = C_1.BUG_ID
GROUP BY A_1.PRODUCT_ID,
A_1.PRODUCT_NAME) T,
BUGS_PRODUCTS B_2,
BUGS C_2
WHERE B_2.BUG_ID = C_2.BUG_ID
AND B_2.PRODUCT_ID = T.PRODUCT_ID
AND C_2.DATE_REPORTED = T.LASTED
;
PRODUCT_NAME LASTED BUG_ID
-------------------- -------------------- ----------
Open RoundFile 2010-06-01 2248
Visual TurboBuilder 2010-02-16 3456
Visual TurboBuilder 2010-02-16 5150
ReConsider 2010-01-01 5678
SELECT T.PRODUCT_NAME,
TO_CHAR(T.LASTED, 'YYYY-MM-DD') LASTED,
MAX(C_2.BUG_ID) BUG_ID
FROM (SELECT A_1.PRODUCT_ID,
A_1.PRODUCT_NAME,
MAX(C_1.DATE_REPORTED) AS LASTED
FROM PRODUCTS A_1,
BUGS_PRODUCTS B_1,
BUGS C_1
WHERE A_1.PRODUCT_ID = B_1.PRODUCT_ID
AND B_1.BUG_ID = C_1.BUG_ID
GROUP BY A_1.PRODUCT_ID,
A_1.PRODUCT_NAME) T,
BUGS_PRODUCTS B_2,
BUGS C_2
WHERE B_2.BUG_ID = C_2.BUG_ID
AND B_2.PRODUCT_ID = T.PRODUCT_ID
AND C_2.DATE_REPORTED = T.LASTED
GROUP BY T.PRODUCT_NAME,
TO_CHAR(T.LASTED, 'YYYY-MM-DD')
ORDER BY 1
;
PRODUCT_NAME LASTED BUG_ID
-------------------- -------------------- ----------
Open RoundFile 2010-06-01 2248
ReConsider 2010-01-01 5678
Visual TurboBuilder 2010-02-16 5150
-- 1. MySQL 버전
SELECT BP1.PRODUCT_ID,
B1.DATE_REPORTED AS LATEST,
B1.BUG_ID
FROM BUGS B1
JOIN BUGSPRODUCTS BP1 ON (B1.BUG_ID = BP1.BUG_ID)
LEFT OUTER JOIN (BUGS AS B2 JOIN BUGSPRODUCTS AS BP2 ON (B2.BUG_ID = BP2.BUG_ID)) ON
(BP1.PRODUCT_ID = BP2.PRODUCT_ID AND (B1.DATE_REPORTED < B2.DATE_REPORTED OR B1.DATE_REPORTED = B2.DATE_REPORTED AND B1.BUG_ID < B2.BUG_ID))
WHERE B2.BUG_ID IS NULL
;
-- 1_1. 위에 MySQL Ansi 버전은 이해가 되지 않음 -_-
-- 그래서 아래 Oracle 버전에서 일부 조인 제거함
-- 2. Oracle 버전
col PRODUCT_NAME format a20
col LASTED format a20
SELECT T_2.PRODUCT_NAME,
MAX(TO_CHAR(T_2.LASTED, 'YYYY-MM-DD')) LASTED,
MAX(T_2.BUG_ID) BUG_ID
FROM (SELECT A_1.PRODUCT_ID,
A_1.PRODUCT_NAME,
C_1.DATE_REPORTED AS LASTED,
C_1.BUG_ID
FROM PRODUCTS A_1,
BUGS_PRODUCTS B_1,
BUGS C_1
WHERE A_1.PRODUCT_ID = B_1.PRODUCT_ID
AND B_1.BUG_ID = C_1.BUG_ID) T_1,
(SELECT A_2.PRODUCT_ID,
A_2.PRODUCT_NAME,
C_2.DATE_REPORTED AS LASTED,
C_2.BUG_ID
FROM PRODUCTS A_2,
BUGS_PRODUCTS B_2,
BUGS C_2
WHERE A_2.PRODUCT_ID = B_2.PRODUCT_ID
AND B_2.BUG_ID = C_2.BUG_ID) T_2
WHERE T_1.PRODUCT_ID = T_2.PRODUCT_ID
AND T_1.LASTED < T_2.LASTED
GROUP BY T_2.PRODUCT_NAME
ORDER BY 1
;
PRODUCT_NAME LASTED BUG_ID
-------------------- -------------------- ----------
Open RoundFile 2010-06-01 2248
ReConsider 2010-01-01 5678
Visual TurboBuilder 2010-02-16 5150
SELECT A_1.PRODUCT_NAME,
MAX(TO_CHAR(C_1.DATE_REPORTED, 'YYYY-MM-DD')) AS LASTED,
MAX(C_1.BUG_ID) BUG_ID
FROM PRODUCTS A_1,
BUGS_PRODUCTS B_1,
BUGS C_1
WHERE A_1.PRODUCT_ID = B_1.PRODUCT_ID
AND B_1.BUG_ID = C_1.BUG_ID
GROUP BY A_1.PRODUCT_NAME
ORDER BY 1
;
PRODUCT_NAME LASTED BUG_ID
-------------------- -------------------- ----------
Open RoundFile 2010-06-01 2248
ReConsider 2010-01-01 8063
Visual TurboBuilder 2010-02-16 5150
-- 1. MySQL 버전
SELECT PRODUCT_ID,
MAX(DATE_REPORTED) AS LATEST GROUP_CONCAT(BUG_ID) AS BUG_ID_LIST,
FROM BUGS
JOIN BUGSPRODUCTS
USING (BUG_ID)
GROUP BY PRODUCT_ID
;
-- 2. Oracle 버전
SELECT T.PRODUCT_NAME,
T.LASTED,
SUBSTR(SYS_CONNECT_BY_PATH(T.BUG_ID, ', '), 3) BUG_ID_LIST
FROM (SELECT A_1.PRODUCT_NAME,
TO_CHAR(C_1.DATE_REPORTED, 'YYYY-MM-DD') AS LASTED,
C_1.BUG_ID BUG_ID,
ROW_NUMBER() OVER(PARTITION BY A_1.PRODUCT_NAME ORDER BY C_1.DATE_REPORTED) CNT,
COUNT(*) OVER(PARTITION BY A_1.PRODUCT_NAME) CNT_ALL
FROM PRODUCTS A_1,
BUGS_PRODUCTS B_1,
BUGS C_1
WHERE A_1.PRODUCT_ID = B_1.PRODUCT_ID
AND B_1.BUG_ID = C_1.BUG_ID) T
WHERE T.CNT = T.CNT_ALL
CONNECT BY PRIOR T.CNT = T.CNT - 1
AND PRIOR T.PRODUCT_NAME = T.PRODUCT_NAME
START WITH CNT = 1
;
PRODUCT_NAME LASTED BUG_ID_LIST
-------------------- -------------------- ------------------
Open RoundFile 2010-06-01 1234, 2248
ReConsider 2010-01-01 8063, 5678
Visual TurboBuilder 2010-02-16 4077, 3456, 5150
-- 1. 1차 버전
col PRODUCT_NAME format a20
col LASTED format a20
SELECT A_1.PRODUCT_NAME,
TO_CHAR(C_1.DATE_REPORTED, 'YYYY-MM-DD') AS LASTED,
C_1.BUG_ID,
ROW_NUMBER() OVER(PARTITION BY A_1.PRODUCT_NAME ORDER BY C_1.DATE_REPORTED DESC, C_1.BUG_ID DESC) CNT
FROM PRODUCTS A_1,
BUGS_PRODUCTS B_1,
BUGS C_1
WHERE A_1.PRODUCT_ID = B_1.PRODUCT_ID
AND B_1.BUG_ID = C_1.BUG_ID
;
PRODUCT_NAME LASTED BUG_ID CNT
-------------------- -------------------- ---------- ----------
Open RoundFile 2010-06-01 2248 1
Open RoundFile 2009-12-19 1234 2
ReConsider 2010-01-01 5678 1
ReConsider 2009-11-09 8063 2
Visual TurboBuilder 2010-02-16 5150 1
Visual TurboBuilder 2010-02-16 3456 2
Visual TurboBuilder 2010-02-10 4077 3
-- 2. 2차 버전
SELECT *
FROM (SELECT A_1.PRODUCT_NAME,
TO_CHAR(C_1.DATE_REPORTED, 'YYYY-MM-DD') AS LASTED,
C_1.BUG_ID,
ROW_NUMBER() OVER(PARTITION BY A_1.PRODUCT_NAME ORDER BY C_1.DATE_REPORTED DESC, C_1.BUG_ID DESC) CNT
FROM PRODUCTS A_1,
BUGS_PRODUCTS B_1,
BUGS C_1
WHERE A_1.PRODUCT_ID = B_1.PRODUCT_ID
AND B_1.BUG_ID = C_1.BUG_ID)
WHERE CNT = 1
;
PRODUCT_NAME LASTED BUG_ID CNT
-------------------- -------------------- ---------- ----------
Open RoundFile 2010-06-01 2248 1
ReConsider 2010-01-01 5678 1
Visual TurboBuilder 2010-02-16 5150 1
모호한 쿼리 결과를 피하기 위해 단일 값 규칙을 따라라.