全部博文(47)
分类: Oracle
2008-09-04 13:42:01
Note: Decode and Case are very similar in their appearance but can produce very different results. | ||||
Demo Tables & Data |
| |||
DECODE (overload 1) | standard.decode(expr NUMBER, pat NUMBER, res NUMBER) RETURN NUMBER; | |||
DECODE (overload 2) | standard.decode( expr NUMBER, pat NUMBER, res VARCHAR2 CHARACTER SET ANY_CS) return VARCHAR2 CHARACTER SET res%CHARSET; | |||
DECODE (overload 3) | standard.decode(expr NUMBER, pat NUMBER, res DATE) RETURN DATE; | |||
DECODE (overload 4) | standard.decode( expr VARCHAR2 CHARACTER SET ANY_CS, pat VARCHAR2 CHARACTER SET expr%CHARSET, res NUMBER) RETURN NUMBER; | |||
DECODE (overload 5) | standard.decode( expr VARCHAR2 CHARACTER SET ANY_CS, pat VARCHAR2 CHARACTER SET expr%CHARSET, res VARCHAR2 CHARACTER SET ANY_CS) RETURN VARCHAR2 CHARACTER SET res%CHARSET; | |||
DECODE (overload 6) | standard.decode( expr VARCHAR2 CHARACTER SET ANY_CS, pat VARCHAR2 CHARACTER SET expr%CHARSET, res DATE) RETURN DATE; | |||
DECODE (overload 7) | standard.decode(expr DATE, pat DATE, res NUMBER) RETURN NUMBER; | |||
DECODE (overload 8) | standard.decode( expr DATE, pat DATE, res VARCHAR2 CHARACTER SET ANY_CS) RETURN VARCHAR2 CHARACTER SET res%CHARSET; | |||
DECODE (overload 9) | standard.decode( expr DATE, pat DATE, res DATE) RETURN DATE; | |||
DECODE (overload 10) | standard.decode(expr OBJECT, pat OBJECT, res OBJECT) RETURN OBJECT; | |||
DECODE (overload 11) | standard.decode(expr UNDEFINED, pat UNDEFINED, res UNDEFINED) RETURN UNDEFINED; | |||
Simple DECODE |
SELECT DECODE (value, FROM dual; | |||
SELECT program_id, DECODE(customer_id, 'AAL', 'American Airlines') AIRLINE, delivered_date FROM airplanes WHERE ROWNUM < 11; | ||||
More Complex DECODE |
SELECT DECODE (value,<if this value>,<return this value>, < if this value>,<return this value>, ....) FROM dual; | |||
SELECT program_id, DECODE(customer_id, 'AAL', 'American Airlines', 'ILC', 'Intl. Leasing Corp.', 'NWO', 'Northwest Orient', 'SAL', 'Southwest Airlines', 'SWA', 'Sweptwing Airlines', 'USAF', 'U.S. Air Force') AIRLINE, delivered_date FROM airplanes WHERE ROWNUM < 11; | ||||
DECODE with DEFAULT |
SELECT DECODE (value, .... FROM dual; | |||
SELECT program_id, DECODE(customer_id, 'AAL', 'American Airlines', 'ILC', 'Intl. Leasing Corp.', 'NWO', 'Northwest Orient', 'SAL', 'Southwest Airlines', 'SWA', 'Sweptwing Airlines', 'USAF', 'United States Air Force', 'Not Known') AIRLINE, delivered_date FROM airplanes WHERE ROWNUM < 11; | ||||
Note: The following crosstabulation is the standard for 10g or earlier. In 11g use the PIVOT and UNPIVOT operators | ||||
Simple DECODE Crosstab Note how each decode only looks at a single possible value and turns it into a new column |
SELECT program_id, DECODE(customer_id, 'AAL', 'AAL') AMERICAN, DECODE(customer_id, 'DAL', 'DAL') DELTA, DECODE(customer_id, 'NWO', 'NWO') NORTHWEST, DECODE(customer_id, 'ILC', 'ILC') INTL_LEASING FROM airplanes WHERE rownum < 20; | |||
DECODE as an in-line view with crosstab summation |
The above DECODE, in blue, used as an in-line view | |||
SELECT program_id, COUNT (AMERICAN) AAL, COUNT (DELTA) DAL, COUNT (NORTHWEST) NWO, COUNT(INTL_LEASING) ILC FROM ( SELECT program_id, DECODE(customer_id, 'AAL', 'AAL') AMERICAN, DECODE(customer_id, 'DAL', 'DAL') DELTA, DECODE(customer_id, 'NWO', 'NWO') NORTHWEST, DECODE(customer_id, 'ILC', 'ILC') INTL_LEASING FROM airplanes) GROUP BY program_id; | ||||
Query for DECODE demo |
CREATE TABLE stores ( store_name VARCHAR2(20), region_dir NUMBER(5), region_mgr NUMBER(5), store_mgr1 NUMBER(5), store_mgr2 NUMBER(5), asst_storemgr1 NUMBER(5), asst_storemgr2 NUMBER(5), asst_storemgr3 NUMBER(5)); INSERT INTO stores VALUES ('San Francisco',100,200,301,302,401,0,403); INSERT INTO stores VALUES ('Oakland',100,200,301,0,404,0,0); INSERT INTO stores VALUES ('Palo Alto',100,200,0,305,0,405,406); INSERT INTO stores VALUES ('Santa Clara',100,250,0,306,0,0,407); COMMIT; SELECT DECODE(asst_storemgr1, 0, DECODE(asst_storemgr2, 0, DECODE(asst_storemgr3, 0, 0, asst_storemgr3), asst_storemgr2), asst_storemgr1) ASST_MANAGER, DECODE(store_mgr1,0, DECODE(store_mgr2,0, 0, store_mgr2), store_mgr1) STORE_MANAGER, REGION_MGR, REGION_DIR FROM stores; | |||
DECODE with Summary Function |
SELECT SUM(CA_COUNT) CA, SUM(TX_COUNT) TX FROM ( SELECT state, DECODE(state, 'CA', COUNT(*), 0) CA_COUNT, DECODE(state, 'TX', COUNT(*), 0) TX_COUNT FROM locations GROUP BY state); | |||
DECODE in the WHERE clause |
set serveroutput on DECLARE posn PLS_INTEGER := 0; empid PLS_INTEGER := 178; x NUMBER; BEGIN SELECT NVL(SUM(ah.quantity * ah.saleprice * ap.payoutpct), 0) INTO x FROM accessoryhistory ah, payoutpercentage ap, sku s, store st WHERE empid = DECODE(posn, 0, st.areadir, 1, st.areamgr, 2, NVL(st.storemgr1, st.storemgr2), 3, NVL(st.asstmgr1, NVL(st.asstmgr2, st.asstmgr3))) AND ah.statustype IN ('ACT', 'DEA') AND ah.store = st.store AND s.dbid = ah.dbid AND s.sku = ah.sku AND ap.productgroup = s.productgroup AND ap.position = posn; dbms_output.put_line(x); END; / | |||
DECODE Altered WHERE Clause |
CREATE TABLE test ( pubdate DATE, compdate DATE, valuecol NUMBER(5)); INSERT INTO test VALUES (TRUNC(SYSDATE), TRUNC(SYSDATE+300), 1); INSERT INTO test VALUES (TRUNC(SYSDATE-300), TRUNC(SYSDATE), 9); COMMIT; SELECT * FROM test; CREATE OR REPLACE PROCEDURE testproc ( StartDate DATE, EndDate DATE, DateType IN VARCHAR2) IS i PLS_INTEGER; BEGIN SELECT valuecol INTO i FROM test WHERE DECODE(DateType, 'AA',compdate, 'BB', pubdate, compdate) <= EndDate AND DECODE(DateType, 'AA', compdate, 'BB', pubdate, compdate) >= StartDate; dbms_output.put_line(TO_CHAR(i)); END testproc; / set serveroutput on exec testproc(TRUNC(SYSDATE), TRUNC(SYSDATE), 'BB'); |