关联数组定义和初始化
最近更新时间: 2025-02-18 16:02:00
示例:
由不同类型索引的关联数组类型
set enable_oracle_compatible=on;
drop table dept cascade;
CREATE TABLE DEPT
(DEPTNO NUMBER(2) CONSTRAINT PK_DEPT PRIMARY KEY,
DNAME VARCHAR2(14) ,
LOC VARCHAR2(13) ) ;
drop table emp cascade;
CREATE TABLE EMP
(EMPNO NUMBER(4) CONSTRAINT PK_EMP PRIMARY KEY,
ENAME VARCHAR2(10),
JOB VARCHAR2(9),
MGR NUMBER(4),
HIREDATE DATE,
SAL NUMBER(7,2),
COMM NUMBER(7,2),
DEPTNO NUMBER(2));
INSERT INTO DEPT VALUES
(10,'ACCOUNTING','NEW YORK');
INSERT INTO DEPT VALUES (20,'RESEARCH','DALLAS');
INSERT INTO DEPT VALUES
(30,'SALES','CHICAGO');
INSERT INTO DEPT VALUES
(40,'OPERATIONS','BOSTON');
INSERT INTO EMP VALUES
(7369,'SMITH','CLERK',7902,to_date('17-12-1980','dd-mm-yyyy'),800,NULL,20);
INSERT INTO EMP VALUES
(7499,'ALLEN','SALESMAN',7698,to_date('20-2-1981','dd-mm-yyyy'),1600,300,30);
INSERT INTO EMP VALUES
(7521,'WARD','SALESMAN',7698,to_date('22-2-1981','dd-mm-yyyy'),1250,500,30);
INSERT INTO EMP VALUES
(7566,'JONES','MANAGER',7839,to_date('2-4-1981','dd-mm-yyyy'),2975,NULL,20);
INSERT INTO EMP VALUES
(7654,'MARTIN','SALESMAN',7698,to_date('28-9-1981','dd-mm-yyyy'),1250,1400,30);
INSERT INTO EMP VALUES
(7698,'BLAKE','MANAGER',7839,to_date('1-5-1981','dd-mm-yyyy'),2850,NULL,30);
INSERT INTO EMP VALUES
(7782,'CLARK','MANAGER',7839,to_date('9-6-1981','dd-mm-yyyy'),2450,NULL,10);
INSERT INTO EMP VALUES
(7788,'SCOTT','ANALYST',7566,to_date('19-04-1987','dd-mm-yyyy'),3000,NULL,20);
INSERT INTO EMP VALUES
(7839,'KING','PRESIDENT',NULL,to_date('17-11-1981','dd-mm-yyyy'),5000,NULL,10);
INSERT INTO EMP VALUES
(7844,'TURNER','SALESMAN',7698,to_date('8-9-1981','dd-mm-yyyy'),1500,0,30);
INSERT INTO EMP VALUES
(7876,'ADAMS','CLERK',7788,to_date('23-05-1987', 'dd-mm-yyyy'),1100,NULL,20);
INSERT INTO EMP VALUES
(7900,'JAMES','CLERK',7698,to_date('3-12-1981','dd-mm-yyyy'),950,NULL,30);
INSERT INTO EMP VALUES
(7902,'FORD','ANALYST',7566,to_date('3-12-1981','dd-mm-yyyy'),3000,NULL,20);
INSERT INTO EMP VALUES
(7934,'MILLER','CLERK',7782,to_date('23-1-1982','dd-mm-yyyy'),1300,NULL,10);
drop table bonus cascade;
CREATE TABLE BONUS
(
ENAME VARCHAR2(10) ,
JOB VARCHAR2(9) ,
SAL NUMBER,
COMM NUMBER
) ;
drop table salgrade cascade;
CREATE TABLE SALGRADE
( GRADE NUMBER,
LOSAL NUMBER,
HISAL NUMBER );
INSERT INTO SALGRADE VALUES (1,700,1200);
INSERT INTO SALGRADE VALUES (2,1201,1400);
INSERT INTO SALGRADE VALUES (3,1401,2000);
INSERT INTO SALGRADE VALUES (4,2001,3000);
INSERT INTO SALGRADE VALUES (5,3001,9999);
-- TestPoint : Associative array with different index type
DECLARE
TYPE aa_type IS TABLE OF INTEGER INDEX BY PLS_INTEGER;
TYPE bb_type IS TABLE OF number(6,2) INDEX BY VARCHAR2(2);
TYPE cc_type IS TABLE OF char(5) INDEX BY VARCHAR(2);
TYPE dd_type IS TABLE OF date INDEX BY long;
aa aa_type; -- associative array
bb bb_type;
cc cc_type;
dd dd_type;
BEGIN
aa(1):=3;
aa(2):=6;
perform dbms_output.serveroutput('t');
--raise notice '%,%',aa.count,aa.limit;
perform DBMS_OUTPUT.PUT('aa.COUNT = ');
perform DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(aa.COUNT), 'NULL'));
perform DBMS_OUTPUT.PUT('aa.LIMIT = ');
perform DBMS_OUTPUT.PUT_LINE(NVL(to_char(aa.LIMIT), 'NULL'));
bb('a'):=1.1;
bb('b'):=2.222;
raise notice '%',bb.count;
raise notice '%,%',bb('a'),bb('b');
cc('a'):='chqin';
cc('b'):='tbase';
raise notice '%',bb.count;
raise notice '%,%',cc('a'),cc('b');
dd('a'):=to_date('2021-09-23 15:12:55','yyyy-mm-dd hh24:mi:ss');
dd('b'):=to_date('2021-09-24 15:12:55','yyyy-mm-dd hh24:mi:ss');
raise notice '%',bb.count;
raise notice '%,%',dd('a'),dd('b');
end;
/
-- TestPoint : Associative Array index type long
declare
TYPE population IS TABLE OF long INDEX BY long;
myvar population; -- Associative array variable
i long; -- Scalar variable
BEGIN
raise notice 'Begin Count=%', myvar.COUNT;
myvar('v1') := 'v1';
myvar('v2') := 'v2';
raise notice 'Initialed Count=%', myvar.COUNT;
raise notice 'Print first to last';
i := myvar.FIRST();
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.NEXT(i);
END LOOP;
end;
/
-- TestPoint : Associative Array index type varchar
declare
TYPE population IS TABLE OF long raw INDEX BY varchar(20);
myvar population; -- Associative array variable
i varchar(20); -- Scalar variable
BEGIN
raise notice 'Begin Count=%', myvar.COUNT;
myvar('1') := '2000';
myvar('2') := '750000';
myvar('3') := '1000000';
myvar('4') := '2001';
myvar('5') := '20210617';
myvar('10') := '20210618';
raise notice 'Initialed Count=%', myvar.COUNT;
raise notice 'Print first to last';
i := myvar.FIRST();
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.NEXT(i);
END LOOP;
IF myvar.EXISTS('12') THEN
raise notice 'myvar(''12'') is exist';
ELSE
raise notice 'myvar(''12'') is not exist';
END IF;
myvar('12') := '1001';
raise notice 'INSERT (''12'') = 1001, COUNT=%', myvar.COUNT;
IF myvar.EXISTS('12') THEN
raise notice 'myvar(''12'') is exist';
ELSE
raise notice 'myvar(''12'') is not exist';
END IF;
myvar('20') := '30006';
raise notice 'Print last to first';
i := myvar.LAST;
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.PRIOR(i);
END LOOP;
raise notice 'End Count=%', myvar.COUNT;
END;
/
-- TestPoint : Associative Array : nclob type index of PLS_INTEGER
declare
TYPE population IS TABLE OF nclob INDEX BY PLS_INTEGER;
myvar population; -- Associative array variable
i PLS_INTEGER; -- Scalar variable
BEGIN
raise notice 'Begin Count=%', myvar.COUNT;
myvar(1) := '2000';
myvar(2) := '750000';
myvar(3) := '1000000';
myvar(4) := '2001';
myvar(5) := '20210617';
myvar(10) := '20210618';
raise notice 'Initialed Count=%', myvar.COUNT;
raise notice 'Print first to last';
i := myvar.FIRST();
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.NEXT(i);
END LOOP;
IF myvar.EXISTS(12) THEN
raise notice 'myvar(''12'') is exist';
ELSE
raise notice 'myvar(''12'') is not exist';
END IF;
myvar(12) := '1001';
raise notice 'INSERT (''12'') = 1001, COUNT=%', myvar.COUNT;
IF myvar.EXISTS(12) THEN
raise notice 'myvar(''12'') is exist';
ELSE
raise notice 'myvar(''12'') is not exist';
END IF;
myvar(20) := '30006';
raise notice 'Print last to first';
i := myvar.LAST;
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.PRIOR(i);
END LOOP;
raise notice 'End Count=%', myvar.COUNT;
END;
/
declare
v1 string(20);
begin
v1:='v';
end;
/
-- TestPoint : Associative Array : emp.ename%type type index of PLS_INTEGER
declare
TYPE population IS TABLE OF emp.ename%type INDEX BY PLS_INTEGER;
myvar population; -- Associative array variable
i PLS_INTEGER; -- Scalar variable
v1 emp.ename%type;
BEGIN
select ename into v1 from emp where empno=7788;
myvar(1):=v1;
select ename into v1 from emp where empno=7521;
myvar(2):=v1;
raise notice '%',myvar(1);
i := myvar.FIRST();
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.NEXT(i);
END LOOP;
end;
/
-- TestPoint : Associative Array : emp.hiredate%type type index of varchar2(20)
-- ERROR: input value length is 40; too long for type varchar2(10)
declare
TYPE population IS TABLE OF emp.hiredate%type INDEX BY varchar2(10);
myvar population; -- Associative array variable
-- i varchar2(10); -- Scalar variable
i emp.ename%type;
v1 emp.ename%type;
v2 emp.hiredate%type;
BEGIN
raise notice 'Begin Count=%', myvar.COUNT;
select ename,hiredate into v1,v2 from emp where empno=7788;
myvar(v1) := v2;
select ename,hiredate into v1,v2 from emp where empno=7521;
myvar(v1) := v2;
raise notice 'Initialed Count=%', myvar.COUNT;
raise notice 'Print first to last';
i := myvar.FIRST();
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.NEXT(i);
END LOOP;
IF myvar.EXISTS('12') THEN
raise notice 'myvar(''12'') is exist';
ELSE
raise notice 'myvar(''12'') is not exist';
END IF;
raise notice 'Print last to first';
i := myvar.LAST;
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.PRIOR(i);
END LOOP;
END;
/
-- TestPoint : Associative Array with table columns: varchar2 index by varchar2
drop table if exists chqin;
create table chqin (f1 varchar2(10), f2 varchar2(20));
insert into chqin values('1','tbase1');
insert into chqin values('2','tbase2');
declare
TYPE population IS TABLE OF chqin.f2%type INDEX BY varchar2(20);
myvar population; -- Associative array variable
i varchar2(10); -- Scalar variable
v1 chqin.f1%type;
v2 chqin.f2%type;
BEGIN
raise notice 'Begin Count=%', myvar.COUNT;
select f1,f2 into v1,v2 from chqin where f1='1';
myvar(v1) := v2;
select f1,f2 into v1,v2 from chqin where f1='2';
myvar(v1) := v2;
raise notice 'Initialed Count=%', myvar.COUNT;
raise notice 'Print first to last';
i := myvar.FIRST();
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.NEXT(i);
END LOOP;
IF myvar.EXISTS('12') THEN
raise notice 'myvar(''12'') is exist';
ELSE
raise notice 'myvar(''12'') is not exist';
END IF;
raise notice 'Print last to first';
i := myvar.LAST;
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.PRIOR(i);
END LOOP;
END;
/
drop table if exists chqin;
-- TestPoint : Associative Array with table columns
drop table if exists chqin;
create table chqin (f1 varchar2(10), f2 long,f3 nclob,f4 interval year to month,f5 timestamp(6) with local time zone,f6 raw(8),f7 nchar(6));
insert into chqin values('1','tbase1','tbase1',interval '3-2' year to month, '2021-06-22 16:02:07.067',utl_raw.cast_to_raw('raw1'),'tbase1');
insert into chqin values('2','tbase2','tbase2',interval '4-2' year to month, '2021-07-22 16:02:07.067',utl_raw.cast_to_raw('raw2'),'tbase2');
-- TestPoint : Associative Array: varchar2 index by long --core dump
declare
TYPE population IS TABLE OF chqin.f1%type INDEX BY long;
myvar population; -- Associative array variable
i long; -- Scalar variable
v1 chqin.f1%type;
v2 chqin.f2%type;
BEGIN
raise notice 'Begin Count=%', myvar.COUNT;
select f1,f2 into v1,v2 from chqin where f1='1';
myvar(v2) := v1;
select f1,f2 into v1,v2 from chqin where f1='2';
myvar(v2) := v1;
raise notice 'Initialed Count=%', myvar.COUNT;
raise notice 'Print first to last';
i := myvar.FIRST();
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.NEXT(i);
END LOOP;
end;
/
-- TestPoint : Associative Array: nclob index by long --core
declare
TYPE population IS TABLE OF chqin.f3%type INDEX BY long;
myvar population; -- Associative array variable
i long; -- Scalar variable
v1 chqin.f1%type;
v2 chqin.f2%type;
BEGIN
raise notice 'Begin Count=%', myvar.COUNT;
select f3,f2 into v1,v2 from chqin where f1='1';
myvar(v2) := v1;
select f3,f2 into v1,v2 from chqin where f1='2';
myvar(v2) := v1;
raise notice 'Initialed Count=%', myvar.COUNT;
raise notice 'Print first to last';
i := myvar.FIRST();
WHILE i IS NOT NULL LOOP
raise notice 'Loop[%] is %',i, myvar(i);
i := myvar.NEXT(i);
END LOOP;
end;
/