[DB] PROCEDURE


ν”„λ‘œμ‹œμ €(PROCEDURE)


νŠΉμ •ν•œ λ‘œμ§μ„ μ²˜λ¦¬ν•˜κΈ°λ§Œ ν•˜κ³  κ²°κ³Ό 값을 λ°˜ν™˜ν•˜μ§€ μ•ŠλŠ” μ„œλΈŒ ν”„λ‘œκ·Έλž¨μ΄λ‹€.

ν…Œμ΄λΈ”μ—μ„œ 데이터λ₯Ό μΆ”μΆœν•΄ μ‘°μž‘ν•˜κ³  κ·Έ κ²°κ³Όλ₯Ό λ‹€λ₯Έ ν…Œμ΄λΈ”μ— λ‹€μ‹œ μ €μž₯ν•˜κ±°λ‚˜ κ°±μ‹ ν•˜λŠ” 일련의 처리λ₯Ό ν•  λ•Œ 주둜 ν”„λ‘œμ‹œμ €λ₯Ό μ‚¬μš©ν•œλ‹€.


생성

CREATE OR REPLACE PROCEDURE ν”„λ‘œμ‹œμ €λͺ…
    (λ§€κ°œλ³€μˆ˜λͺ…1 [IN | OUT | IN OUT] λ°μ΄ν„°νƒ€μž… [:= λ””ν΄νŠΈκ°’]
    ,λ§€κ°œλ³€μˆ˜λͺ…2 [IN | OUT | IN OUT] λ°μ΄ν„°νƒ€μž… [:= λ””ν΄νŠΈκ°’]
    ...
    )
IS[AS]
    λ³€μˆ˜, μƒμˆ˜ λ“± μ„ μ–Έ
BEGIN
    μ‹€ν–‰λΆ€
    
[EXCEPTION
    μ˜ˆμ™Έμ²˜λ¦¬λΆ€]
END [ν”„λ‘œμ‹œμ €λͺ…];


λ§€κ°œλ³€μˆ˜

IN은 μž…λ ₯, OUT은 좜λ ₯, IN OUT은 μž…μΆœλ ₯을 λ™μ‹œμ— ν•œλ‹€λŠ” μ˜λ―Έμ΄λ‹€.

λ””ν΄νŠΈκ°’μ€ IN이닀.

OUTλ§€κ°œλ³€μˆ˜λŠ” ν”„λ‘œμ‹œμ € λ‚΄μ—μ„œ 둜직 처리 ν›„, ν•΄λ‹Ή λ§€κ°œλ³€μˆ˜μ— 값을 ν• λ‹Ήν•΄ ν”„λ‘œμ‹œμ € ν˜ΈμΆœλΆ€λΆ„μ—μ„œ 이 값을 μ°Έμ‘°ν•  수 μžˆλ‹€.

CREATE OR REPLACE PROCEDURE MY_NEW_JOB_PROC
(   P_JOB_ID    IN  JOBS.JOB_ID%TYPE,
    P_JOB_TITLE IN  JOBS.JOB_TITLE%TYPE,
    P_MIN_SAL   IN  JOBS.MIN_SALARY%TYPE,
    P_MAX_SAL   IN  JOBS.MAX_SALARY%TYPE    )
IS
 
BEGIN
    INSERT INTO JOBS (JOB_ID, JOB_TITLE, MIN_SALARY, MAX_SALARY, CREATE_DATE, UPDATE_DATE)
    VALUES (P_JOB_ID, P_JOB_TITLE, P_MIN_SAL, P_MAX_SAL, SYSDATE, SYSDATE);
    
    COMMIT;
END;


μ‹€ν–‰

ν”„λ‘œμ‹œμ €λŠ” λ°˜ν™˜κ°’μ΄ μ—†μœΌλ―€λ‘œ ν•¨μˆ˜μ²˜λŸΌ SELECTμ ˆμ—λŠ” μ‚¬μš©ν•  수 μ—†λ‹€.

