Skip to content

Commit b60867a

Browse files
authored
Merge pull request #158 from bigplaice/en_rowtype
Add english doc for %Rowtype feature
2 parents 3f166bb + ea29c95 commit b60867a

File tree

3 files changed

+298
-0
lines changed

3 files changed

+298
-0
lines changed

EN/modules/ROOT/nav.adoc

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,7 @@
2323
*** xref:master/6.3.1.adoc[like]
2424
*** xref:master/6.3.3.adoc[RowID]
2525
*** xref:master/6.3.2.adoc[OUT Parameter]
26+
*** xref:master/6.3.4.adoc[%Type & %Rowtype]
2627
** xref:master/6.4.adoc[GB18030 Character Set]
2728
* List of Oracle compatible features
2829
** xref:master/7.1.adoc[1、Ivorysql frame design]
@@ -40,6 +41,7 @@
4041
** xref:master/7.13.adoc[13、Invisible Columns]
4142
** xref:master/7.14.adoc[14、RowID Column]
4243
** xref:master/7.15.adoc[15、OUT Parameter]
44+
** xref:master/7.16.adoc[16、%Type & %Rowtype]
4345
* xref:master/8.adoc[Community contribution]
4446
* xref:master/9.adoc[Tool Reference]
4547
* xref:master/10.adoc[FAQ]
Lines changed: 102 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,102 @@
1+
:sectnums:
2+
:sectnumlevels: 5
3+
4+
:imagesdir: ./_images
5+
6+
= %ROWTYPE、%TYPE
7+
8+
== Purpose
9+
10+
IvorySQL provides Oracle-compatible PL/SQL data type functionality, including %TYPE and %ROWTYPE.
11+
12+
== Implementation description
13+
14+
=== If the reference changes, variables declared with %TYPE or %ROWTYPE will change accordingly
15+
16+
This is a passive process. The current implementation records the dependency between functions (stored procedures) and tablename.columnname. When the referenced type changes, the function (stored procedure) cache is invalidated based on this dependency. As a result, when the function is called, it undergoes forced compilation, ensuring that the function retrieves the latest variable type.
17+
18+
A field named `prostatus` is added to the system table `pg_proc` to indicate the status of a function (stored procedure), with three possible states: validate (v), invalidate (i), and N/A (n). After a function is successfully compiled, this status is set to valid.
19+
20+
When parsing function content, the functions `plisql_parse_cwordtype`, `plisql_parse_wordrowtype`, and `plisql_parse_cwordrowtype` identify objects referenced by %TYPE and %ROWTYPE, record them in the `plisql_referenced_object` linked list, and finally add them to the `pg_depend` system table.
21+
22+
Add a new dependency type, DEPENDENCY_TYPE = 't', to represent %TYPE or %ROWTYPE dependencies. When adding object reference relationships to the `pg_depend` system table, set the dependency type to 't'.
23+
24+
When performing operations on a table (such as modifying the table type or deleting the table), check the `pg_depend` system table. If there exists a dependency type `deptype='t'` and the dependent object is a function, call the `plisql_free_function` function to clear the function cache and update the function status `prostatus` in the `pg_proc` system table to N/A (n).
25+
26+
27+
=== Variables declared with %TYPE inherit the constraints of the referenced variable.
28+
29+
Add bool notnull member in structure PLiSQL_type;
30+
31+
```
32+
/*
33+
* Postgres data type
34+
*/
35+
typedef struct PLiSQL_type
36+
{
37+
bool notnull; /* the type is built by variable%type,
38+
* isnull or notnull of the variable */
39+
```
40+
41+
In the `plisql_parse_wordtype` or `plisql_parse_cwordtype` functions responsible for parsing %TYPE type functions, determine if the referenced variable type specifies a NOT NULL constraint, and set the `bool notnull` attribute of the returned `datatype` member to `true`. In the `decl_statement` grammar of the `pl_gram.y` file, assign the `notnull` attribute of the `PLiSQL_variable *var` variable based on the `bool notnull` member of `PLiSQL_type`. This way, the constraints of the referenced variable are inherited.
42+
43+
44+
=== Use table_name%ROWTYPE or view_name%ROWTYPE as the parameter type of a function / stored procedure or the return type of a function
45+
46+
Add support of %ROWTYPE for func_type in ora_gram.y
47+
48+
```
49+
| type_function_name attrs '%' ROWTYPE
50+
{
51+
$$ = makeTypeNameFromNameList(lcons(makeString($1), $2));
52+
$$->row_type = true;
53+
$$->location = @1;
54+
}
55+
```
56+
57+
Add a member `bool row_type` to the `TypeName` struct to indicate whether %ROWTYPE is specified.
58+
59+
```
60+
typedef struct TypeName
61+
{
62+
bool pct_type; /* %TYPE specified? */
63+
bool row_type; /* %ROWTYPE specified? */
64+
```
65+
66+
In the `LookupTypeName` function, if the `row_type` member of `TypeName` is `TRUE`, obtain the schema name and table name from the `names` member of `TypeName`, and then retrieve the table's `typeoid`.
67+
68+
=== Enhancement to INSERT statement
69+
70+
In `ora_gram.y`, add new syntax to support `VALUES` without requiring parentheses '(' afterward.
71+
72+
```
73+
values_clause_no_parens:
74+
VALUES columnref
75+
{
76+
SelectStmt *n = makeNode(SelectStmt);
77+
n->valuesLists = list_make1(list_make1($2));
78+
n->valuesIsrow = true;
79+
$$ = (Node *) n;
80+
}
81+
```
82+
83+
Add a field `bool valuesIsrow` to the `SelectStmt` struct to indicate that `values` is a row.
84+
85+
When the `transformInsertStmt` function processes the `INSERT ... VALUES` statement, if `valuesIsrow` is `true`, calls the new function `transformRowExpression` to convert `row_variable` into the equivalent `row_variable.field1, ..., row_variable.fieldN`.
86+
87+
=== Enhancement to UPDATE statement
88+
89+
When transforming an UPDATE statement, i.e., when calling the `transformUpdateStmt` function, if in Oracle compatibility mode, invoke the newly added `transformIvyUpdateTargetList` function. In this new function, for cases where the `origTlist` (i.e., `targetList`) does not contain a name of `row`, execute the `transformUpdateTargetList` function following the original UPDATE transform process.
90+
91+
For cases where the `origTlist` parameter contains a name `row`, since `row` can be used as a column name in PostgreSQL but is a reserved keyword in Oracle and cannot be used as a column name, it is necessary to determine whether `row` is a column in the table being updated. If `row` is not a column in the table to be updated, call the new function `transformUpdateRowTargetList` to convert the sql statement
92+
```
93+
UPDATE table_name SET ROW = row_variable [WHERE …];
94+
```
95+
into equivalent
96+
```
97+
UPDATE table_name SET table_name.column1 = row_variable.column1, table_name.column2 = row_variable.filed2,… table_name.columnN = row_variable.columnN [WHERE …];
98+
```
99+
100+
If the variable `row_variable` in the statement `UPDATE table_name SET ROW = row_variable` is not a composite type, execute the `transformUpdateTargetList` function following the original UPDATE transform process.
101+
If the variable `row_variable` in the statement is a composite type, the column named `row` in the table is also a composite type, and their type OIDs match, execute the `transformUpdateTargetList` function following the original UPDATE transform process.
102+
In all other cases, call the new function `transformUpdateRowTargetList` for processing.
Lines changed: 194 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,194 @@
1+
:sectnums:
2+
:sectnumlevels: 5
3+
4+
:imagesdir: ./_images
5+
6+
= %ROWTYPE、%TYPE
7+
8+
== Purpose
9+
10+
IvorySQL provides Oracle-compatible PL/SQL data type functionality, including %TYPE and %ROWTYPE.
11+
12+
This document aims to introduce users to the functionality of %TYPE and %ROWTYPE.
13+
14+
== Function descriptions
15+
16+
IvorySQL provides Oracle-compatible %TYPE and %ROWTYPE functionality, including the following content.
17+
18+
=== If the reference changes, variables declared with %TYPE or %ROWTYPE will change accordingly.
19+
20+
Create table and function.
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+
The state of function is valid and function can be executed successfully.
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+
Modifying the previously defined declaration of a reference causes the function's status to become invalid, but the function can still execute successfully.
48+
49+
```
50+
ALTER TABLE t1 ALTER COLUMN id TYPE varchar(20);
51+
52+
SELECT prostatus FROM pg_proc WHERE proname like 'fun1'; --n
53+
prostatus
54+
-----------
55+
n
56+
(1 row)
57+
58+
--after changing the column id type from int to varchar, call the function again
59+
SELECT fun1('a') FROM dual; --successfully
60+
fun1
61+
------
62+
a
63+
(1 row)
64+
```
65+
66+
re-compile the function, its state become valid.
67+
```
68+
ALTER FUNCTION fun1 COMPILE;
69+
SELECT prostatus FROM pg_proc WHERE proname like 'fun1'; --v
70+
prostatus
71+
-----------
72+
v
73+
(1 row)
74+
```
75+
76+
=== Variables declared with %TYPE inherit the constraints of the referenced variable.
77+
78+
Example:
79+
```
80+
--the following testcase will fail
81+
DECLARE
82+
name VARCHAR(25) NOT NULL := 'Niu';
83+
surname name%TYPE ;
84+
BEGIN
85+
raise notice 'name=%' ,name;
86+
raise notice 'surname=%' ,surname;
87+
END;
88+
/
89+
90+
ERROR: variable "surname" must have a default value, since it's declared NOT NULL
91+
LINE 3: surname name%TYPE ;
92+
^
93+
```
94+
95+
=== Use table_name%ROWTYPE or view_name%ROWTYPE as the parameter type of a function / stored procedure or the return type of a function
96+
97+
Example:
98+
```
99+
CREATE TABLE employees(first_name varchar(20) not null,
100+
last_name varchar(20) not null,
101+
phone_number varchar(50));
102+
103+
INSERT INTO employees VALUES ('Steven','Niu','1-650-555-1234');
104+
105+
CREATE OR REPLACE PROCEDURE p0(v employees%ROWTYPE) AS
106+
BEGIN
107+
raise notice 'v.first_name = %, v.last_name = %, v.phone_number = %',
108+
v.first_name, v.last_name, v.phone_number;
109+
END;
110+
/
111+
112+
DECLARE
113+
a employees%ROWTYPE;
114+
BEGIN
115+
select * into a from employees ;
116+
raise notice 'a=%', a;
117+
call p0(a);
118+
END;
119+
/
120+
121+
NOTICE: a=(Steven,Niu,1-650-555-1234)
122+
NOTICE: v.first_name = Steven, v.last_name = Niu, v.phone_number = 1-650-555-1234
123+
124+
\df p0
125+
List of functions
126+
Schema | Name | Result data type | Argument data types | Type
127+
--------+------+------------------+------------------------+------
128+
public | p0 | | IN v employees%ROWTYPE | proc
129+
(1 row)
130+
```
131+
132+
=== Enhancement to INSERT statement
133+
134+
Support inserting a variables declared with %TYPE or %ROWTYPE into table.
135+
136+
grammar:
137+
```
138+
INSERT INTO table_name VALUES row_variable ;
139+
```
140+
141+
Example:
142+
```
143+
CREATE TABLE t1(id int, name varchar(20));
144+
145+
DECLARE
146+
v1 t1%ROWTYPE;
147+
BEGIN
148+
FOR i IN 1 .. 5 LOOP
149+
v1.id := i;
150+
v1.name := 'a' || i;
151+
INSERT INTO t1 VALUES v1;
152+
END LOOP;
153+
END;
154+
/
155+
156+
157+
SELECT * FROM t1;
158+
id | name
159+
----+------
160+
1 | a1
161+
2 | a2
162+
3 | a3
163+
4 | a4
164+
5 | a5
165+
(5 rows)
166+
```
167+
168+
=== Enhancement to UPDATE statement
169+
170+
example:
171+
```
172+
CREATE TABLE t1(id int, name varchar(20));
173+
174+
DELETE FROM t1;
175+
176+
DECLARE
177+
v1 t1%ROWTYPE;
178+
v2 t1%ROWTYPE;
179+
BEGIN
180+
v1.id := 11;
181+
v1.name := 'abc';
182+
INSERT INTO t1 VALUES v1;
183+
v2.id := 22;
184+
v2.name := 'new';
185+
UPDATE t1 SET ROW = v2;
186+
END;
187+
/
188+
189+
SELECT * FROM t1;
190+
id | name
191+
----+------
192+
22 | new
193+
(1 row)
194+
```

0 commit comments

Comments
 (0)