|
| 1 | +:sectnums: |
| 2 | +:sectnumlevels: 5 |
| 3 | + |
| 4 | +:imagesdir: ./_images |
| 5 | + |
| 6 | += %ROWTYPE、%TYPE |
| 7 | + |
| 8 | +== 目的 |
| 9 | + |
| 10 | +IvorySQL提供了兼容Oracle的plsql数据类型功能,包括%TYPE、%ROWTYPE。 |
| 11 | + |
| 12 | +本文档旨在为使用人员介绍%TYPE、%ROWTYPE的功能。 |
| 13 | + |
| 14 | +== 功能说明 |
| 15 | + |
| 16 | +IvorySQL提供了兼容Oracle的%TYPE、%ROWTYPE功能,包括如下内容。 |
| 17 | + |
| 18 | +=== 引用发生改变,%TYPE或%ROWTYPE声明的变量也相应改变。 |
| 19 | + |
| 20 | +创建表以及函数。 |
| 21 | +``` |
| 22 | +CREATE TABLE t1(id int, name varchar(20)); |
| 23 | + |
| 24 | +--function's parameter datatype is tablename.columnname%TYPE |
| 25 | +CREATE OR REPLACE FUNCTION fun1(v t1.id%TYPE) RETURN varchar AS |
| 26 | +BEGIN |
| 27 | + RETURN v; |
| 28 | +END; |
| 29 | +/ |
| 30 | +``` |
| 31 | + |
| 32 | +函数状态是valid,并且执行函数能够成功。 |
| 33 | +``` |
| 34 | +SELECT prostatus FROM pg_proc WHERE proname like 'fun1'; --v |
| 35 | + prostatus |
| 36 | +----------- |
| 37 | + v |
| 38 | +(1 row) |
| 39 | +
|
| 40 | +SELECT fun1(1) FROM dual; |
| 41 | + fun1 |
| 42 | +------ |
| 43 | + 1 |
| 44 | +(1 row) |
| 45 | +``` |
| 46 | + |
| 47 | +修改引用的先前定义的声明,函数状态变为invalid,但是函数能够执行成功。 |
| 48 | +``` |
| 49 | +ALTER TABLE t1 ALTER COLUMN id TYPE varchar(20); |
| 50 | + |
| 51 | +SELECT prostatus FROM pg_proc WHERE proname like 'fun1'; --n |
| 52 | + prostatus |
| 53 | +----------- |
| 54 | + n |
| 55 | +(1 row) |
| 56 | +
|
| 57 | +--after changing the column id type from int to varchar, call the function again |
| 58 | +SELECT fun1('a') FROM dual; --successfully |
| 59 | + fun1 |
| 60 | +------ |
| 61 | + a |
| 62 | +(1 row) |
| 63 | +``` |
| 64 | + |
| 65 | +重新编译函数,状态重新变成valid。 |
| 66 | +``` |
| 67 | +ALTER FUNCTION fun1 COMPILE; |
| 68 | +SELECT prostatus FROM pg_proc WHERE proname like 'fun1'; --v |
| 69 | + prostatus |
| 70 | +----------- |
| 71 | + v |
| 72 | +(1 row) |
| 73 | +``` |
| 74 | +
|
| 75 | +=== %TYPE声明的变量继承引用变量的约束 |
| 76 | +
|
| 77 | +示例: |
| 78 | +``` |
| 79 | +--the following testcase will fail |
| 80 | +DECLARE |
| 81 | + name VARCHAR(25) NOT NULL := 'Niu'; |
| 82 | + surname name%TYPE ; |
| 83 | +BEGIN |
| 84 | + raise notice 'name=%' ,name; |
| 85 | + raise notice 'surname=%' ,surname; |
| 86 | +END; |
| 87 | +/ |
| 88 | +
|
| 89 | +ERROR: variable "surname" must have a default value, since it's declared NOT NULL |
| 90 | +LINE 3: surname name%TYPE ; |
| 91 | + ^ |
| 92 | +``` |
| 93 | +
|
| 94 | +=== 表名%ROWTYPE或视图名%ROWTYPE作为函数或存储过程的参数类型和函数返回值类型 |
| 95 | +
|
| 96 | +示例: |
| 97 | +``` |
| 98 | +CREATE TABLE employees(first_name varchar(20) not null, |
| 99 | +last_name varchar(20) not null, |
| 100 | +phone_number varchar(50)); |
| 101 | +
|
| 102 | +INSERT INTO employees VALUES ('Steven','Niu','1-650-555-1234'); |
| 103 | +
|
| 104 | +CREATE OR REPLACE PROCEDURE p0(v employees%ROWTYPE) AS |
| 105 | +BEGIN |
| 106 | + raise notice 'v.first_name = %, v.last_name = %, v.phone_number = %', |
| 107 | + v.first_name, v.last_name, v.phone_number; |
| 108 | +END; |
| 109 | +/ |
| 110 | +
|
| 111 | +DECLARE |
| 112 | + a employees%ROWTYPE; |
| 113 | +BEGIN |
| 114 | + select * into a from employees ; |
| 115 | + raise notice 'a=%', a; |
| 116 | + call p0(a); |
| 117 | +END; |
| 118 | +/ |
| 119 | +
|
| 120 | +NOTICE: a=(Steven,Niu,1-650-555-1234) |
| 121 | +NOTICE: v.first_name = Steven, v.last_name = Niu, v.phone_number = 1-650-555-1234 |
| 122 | +
|
| 123 | +\df p0 |
| 124 | + List of functions |
| 125 | + Schema | Name | Result data type | Argument data types | Type |
| 126 | +--------+------+------------------+------------------------+------ |
| 127 | + public | p0 | | IN v employees%ROWTYPE | proc |
| 128 | +(1 row) |
| 129 | +``` |
| 130 | +
|
| 131 | +=== INSERT语句增强 |
| 132 | +
|
| 133 | +INSERT语句增强支持把一个%ROWTYPE声明的变量插入表中。 |
| 134 | +
|
| 135 | +语法为: |
| 136 | +``` |
| 137 | +INSERT INTO table_name VALUES row_variable ; |
| 138 | +``` |
| 139 | +
|
| 140 | +示例: |
| 141 | +``` |
| 142 | +CREATE TABLE t1(id int, name varchar(20)); |
| 143 | +
|
| 144 | +DECLARE |
| 145 | + v1 t1%ROWTYPE; |
| 146 | +BEGIN |
| 147 | + FOR i IN 1 .. 5 LOOP |
| 148 | + v1.id := i; |
| 149 | + v1.name := 'a' || i; |
| 150 | + INSERT INTO t1 VALUES v1; |
| 151 | + END LOOP; |
| 152 | +END; |
| 153 | +/ |
| 154 | +
|
| 155 | +
|
| 156 | +SELECT * FROM t1; |
| 157 | + id | name |
| 158 | +----+------ |
| 159 | + 1 | a1 |
| 160 | + 2 | a2 |
| 161 | + 3 | a3 |
| 162 | + 4 | a4 |
| 163 | + 5 | a5 |
| 164 | +(5 rows) |
| 165 | +``` |
| 166 | +
|
| 167 | +=== UPDATE语句增强 |
| 168 | +
|
| 169 | +示例: |
| 170 | +``` |
| 171 | +CREATE TABLE t1(id int, name varchar(20)); |
| 172 | +
|
| 173 | +DELETE FROM t1; |
| 174 | +
|
| 175 | +DECLARE |
| 176 | + v1 t1%ROWTYPE; |
| 177 | + v2 t1%ROWTYPE; |
| 178 | +BEGIN |
| 179 | + v1.id := 11; |
| 180 | + v1.name := 'abc'; |
| 181 | + INSERT INTO t1 VALUES v1; |
| 182 | + v2.id := 22; |
| 183 | + v2.name := 'new'; |
| 184 | + UPDATE t1 SET ROW = v2; |
| 185 | +END; |
| 186 | +/ |
| 187 | +
|
| 188 | +SELECT * FROM t1; |
| 189 | + id | name |
| 190 | +----+------ |
| 191 | + 22 | new |
| 192 | +(1 row) |
| 193 | +``` |
0 commit comments