EXEC(EXECUTE) ν”„λ‘œμ‹œμ €λͺ…(λ§€κ°œλ³€μˆ˜1κ°’, λ§€κ°œλ³€μˆ˜2κ°’, ...);
EXEC MY_NEW_JOB_PROC('SM_JOB1', 'SAMPLE JOB1', 1000, 5000);

λ™μΌν•œ JOB_IDκ°€ λ“€μ–΄μ˜€λ©΄ μ‹ κ·œ INSERT λŒ€μ‹  λ‹€λ₯Έ 정보λ₯Ό κ°±μ‹ ν•˜λŠ” ν”„λ‘œμ‹œμ €λ₯Ό λ§Œλ“€μ–΄λ³΄μž.

CREATE OR REPLACE PROCEDURE MY_NEW_JOB_PROC
(   P_JOB_ID    IN  JOBS.JOB_ID%TYPE,
    P_JOB_TITLE IN  JOBS.JOB_TITLE%TYPE,
    P_MIN_SAL   IN  JOBS.MIN_SALARY%TYPE,
    P_MAX_SAL   IN  JOBS.MAX_SALARY%TYPE    )
IS
    VN_CNT  NUMBER := 0;
BEGIN
 
    SELECT  COUNT(*)
    INTO    VN_CNT
    FROM    JOBS
    WHERE   JOB_ID = P_JOB_ID;
    
    IF  VN_CNT > 0  THEN
        UPDATE  JOBS
        SET     JOB_TITLE   = P_JOB_TITLE,
                MIN_SALARY  = P_MIN_SAL,
                MAX_SALARY  = P_MAX_SAL,
                UPDATE_DATE = SYSDATE
        WHERE   JOB_ID = P_JOB_ID;
    ELSE
        INSERT INTO JOBS (JOB_ID, JOB_TITLE, MIN_SALARY, MAX_SALARY, CREATE_DATE, UPDATE_DATE)
        VALUES (P_JOB_ID, P_JOB_TITLE, P_MIN_SAL, P_MAX_SAL, SYSDATE, SYSDATE);
    END IF;
    
    COMMIT;
END;

μ‹€ν–‰κ²°κ³Ό

EXEC MY_NEW_JOB_PROC('SM_JOB1', 'SAMPLE JOB1', 2000, 6000);

μ‹€ν–‰κ²°κ³Ό

SELECT  *
FROM    JOBS
WHERE   JOB_ID = 'SM_JOB1';


λ§€κ°œλ³€μˆ˜

μž…λ ₯κ°’ λ§€ν•‘

ν”„λ‘œμ‹œμ €μ˜ λ§€κ°œλ³€μˆ˜κ°€ 많으면 μ‹€ν–‰ν•  λ•Œ λ§€κ°œλ³€μˆ˜ κ°’μ˜ κ°œμˆ˜λ‚˜ μˆœμ„œλ₯Ό ν˜Όλ™ν•  μ—¬μ§€κ°€ λ§Žλ‹€.

이런 κ²½μš°μ—λŠ” λ‹€μŒκ³Ό 같은 ν˜•νƒœλ‘œ λ§€κ°œλ³€μˆ˜μ™€ μž…λ ₯값을 λ§€ν•‘ν•΄ μ‹€ν–‰ν•˜λ©΄ νŽΈλ¦¬ν•˜λ‹€.

EXEC ν”„λ‘œμ‹œμ €λͺ… (λ§€κ°œλ³€μˆ˜1 => λ§€κ°œλ³€μˆ˜1 κ°’,
                λ§€κ°œλ³€μˆ˜2 => λ§€κ°œλ³€μˆ˜2 κ°’, ...);
EXECUTE MY_NEW_JOB_PROC (P_JOB_ID   =>  'SM_JOB1',
                         P_JOB_TITLE=>  'SAMPLE JOB1',
                         P_MIN_SAL  =>  2000,
                         P_MAX_SAL  =>  7000            );
