[DB] PROCEDURE
in DB
νλ‘μμ (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;
ν€ν¬μΈνΈ
IN λ§€κ°λ³μλ μ°Έμ‘°λ§ κ°λ₯νλ©΄ κ°μ ν λΉν μ μλ€
OUT λ§€κ°λ³μμ κ°μ μ λ¬ν μλ μμ§λ§ μλ―Έλ μλ€.
OUT, IN OUT λ§€κ°λ³μμλ λν΄νΈκ°μ μ€μ ν μ μλ€.
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);