| 벤더 | 절차형SQL |
|---|---|
| ORACLE | PL(Procedural Language)/SQL(Oracle) |
| DB2 | SQL/PL |
| SQL Server | T-SQL |


CREATE [OR REPLACE] Procedure [Procedure_name]
( argument1 [IN|OUT|INOUT] data_type1,
argument2 [IN|OUT|INOUT] date_type2,
... ... )
IS [AS]
... ...
BEGIN
... ...
EXCEPTION
... ...
END;
/ > Compile
DROP Procedure [Procedure_name];

CREATE Procedure [schema_name.]Procedure_name
@parameter1 data_type1 [VARYING결과 집합|DEFAULT|OUT|READONLY],
@parameter2 date_type2 [mode],
... ...
WITH [Option RECOMPILE|ENCRYPTIONCREATE|EXECUTE AS|
AS
... ...
BEGIN
... ...
ERROR 처리
... ...
END;
DROP Procedure [schema_name.]Procedure_name;

-- ORACLE --
SQL> desc dept
Name Null? Type
----------------------------------------- -------- ----------------------------
DEPTNO NOT NULL NUMBER(2) > PK
DNAME VARCHAR2(14)
LOC VARCHAR2(13)
CREATE OR REPLACE Procedure p_DEPT_insert
( v_DEPTNO in number,
v_dname in varchar2,
v_loc in varchar2,
v_result out varchar2)
IS
cnt number := 0;
BEGIN
SELECT COUNT★ INTO CNT
FROM DEPT WHERE DEPTNO = v_DEPTNO
AND ROWNUM = 1;
if cnt > 0 then
v_result := '이미 등록된 부서번호이다';
else
INSERT INTO DEPT (DEPTNO, DNAME, LOC) VALUES (v_DEPTNO, v_dname, v_loc);
COMMIT;
v_result := '입력 완료';
end if;
EXCEPTION
WHEN OTHERS THEN
ROLLBACK;
v_result := 'ERROR 발생';
END;
/
SQL> /
Procedure created.
-- SQL Server --
CREATE Procedure dbo.p_DEPT_insert
@v_DEPTNO int,
@v_dname varchar(30),
@v_loc varchar(30),
@v_result varchar(100) OUTPUT
AS
DECLARE @cnt int
SET @cnt = 0
BEGIN
SELECT @cnt=COUNT★
FROM DEPT
WHERE DEPTNO = @v_DEPTNO
IF @cnt > 0
BEGIN
SET @v_result = '이미 등록된 부서번호이다'
RETURN
END
ELSE
BEGIN
BEGIN TRAN
INSERT INTO DEPT (DEPTNO, DNAME, LOC)
VALUES (@v_DEPTNO, @v_dname, @v_loc)
IF @@ERROR<>0
BEGIN
ROLLBACK
SET @v_result = 'ERROR 발생'
RETURN
END
ELSE
BEGIN
COMMIT
SET @v_result = '입력 완료!!'
RETURN
END
END
END
-- 실행 결과
-- ORACLE --
SQL> select * from dept;
DEPTNO DNAME LOC
---------- ---------------------------- --------------------------
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON
SQL> variable rslt varchar2(30);
SQL> exec p_dept_insert(10,'dev','seoul',:rslt);
PL/SQL 처리가 정상적으로 완료되었습니다.
SQL> print rslt;
RSLT
--------------------------------------------------------------------------------
이미 등록된 부서번호이다
SQL> exec p_dept_insert(50,'NewDev','seoul',:rslt);
PL/SQL 처리가 정상적으로 완료되었습니다.
SQL> print rslt;
RSLT
--------------------------------------------------------------------------------
입력 완료
SQL> select * from dept;
DEPTNO DNAME LOC
---------- ---------------------------- --------------------------
50 NewDev seoul
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON
-- SQL Server --
select * from dept;
DEPTNO DNAME LOC
------- -------- ---------
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON
DECALRE @v_result VARCHAR(100)
EXECUTE dbo.p_DEPT_insert 10, 'dev', 'seoul',
@v_result=@v_result OUTPUT
SELECT @v_result AS RSLT
RSLT
--------------------------------
이미 등록된 부서번호이다
DECALRE @v_result VARCHAR(100)
EXECUTE dbo.p_DEPT_insert 50, 'dev', 'seoul',
@v_result=@v_result OUTPUT
⑥ SELECT @v_result AS RSLT
RSLT
--------------------------------
입력 완료!
SELECT * FROM DEPT;
DEPTNO DNAME LOC
------- -------- ---------
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON
50 NewDev SEOUL
5개의 행에서 선택되었다.
-- ORACLE --
CREATE OR REPLACE Function UTIL_ABS
(v_input in number)
return NUMBER IS v_return number := 0;
BEGIN
if v_input < 0 then
v_return := v_input * -1;
else
v_return := v_input; end if;
RETURN v_return;
END; /
SELECT SCHE_DATE 경기일자,
HOMETEAM_ID || ' - ' || AWAYTEAM_ID 팀들,
HOME_SCORE || ' - ' || AWAY_SCORE SCORE,
UTIL_ABS(HOME_SCORE - AWAY_SCORE) 점수차
FROM SCHEDULE
WHERE GUBUN = 'Y'
AND SCHE_DATE BETWEEN '20120801' AND '20120831'
ORDER BY SCHE_DATE;
-- SQL Server --
CREATE Function dbo.UTIL_ABS
(@v_input int)
RETURNS int
AS
BEGIN
DECLARE @v_return int
SET @v_return=0
IF @v_input < 0
SET @v_return = @v_input * -1
ELSE
SET @v_return = @v_input
RETURN @v_return;
END
SELECT SCHE_DATE 경기일자,
HOMETEAM_ID + ' - ' + AWAYTEAM_ID AS 팀들,
HOME_SCORE + ' - ' + AWAY_SCORE AS SCORE,
dbo.UTIL_ABS(HOME_SCORE - AWAY_SCORE) AS 점수차
FROM SCHEDULE WHERE GUBUN = 'Y'
AND SCHE_DATE
BETWEEN '20120801' AND '20120831'
ORDER BY SCHE_DATE;
-- ORACLE --
SQL> CREATE TABLE ORDER_LIST (
ORDER_DATE CHAR(8) NOT NULL,
PRODUCT VARCHAR2(10) NOT NULL,
QTY NUMBER NOT NULL,
AMOUNT NUMBER NOT NULL);
테이블이 생성되었습니다.
SQL> CREATE TABLE SALES_PER_DATE (
SALE_DATE CHAR(8) NOT NULL,
PRODUCT VARCHAR2(10) NOT NULL,
QTY NUMBER NOT NULL,
AMOUNT NUMBER NOT NULL);
테이블이 생성되었습니다.
SQL> CREATE OR REPLACE Trigger SUMMARY_SALES
AFTER INSERT
ON ORDER_LIST
FOR EACH ROW
DECLARE
o_date ORDER_LIST.order_date%TYPE;
o_prod ORDER_LIST.product%TYPE;
BEGIN
o_date := :NEW.order_date;
o_prod := :NEW.product;
UPDATE SALES_PER_DATE
SET qty = qty + :NEW.qty,
amount = amount + :NEW.amount
WHERE sale_date = o_date
AND product = o_prod;
if SQL%NOTFOUND then
INSERT INTO SALES_PER_DATE
VALUES(o_date, o_prod, :NEW.qty, :NEW.amount);
end if;
END;
/
트리거가 생성되었습니다.
SQL>
/
| 구분 | :OLD | :NEW |
|---|---|---|
| Insert | NULL | 입력된 레코드 값 |
| Update | UPDATE 되기 전의 레코드의 값 | UPDATE 된 후의 레코드 값 |
| Delete | 레코드가 삭제되기 전 값 | NULL |
SQL> SELECT * FROM ORDER_LIST;
선택된 레코드가 없습니다.
SQL> SELECT * FROM SALES_PER_DATE;
선택된 레코드가 없습니다.
SQL> INSERT INTO ORDER_LIST VALUES('20120901', 'MONOPACK', 10, 300000);
1 개의 행이 만들어졌습니다.
SQL> commit;
커밋이 완료되었습니다.
SQL> SELECT * FROM ORDER_LIST;
ORDER_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
SQL> SELECT * FROM SALES_PER_DATE;
SALE_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
SQL> INSERT INTO ORDER_LIST VALUES('20120901','MONOPACK',20,600000);
1 개의 행이 만들어졌습니다.
SQL> commit;
커밋이 완료되었습니다.
SQL> SELECT * FROM ORDER_LIST;
ORDER_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
20120901 MONOPACK 20 600000
SQL> SELECT * FROM SALES_PER_DATE;
SALE_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 30 900000
SQL> INSERT INTO ORDER_LIST VALUES('20120901','MULTIPACK',10,300000);
1 개의 행이 만들어졌습니다.
SQL> SELECT * FROM ORDER_LIST;
ORDER_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
20120901 MONOPACK 20 600000
20120901 MULTIPACK 10 300000
SQL> SELECT * FROM SALES_PER_DATE;
SALE_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 30 900000
20120901 MULTIPACK 10 300000
SQL> rollback;
롤백이 완료되었습니다.
SQL> SELECT * FROM ORDER_LIST;
ORDER_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
20120901 MONOPACK 20 600000
SQL> SELECT * FROM SALES_PER_DATE;
SALE_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 30 900000
SQL>
-- SQL Server --
CREATE TABLE ORDER_LIST (
ORDER_DATE CHAR(8) NOT NULL,
PRODUCT VARCHAR(10) NOT NULL,
QTY INT NOT NULL,
AMOUNT INT NOT NULL);
CREATE TABLE SALES_PER_DATE (
SALE_DATE CHAR(8) NOT NULL,
PRODUCT VARCHAR(10) NOT NULL,
QTY INT NOT NULL,
AMOUNT INT NOT NULL);
CREATE Trigger dbo.SUMMARY_SALES
ON ORDER_LIST
AFTER INSERT
AS
DECLARE
@o_date DATETIME,@o_prod INT,@qty int, @amount int
BEGIN
SELECT @o_date=order_date, @o_prod=product, @qty=qty, @amount=amount
FROM inserted
UPDATE SALES_PER_DATE
SET qty = qty + @qty,
amount = amount + @amount
WHERE sale_date = @o_date
AND product = @o_prod;
IF @@ROWCOUNT=0
INSERT INTO SALES_PER_DATE
VALUES(@o_date, @o_prod, @qty, @amount)
END
| 구분 | deleted | :nserted는 |
|---|---|---|
| Insert | NULL | 입력된 레코드 값 |
| Update | UPDATE 되기 전의 레코드의 값 | UPDATE 된 후의 레코드 값 |
| Delete | 레코드가 삭제되기 전 값 | NULL |
-- SQL Server --
SELECT * FROM ORDER_LIST;
선택된 레코드가 없습니다.
SELECT * FROM SALES_PER_DATE;
선택된 레코드가 없습니다.
INSERT INTO ORDER_LIST VALUES('20120901', 'MONOPACK', 10, 300000);
1 개의 행이 만들어졌습니다.
SELECT * FROM ORDER_LIST;
ORDER_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
SELECT * FROM SALES_PER_DATE;
SALE_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
INSERT INTO ORDER_LIST VALUES('20120901','MONOPACK',20,600000);
1 개의 행이 만들어졌습니다.
SQL> commit;
커밋이 완료되었습니다.
SELECT * FROM ORDER_LIST;
ORDER_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
20120901 MONOPACK 20 600000
SELECT * FROM SALES_PER_DATE;
SALE_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 30 900000
BEGIN TRAN
INSERT INTO ORDER_LIST VALUES('20120901','MULTIPACK',10,300000);
1 개의 행이 만들어졌습니다.
SELECT * FROM ORDER_LIST;
ORDER_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
20120901 MONOPACK 20 600000
20120901 MULTIPACK 10 300000
SELECT * FROM SALES_PER_DATE;
SALE_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 30 900000
20120901 MULTIPACK 10 300000
rollback;
롤백이 완료되었습니다.
SELECT * FROM ORDER_LIST;
ORDER_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 10 300000
20120901 MONOPACK 20 600000
SELECT * FROM SALES_PER_DATE;
SALE_DATE PRODUCT QTY AMOUNT
---------------- -------------------- ---------- ----------
20120901 MONOPACK 30 900000
| 프로시저 | 트리거 |
|---|---|
| Create Procedure 문법사용 | Create Trigger 문법사용 |
| Execute 명령어로 실행 | 생성 후 자동으로 실행 |
| Commit , rollback 실행가능 | Commit, Rollback 실행 안됨 |