λ””ν΄νŠΈ κ°’ μ„€μ •

λ§€κ°œλ³€μˆ˜μ— λ””ν΄νŠΈ 값을 μ„€μ •ν•˜λ©΄ ν”„λ‘œμ‹œμ € μ‹€ν–‰μ‹œ ν•΄λ‹Ή λ§€κ°œλ³€μˆ˜μ— 값을 λ„£μ§€ μ•Šμ•„λ„λœλ‹€.

λ””ν΄νŠΈκ°’μ€ IN λ§€κ°œλ³€μˆ˜μ—λ§Œ μ‚¬μš©ν•  수 μžˆλ‹€.

CREATE OR REPLACE PROCEDURE MY_NEW_JOB_PROC
(   P_JOB_ID    IN  JOBS.JOB_ID%TYPE,
    P_JOB_TITLE IN  JOBS.JOB_TITLE%TYPE,
    P_MIN_SAL   IN  JOBS.MIN_SALARY%TYPE := 10,
    P_MAX_SAL   IN  JOBS.MAX_SALARY%TYPE := 100   )
IS
    VN_CNT  NUMBER := 0;
BEGIN
 
    SELECT  COUNT(*)
    INTO    VN_CNT
    FROM    JOBS
    WHERE   JOB_ID = P_JOB_ID;
    
    IF  VN_CNT > 0  THEN
        UPDATE  JOBS
        SET     JOB_TITLE   = P_JOB_TITLE,
                MIN_SALARY  = P_MIN_SAL,
                MAX_SALARY  = P_MAX_SAL,
                UPDATE_DATE = SYSDATE
        WHERE   JOB_ID = P_JOB_ID;
    ELSE
        INSERT INTO JOBS (JOB_ID, JOB_TITLE, MIN_SALARY, MAX_SALARY, CREATE_DATE, UPDATE_DATE)
        VALUES (P_JOB_ID, P_JOB_TITLE, P_MIN_SAL, P_MAX_SAL, SYSDATE, SYSDATE);
    END IF;
    
    COMMIT;
END;
 
EXEC MY_NEW_JOB_PROC('SM_JOB1', 'SAMPLE JOB1');
 
SELECT  *
FROM    JOBS
WHERE   JOB_ID = 'SM_JOB1';


OUT λ§€κ°œλ³€μˆ˜

ν”„λ‘œμ‹œμ € μ‹€ν–‰ μ‹œ 점에 OUT λ§€κ°œλ³€μˆ˜λ₯Ό λ³€μˆ˜ ν˜•νƒœλ₯Ό μ „λ‹¬ν•˜κ³ , ν”„λ‘œμ‹œμ € μ‹€ν–‰λΆ€μ—μ„œ 이 λ§€κ°œλ³€μˆ˜μ— νŠΉμ • 값을 ν• λ‹Ήν•œλ‹€.

싀행이 λλ‚˜λ©΄ μ „λ‹¬ν•œ λ³€μˆ˜λ₯Ό μ°Έμ‘°ν•΄ 값을 κ°€μ Έμ˜¬ 수 μžˆλ‹€.

CREATE OR REPLACE PROCEDURE MY_NEW_JOB_PROC
(   P_JOB_ID    IN  JOBS.JOB_ID%TYPE,
    P_JOB_TITLE IN  JOBS.JOB_TITLE%TYPE,
    P_MIN_SAL   IN  JOBS.MIN_SALARY%TYPE := 10,
    P_MAX_SAL   IN  JOBS.MAX_SALARY%TYPE := 100,
    P_UPDATE_DATE OUT JOBS.UPDATE_DATE%TYPE     )
IS
    VN_CNT  NUMBER := 0;
    VN_CUR_DATE JOBS.UPDATE_DATE%TYPE := SYSDATE;
BEGIN
 
    SELECT  COUNT(*)
    INTO    VN_CNT
    FROM    JOBS
    WHERE   JOB_ID = P_JOB_ID;
    
    IF  VN_CNT > 0  THEN
        UPDATE  JOBS
        SET     JOB_TITLE   = P_JOB_TITLE,
                MIN_SALARY  = P_MIN_SAL,
                MAX_SALARY  = P_MAX_SAL,
                UPDATE_DATE = VN_CUR_DATE
        WHERE   JOB_ID = P_JOB_ID;
    ELSE
        INSERT INTO JOBS (JOB_ID, JOB_TITLE, MIN_SALARY, MAX_SALARY, CREATE_DATE, UPDATE_DATE)
        VALUES (P_JOB_ID, P_JOB_TITLE, P_MIN_SAL, P_MAX_SAL, SYSDATE, SYSDATE);
    END IF;
    
    P_UPDATE_DATE := VN_CUR_DATE;
    
    COMMIT;
END;
 
DECLARE
    VD_CUR_DATE JOBS.UPDATE_DATE%TYPE;
BEGIN
    MY_NEW_JOB_PROC ('SM_JOB1', 'SAMPLE JOB1', 2000, 6000, VD_CUR_DATE);
    
    DBMS_OUTPUT.PUT_LINE(VD_CUR_DATE);
END;


IN OUT λ§€κ°œλ³€μˆ˜

μž…λ ₯κ³Ό λ™μ‹œμ— 좜λ ₯용으둜 μ‚¬μš©ν•  수 μžˆλ‹€.

ν”„λ‘œμ‹œμ € μ‹€ν–‰μ‹œ OUT λ§€κ°œλ³€μˆ˜μ— 전달할 λ³€μˆ˜μ— 값을 ν• λ‹Ήν•΄μ„œ λ„˜κ²¨μ€„ 수 μžˆμ§€λ§Œ μ˜λ―Έμ—†λ‹€.

μ™œλƒν•˜λ©΄ OUT λ§€κ°œλ³€μˆ˜λŠ” ν”„λ‘œμ‹œμ €κ°€ μ„±κ³΅μ μœΌλ‘œ 싀행을 μ™„λ£Œν•  λ•ŒκΉŒμ§€ 값이 ν• λ‹Ήλ˜μ§€ μ•ŠκΈ°λ•Œλ¬Έμ΄λ‹€.

κ·ΈλŸ¬λ―€λ‘œ λ§€κ°œλ³€μˆ˜μ— 값을 μ „λ‹¬ν•΄μ„œ μ‚¬μš©ν•œ λ‹€μŒ λ‹€μ‹œ 이 λ§€κ°œλ³€μˆ˜μ— 값을 받아와 μ°Έμ‘°ν•˜κ³ μ‹Άλ‹€λ©΄ IN OUT λ§€κ°œλ³€μˆ˜λ₯Ό μ΄μš©ν•΄μ•Όν•œλ‹€.

CREATE OR REPLACE PROCEDURE MY_PARAMETER_TEST_PROC
(   P_VAR1          VARCHAR2,
    P_VAR2  OUT     VARCHAR2,
    P_VAR3  IN OUT  VARCHAR2    )
IS
BEGIN
    DBMS_OUTPUT.PUT_LINE('P_VAR1 VALUE=' || P_VAR1);
    DBMS_OUTPUT.PUT_LINE('P_VAR2 VALUE=' || P_VAR2);
    DBMS_OUTPUT.PUT_LINE('P_VAR3 VALUE=' || P_VAR3);
    
    P_VAR2 := 'B2';
    P_VAR3 := 'C2';
END;
 
DECLARE
    V_VAR1  VARCHAR2(10) := 'A';
    V_VAR2  VARCHAR2(10) := 'B';
    V_VAR3  VARCHAR2(10) := 'C';
BEGIN
    MY_PARAMETER_TEST_PROC(V_VAR1, V_VAR2, V_VAR3);
    
    DBMS_OUTPUT.PUT_LINE('V_VAR2 VALUE=' || V_VAR2);
    DBMS_OUTPUT.PUT_LINE('V_VAR3 VALUE=' || V_VAR3);
END;


ν‚€ν¬μΈνŠΈ

img IN λ§€κ°œλ³€μˆ˜λŠ” 참쑰만 κ°€λŠ₯ν•˜λ©΄ 값을 ν• λ‹Ήν•  수 μ—†λ‹€

img OUT λ§€κ°œλ³€μˆ˜μ— 값을 전달할 μˆ˜λŠ” μžˆμ§€λ§Œ μ˜λ―ΈλŠ” μ—†λ‹€.

img OUT, IN OUT λ§€κ°œλ³€μˆ˜μ—λŠ” λ””ν΄νŠΈκ°’μ„ μ„€μ •ν• μˆ˜ μ—†λ‹€.

img IN λ§€κ°œλ³€μˆ˜μ—λŠ” λ³€μˆ˜λ‚˜ μƒμˆ˜, 각 데이터 μœ ν˜•μ— λ”°λ₯Έ 값을 전달할 수 μžˆμ§€λ§Œ OUT, IN OUT λ§€κ°œλ³€μˆ˜λ₯Ό 전달할 λ•ŒλŠ” λ°˜λ“œλ¦¬ λ³€μˆ˜ ν˜•νƒœλ‘œ 값을 λ„˜κ²¨μ€˜μ•Όν•œλ‹€.


RETURN문

ν•¨μˆ˜μ—μ„œλŠ” μΌμ •ν•œ 연상을 μˆ˜ν–‰ν•˜κ³  κ²°κ³Ό 값을 λ°˜ν™˜ν•˜λŠ” 역할을 ν–ˆμ§€λ§Œ, ν”„λ‘œμ‹œμ €μ—μ„œλŠ” RETURN문을 λ§Œλ‚˜λ©΄ 이후 λ‘œμ§μ„ μˆ˜ν–‰ν•˜μ§€ μ•Šκ³  ν”„λ‘œμ‹œμ €λ₯Ό λΉ μ Έλ‚˜κ°„λ‹€.

CREATE OR REPLACE PROCEDURE MY_NEW_JOB_PROC
(   P_JOB_ID    IN  JOBS.JOB_ID%TYPE,
    P_JOB_TITLE IN  JOBS.JOB_TITLE%TYPE,
    P_MIN_SAL   IN  JOBS.MIN_SALARY%TYPE := 10,
    P_MAX_SAL   IN  JOBS.MAX_SALARY%TYPE := 100     )
IS
    VN_CNT  NUMBER := 0;
BEGIN
    IF  P_MIN_SAL < 1000 THEN
        DBMS_OUTPUT.PUT_LINE('μ΅œμ†Œ 급여값은 1000 μ΄μƒμ΄μ–΄μ•Όν•œλ‹€.');
        RETURN;
    END IF;
 
    SELECT  COUNT(*)
    INTO    VN_CNT
    FROM    JOBS
    WHERE   JOB_ID = P_JOB_ID;
    
    IF  VN_CNT > 0  THEN
        UPDATE  JOBS
        SET     JOB_TITLE   = P_JOB_TITLE,
                MIN_SALARY  = P_MIN_SAL,
                MAX_SALARY  = P_MAX_SAL,
                UPDATE_DATE = SYSDATE
        WHERE   JOB_ID = P_JOB_ID;
    ELSE
        INSERT INTO JOBS (JOB_ID, JOB_TITLE, MIN_SALARY, MAX_SALARY, CREATE_DATE, UPDATE_DATE)
        VALUES (P_JOB_ID, P_JOB_TITLE, P_MIN_SAL, P_MAX_SAL, SYSDATE, SYSDATE);
    END IF;
    
    COMMIT;
END;
 
EXEC MY_NEW_JOB_PROC('SM_JOB1', 'SAMPLE JOB1', 999, 6000);