diff --git a/CN/modules/ROOT/nav.adoc b/CN/modules/ROOT/nav.adoc index e3c8c3c6..d0f86121 100644 --- a/CN/modules/ROOT/nav.adoc +++ b/CN/modules/ROOT/nav.adoc @@ -26,6 +26,7 @@ **** xref:master/6.3.2.adoc[OUT 参数] **** xref:master/6.3.4.adoc[%TYPE、%ROWTYPE] **** xref:master/6.3.5.adoc[NLS 参数] +**** xref:master/6.3.6.adoc[函数与存储过程] *** xref:master/6.4.adoc[国标GB18030] ** Oracle兼容功能列表 *** xref:master/7.1.adoc[1、框架设计] diff --git a/CN/modules/ROOT/pages/master/6.3.6.adoc b/CN/modules/ROOT/pages/master/6.3.6.adoc new file mode 100644 index 00000000..e9be67a9 --- /dev/null +++ b/CN/modules/ROOT/pages/master/6.3.6.adoc @@ -0,0 +1,261 @@ +:sectnums: +:sectnumlevels: 5 + +:imagesdir: ./_images + += PL/iSQL函数与存储过程 + +== 目的 + +PostgreSQL支持函数(FUNCTION)和存储过程(PROCEDURE),但是在语法上和Oracle有差异,为了让Oracle的PLSQL语句可以在IvorySQL上执行,也就是“语法兼容”,IvorySQL采取这样的解决方案:如果Oracle的子句在IvorySQL中存在相同功能的子句,则直接映射为对应的IvorySQL子句,否则只实现其语法,不实现其功能。 + +== 实现说明 + +PL/iSQL是IvorySQL中的过程语言名称,专门用来兼容Oracle的PLSQL语句。为了兼容Oracle风格的函数与存储过程语法,需要对psql客户端工具、SQL端以及PL/iSQL端做相应处理。 + +=== 客户端工具psql + +Oracle的sqlplus工具使用斜线(/)来结束函数和存储过程,IvorySQL的客户端工具psql需要兼容同样的语法,也就是说我们常规的遇到分号发送语句给服务端的机制,当遇到Oracle风格的函数和存储过程命令时失效,改为使用斜线(/)发送命令。 + +为此在 PsqlScanStateData 结构体中增加如下字段: +``` + bool cancel_semicolon_terminator; /* not send command when semicolon found */ + + /* + * State to track boundaries of Oracle ANONYMOUS BLOCK. + * Case 1: Statements starting with << ident >> is Oracle anonymous block. + */ + int token_count; /* # of tokens, not blank or newline since start of statement */ + bool anonymous_label_start; /* T if the first token is "<<" */ + bool anonymous_label_ident; /* T if the second token is an identifier */ + bool anonymous_label_end; /* T if the third token is ">>" */ + + /* + * Case 2: DECLARE BEGIN ... END is Oracle anonymous block syntax. + * DECLARE can also be a PostgreSQL cursor declaration statement, we need to tell this. + */ + bool maybe_anonymous_declare_start; /* T if the first token is DECLARE */ + int token_cursor_idx; /* the position of keyword CURSOR in SQL statement */ + + /* + * Case 3: DECLARE BEGIN ... END is Oracle anonymous block syntax. + * BEGIN can also be a PostgreSQL transaction statement. + */ + bool maybe_anonymous_begin_start; /* T if the first token is BEGIN */ + +``` + +同时修改 ora_psqlscan.l,添加和修改相应的词法规则, 以下是代码片段示例: +``` +{ + if (is_oracle_slash(cur_state, cur_state->scanline)) + { + /* Terminate lexing temporarily */ + cur_state->cancel_semicolon_terminator = false; + cur_state->maybe_anonymous_declare_start = false; + cur_state->maybe_anonymous_begin_start = false; + cur_state->anonymous_label_start = false; + cur_state->anonymous_label_ident = false; + cur_state->anonymous_label_end = false; + cur_state->start_state = YY_START; + cur_state->token_count = 0; + cur_state->token_cursor_idx = 0; + cur_state->identifier_count = 0; + cur_state->begin_depth = 0; + cur_state->ora_plsql_expect_end_symbol = END_SYMBOL_INVALID; + return LEXRES_SEMI; + } + ECHO; +``` + +Psql工具需要检测斜线/的含义,避免将注释等部分的斜线判定为结束符,为此在oracle_fe_utils/ora_psqlscan.l文件中增加一个单独的接口is_oracle_slash来检测: +``` +bool +is_oracle_slash(PsqlScanState state, const char *line) +{ + bool result = false; + + switch (state->start_state) + { + case INITIAL: + case xqs: /* treat these like INITIAL */ + { + int len, i; + bool has_slash = false; + + len = strlen(line); + for (i = 0; i < len; i++) + { + /* allow special char */ + if (line[i] == '\t' || + line[i] == '\n' || + line[i] == '\r' || + line[i] == ' ') + continue; + + if (line[i] == '/') + { + if (has_slash) + break; + has_slash = true; + continue; + } + /* others */ + break; + } + + if (i == len && has_slash) + result = true; + } + break; + default: + break; + } + + return result; +} + +``` + +=== SQL端 + +SQL端要能够识别函数和存储过程的创建语法,这是通过修改ora_base_yylex来实现的。这个函数预取并缓存token,如果是Oracle语法格式则组织一个SCONST发送给PLSQL端,否则从堆栈中获取之前预读的token,按照原生PG的逻辑进行处理。 + +在ora_base_yy_extra_type数据结构中增加如下字段: +``` + /* + * The native PG only cache one-token info include yylloc, yylval and token + * number in yyextra, IvorySQL cache multiple tokens info using two arrays. + */ + int max_pushbacks; /* the max size of cache array */ + int loc_pushback; /* # of used tokens */ + int num_pushbacks; /* # of cached tokens */ + int *pushback_token; /* token number array */ + TokenAuxData *pushback_auxdata; /* auxdata array */ + + OraBodyStyle body_style; + int body_start; + int body_level; +``` + +增加token堆栈的操作接口: +|==== +| push_back_token +| forward_token +| ora_internal_yylex +| internal_yylex +|==== + +ora_base_yylex函数中在创建函数、过程、匿名块时会预读部分token,使用上述结构缓存到堆栈中,是为了构造一个符合Oracle PL/SQL语法的SCONST发送给PL/iSQL端去处理。具体请参考源代码。 + + +=== PL/iSQL端 + +该部分主要修改了pl_gram.y文件,以兼容PLSQL的函数和存储过程语法,在不影响PG原生的PL/pgSQL的前提下去兼容Oracle PL/SQL语法形式,如下是DECLARE部分兼容的代码示例,更多请参考IvorySQL源代码。 + +``` +/* + * The declaration section of the outermost block in Oracle does not have the DECLARE keyword. + */ +ora_outermost_pl_block: ora_decl_sect K_BEGIN proc_sect exception_sect K_END opt_label + { + PLiSQL_stmt_block *new; + + new = palloc0(sizeof(PLiSQL_stmt_block)); + + new->cmd_type = PLISQL_STMT_BLOCK; + new->lineno = plisql_location_to_lineno(@2); + new->stmtid = ++plisql_curr_compile->nstatements; + new->label = $1.label; + new->n_initvars = $1.n_initvars; + new->initvarnos = $1.initvarnos; + new->body = $3; + new->exceptions = $4; + + check_labels($1.label, $6, @6); + plisql_ns_pop(); + + $$ = (PLiSQL_stmt *)new; + } + ; + +ora_decl_sect: opt_block_label opt_ora_decl_start opt_ora_decl_stmts + { + if ($2) + { + if ($1 == NULL) + { + plisql_ns_push(NULL, PLISQL_LABEL_BLOCK); + } + } + } + opt_ora_decl_stmts + { + if ($4) + { + plisql_IdentifierLookup = IDENTIFIER_LOOKUP_NORMAL; + $$.label = ($1 == NULL ? plisql_curr_compile->namelabel : $1); + if ($2 && $1 == NULL) + $$.popname = true; + else + $$.popname = false; + /* Remember variables declared in decl_stmts */ + $$.n_initvars = plisql_add_initdatums(&($$.initvarnos)); + } + else + { + plisql_IdentifierLookup = IDENTIFIER_LOOKUP_NORMAL; + $$.label = ($1 == NULL ? plisql_curr_compile->namelabel : $1); + $$.n_initvars = 0; + if ($2 && $1 == NULL) + $$.popname = true; + else + $$.popname = false; + $$.initvarnos = NULL; + } + } + ; + +opt_ora_decl_start: K_DECLARE + { + /* Forget any variables created before block */ + plisql_add_initdatums(NULL); + /* + * Disable scanner lookup of identifiers while + * we process the decl_stmts + */ + plisql_IdentifierLookup = IDENTIFIER_LOOKUP_DECLARE; + $$ = true; + } + | /*EMPTY*/ + { + /* Forget any variables created before block */ + plisql_add_initdatums(NULL); + /* + * Disable scanner lookup of identifiers while + * we process the decl_stmts + */ + plisql_IdentifierLookup = IDENTIFIER_LOOKUP_DECLARE; + $$ = false; + } + ; + +opt_ora_decl_stmts: + ora_decl_stmts + { + $$ = true; + } + | /*EMPTY*/ + { + $$ = false; + } + +ora_decl_stmts: ora_decl_stmts ora_decl_stmt + | ora_decl_stmt + ; + +ora_decl_stmt: decl_statement + ; + +``` + diff --git a/CN/modules/ROOT/pages/master/7.7.adoc b/CN/modules/ROOT/pages/master/7.7.adoc index 8801dc41..7d5b97fb 100644 --- a/CN/modules/ROOT/pages/master/7.7.adoc +++ b/CN/modules/ROOT/pages/master/7.7.adoc @@ -3,95 +3,561 @@ :imagesdir: ./_images -= 兼容Oracle函数与存储过程 += PL/iSQL函数与存储过程 == 目的 -- 本文档意在兼容Oracle PLSQL函数和存储过程的语法,在IvorySQL中我们称其为PLISQL语言。 - -== 功能说明 - -.函数(FUNCTION) -|==== -|CREATE FUNCTION语法支持EDITIONABLE/NONEDITIONABLE -|CREATE FUNCTION语法支持RETURN, IS关键字,不指定language -|CREATE FUNCTION语法函数没有参数,函数名后面不带() -|CREATE FUNCTION参数个数最多是32767 -|CREATE FUNCTION语法中END; 在psql中以/结束 -|CREATE FUNCTION语法变量声明前面没有DECLARE关键字 -|CREATE FUNCTION语法支持OUT 参数NOCOPY功能 -|CREATE FUNCTION语法支持sharing_clause -|CREATE FUNCTION语法支持invoker_rights_clause,默认权限改成DR(DEFINER) -|CREATE FUNCTION语法支持ACCESSIBLE BY  -|CREATE FUNCTION语法支持DEFAULT COLLATION -|CREATE FUNCTION语法支持result_cache_clause  -|CREATE FUNCTION语法支持aggregate_clause -|CREATE FUNCTION语法支持pipelined_clause -|CREATE FUNCTION语法支持sql_macro_clause -|ALTER FUNCTION语法 -|函数和存储过程相关的视图 -|==== - - -.存储过程(PROCEDURE) -|==== -|CREATE PROCEDURE语法支持EDITIONABLE/NONEDITIONABLE -|CREATE PROCEDURE语法函数没有参数,函数名后面不带() -|CREATE PROCEDURE参数个数最多是32767 -|CREATE PROCEDURE语法中END; 在psql中以/结束 -|CREATE PROCEDURE语法支持sharing_clause -|CREATE PROCEDURE语法支持DEFAULT COLLATION -|CREATE PROCEDURE语法支持invoker_rights_clause -|CREATE PROCEDURE语法支持ACCESSIBLE BY  -|ALTER PROCEDURE语法 -|存储过程没有参数,调用支持不带() -|存储过程调用支持EXEC -|在PL/SQL 中调用存储过程,可以省略CALL,直接使用存储过程名字 -|支持--和/**/两种注释方法 -|==== - - -== 测试用例 - -``` - -CREATE or replace FUNCTION ora_func RETURN integer AS +PostgreSQL支持函数(FUNCTION)和存储过程(PROCEDURE),但是在语法上和Oracle有差异,为了让Oracle的PLSQL语句可以在IvorySQL上执行,也就是“语法兼容”,IvorySQL采取这样的解决方案:如果Oracle的子句在IvorySQL中存在相同功能的子句,则直接映射为对应的IvorySQL子句,否则只实现其语法,不实现其功能。 + +== 兼容支持 + +具体的Oracle兼容支持包括以下几个方面: + +=== CREATE FUNCTION 语法支持 EDITIONABLE/NONEDITIONABLE + +``` +CREATE or replace EDITIONABLE FUNCTION ora_func RETURN integer AS +BEGIN + RETURN 1; +END; +/ + +CREATE or replace NONEDITIONABLE FUNCTION ora_func RETURN integer IS BEGIN RETURN 1; END; / +``` + +=== CREATE FUNCTION 语法支持 RETURN/IS 关键字,无需指定语言 + +``` +CREATE or replace EDITIONABLE FUNCTION ora_func RETURN integer IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法函数没有参数,函数名后面不带() + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = METADATA +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 参数个数增加,最大值可在configure时指定 + +``` +configure --help + --with-max-funarg=MAXFUNARG +``` + +=== CREATE FUNCTION 语法中 END; 在psql中以/结束 + +``` +CREATE or replace EDITIONABLE FUNCTION ora_func RETURN integer IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法变量声明前面没有 DECLARE 关键字 + +``` +CREATE OR REPLACE +FUNCTION ora_func (num1 IN int, num2 IN int) +RETURN int +AS + num3 int :=10; + num4 int :=10; + num5 int; +BEGIN + num3 := num1 + num2; + num4 := num1 * num2; + num5 := num3 * num4; +RETURN num5; +END; +/ +CREATE FUNCTION -CREATE OR REPLACE FUNCTION test_nocopy(a IN int, b OUT NOCOPY int, c IN OUT NOCOPY int) -RETURN record +select ora_func(5,9)from dual; + ora_func +---------- + 630 +(1 row) +``` + +=== CREATE FUNCTION 语法支持 OUT 参数 NOCOPY 功能 + +``` +CREATE OR REPLACE FUNCTION test_nocopy(a IN int, b OUT NOCOPY int, c IN OUT NOCOPY int) +RETURN int IS BEGIN b := a; - c := a; + c := a; + return 1; +END; +/ +``` + +=== CREATE FUNCTION 语法支持 sharing 子句 + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = METADATA +IS +BEGIN + RETURN 1; +END; +/ + +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE +IS +BEGIN + RETURN 1; END; / +``` + +=== CREATE FUNCTION 语法支持 invoker_rights (AUTHID) 子句,默认权限改成 DR(DEFINER) ``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID CURRENT_USER +IS +BEGIN + RETURN 1; +END; +/ + +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +IS +BEGIN + RETURN 1; +END; +/ ``` -CREATE OR REPLACE PROCEDURE ora_procedure() -AS - p integer := 20; +=== CREATE FUNCTION 语法支持 ACCESSIBLE BY + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER ACCESSIBLE BY ( B ) +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER ACCESSIBLE BY ( A.B ) +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER ACCESSIBLE BY ( FUNCTION A.B ) +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D, PACKAGE E, +TRIGGER F, TYPE G ) +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法支持 DEFAULT COLLATION + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法支持 deterministic 子句,功能与 IvorySQL 的 IMMUTABLE 相同 + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法支持 parallel_enable 子句,功能与 IvorySQL 的 PARALLEL SAFE 相同 + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法支持 result_cache 子句 + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON () +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法支持 aggregate 子句 + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +AGGREGATE USING pg_catalog.int4 +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +AGGREGATE USING int +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法支持 pipelined 子句 + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +AGGREGATE USING int +PIPELINED +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== CREATE FUNCTION 语法支持 sql_macro 子句 + +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +AGGREGATE USING int +PIPELINED TABLE POLYMORPHIC USING pg_catalog.int4 +SQL_MACRO +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== ALTER FUNCTION 语法兼容 + +``` +alter function public.test_func noneditionable; +alter function test_func compile; +alter function test_func compile debug; +alter function test_func compile debug sd = mv; +alter function test_func compile debug reuse settings; +``` + +=== CREATE PROCEDURE 语法支持 EDITIONABLE / NONEDITIONABLE + +``` +CREATE OR REPLACE EDITIONABLE PROCEDURE ora_procedure +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ + +CREATE OR REPLACE NONEDITIONABLE PROCEDURE ora_procedure +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== CREATE PROCEDURE 语法函数没有参数,函数名后面不带() + +``` +CREATE OR REPLACE EDITIONABLE PROCEDURE ora_procedure +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== CREATE PROCEDURE 语法中 END; 在psql中以 / 结束 + +``` +CREATE OR REPLACE PROCEDURE ora_procedure +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== CREATE PROCEDURE 语法支持 sharing 子句 + +``` +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = NONE +IS + p integer := 20; begin - raise notice '%', p; + raise notice '%', p; end; / -call ora_procedure(); +``` + +=== CREATE PROCEDURE 语法支持 DEFAULT COLLATION 子句 +``` +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== CREATE PROCEDURE 语法支持 invoker_rights (AUTHID) 子句 + +``` +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID DEFINER +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== CREATE PROCEDURE 语法支持 ACCESSIBLE BY 子句 + +``` +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( B ) +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( A.B ) +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ CREATE OR REPLACE PROCEDURE ora_procedure SHARING = METADATA DEFAULT COLLATION USING_NLS_COMP AUTHID CURRENT_USER ACCESSIBLE BY ( FUNCTION A.B ) IS - p integer := 20; + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +IS + p integer := 20; begin - raise notice '%', p; + raise notice '%', p; end; / +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D, PACKAGE E, TRIGGER F, TYPE G ) +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` +=== ALTER PROCEDURE 语法兼容 + +``` +alter procedure test_proc editionable; +alter procedure public.test_proc noneditionable; +alter procedure test_proc compile; +alter procedure test_proc compile debug; +alter procedure test_proc compile debug sd = mv; +alter procedure test_proc compile debug reuse settings; +``` + +=== 存储过程和函数没有参数,SELECT调用支持不带 () + +``` +create or replace function f_noparentheses +return int is +begin +return 11; +end; +/ +select f_noparentheses from dual; + +create or replace procedure protest +as +begin +raise notice 'protest'; +end; +/ +CALL protest(); ``` + +=== 函数和存储过程相关的视图 + +``` +相关视图位于文件 contrib/ivorysql_ora/src/sysview/sysview--1.0.sql 中,包括DBA_PROCEDURES,ALL_PROCEDURES,USER_PROCEDURES,DBA_SOURCE,ALL_SOURCE,USER_SOURCE,DBA_ARGUMENTS,ALL_ARGUMENTS,USER_ARGUMENTS等。 +``` + +=== 支持--和/**/两种注释方法 + +=== pg_dump备份SQL脚本文件的备份格式时,在函数的定义最后增加一个斜线 / \ No newline at end of file diff --git a/EN/modules/ROOT/nav.adoc b/EN/modules/ROOT/nav.adoc index 3d42ed18..b046ca05 100644 --- a/EN/modules/ROOT/nav.adoc +++ b/EN/modules/ROOT/nav.adoc @@ -25,6 +25,7 @@ *** xref:master/6.3.2.adoc[OUT Parameter] *** xref:master/6.3.4.adoc[%Type & %Rowtype] *** xref:master/6.3.5.adoc[NLS Parameters] +*** xref:master/6.3.6.adoc[Function and stored procedure] ** xref:master/6.4.adoc[GB18030 Character Set] * List of Oracle compatible features ** xref:master/7.1.adoc[1、Ivorysql frame design] diff --git a/EN/modules/ROOT/pages/master/6.3.6.adoc b/EN/modules/ROOT/pages/master/6.3.6.adoc new file mode 100644 index 00000000..031e6d80 --- /dev/null +++ b/EN/modules/ROOT/pages/master/6.3.6.adoc @@ -0,0 +1,262 @@ +:sectnums: +:sectnumlevels: 5 + +:imagesdir: ./_images + += PL/iSQL function and stored procedure + +== Purpose + +PostgreSQL supports functions and stored procedures, but there are syntax differences between PostgreSQL and Oracle. To enable Oracle's PL/SQL statements to run on IvorySQL—i.e., to achieve "syntax compatibility"—IvorySQL adopts the following solution: If an Oracle clause has a counterpart clause with the same function in IvorySQL, it is directly mapped to the corresponding IvorySQL clause; otherwise, only the syntax of the Oracle clause is implemented, while its function is not. + +== Implementation description + +PL/iSQL is the name of the procedural language in IvorySQL, specifically designed to be compatible with Oracle's PL/SQL statements. To achieve compatibility with Oracle-style syntax for functions and stored procedures, corresponding adjustments need to be made to the psql client tool, the SQL layer, and the PL/iSQL layer. + +=== Client tool psql + +Oracle's sqlplus tool uses a slash (/) to terminate functions and stored procedures. IvorySQL's client tool, psql, needs to be compatible with the same syntax. This means that the conventional mechanism—where statements are sent to the server upon encountering a semicolon—becomes ineffective when dealing with Oracle-style function and stored procedure commands; instead, a slash (/) is used to send the commands. + +To this end the following fields are added to the PsqlScanStateData structure: +``` + bool cancel_semicolon_terminator; /* not send command when semicolon found */ + + /* + * State to track boundaries of Oracle ANONYMOUS BLOCK. + * Case 1: Statements starting with << ident >> is Oracle anonymous block. + */ + int token_count; /* # of tokens, not blank or newline since start of statement */ + bool anonymous_label_start; /* T if the first token is "<<" */ + bool anonymous_label_ident; /* T if the second token is an identifier */ + bool anonymous_label_end; /* T if the third token is ">>" */ + + /* + * Case 2: DECLARE BEGIN ... END is Oracle anonymous block syntax. + * DECLARE can also be a PostgreSQL cursor declaration statement, we need to tell this. + */ + bool maybe_anonymous_declare_start; /* T if the first token is DECLARE */ + int token_cursor_idx; /* the position of keyword CURSOR in SQL statement */ + + /* + * Case 3: DECLARE BEGIN ... END is Oracle anonymous block syntax. + * BEGIN can also be a PostgreSQL transaction statement. + */ + bool maybe_anonymous_begin_start; /* T if the first token is BEGIN */ + +``` + +Meanwhile, modify ora_psqlscan.l and add or update the corresponding lexical rules. +Below is a code snippet example: +``` +{ + if (is_oracle_slash(cur_state, cur_state->scanline)) + { + /* Terminate lexing temporarily */ + cur_state->cancel_semicolon_terminator = false; + cur_state->maybe_anonymous_declare_start = false; + cur_state->maybe_anonymous_begin_start = false; + cur_state->anonymous_label_start = false; + cur_state->anonymous_label_ident = false; + cur_state->anonymous_label_end = false; + cur_state->start_state = YY_START; + cur_state->token_count = 0; + cur_state->token_cursor_idx = 0; + cur_state->identifier_count = 0; + cur_state->begin_depth = 0; + cur_state->ora_plsql_expect_end_symbol = END_SYMBOL_INVALID; + return LEXRES_SEMI; + } + ECHO; +``` + +The psql tool needs to detect the meaning of the slash (/), to avoid identifying slashes in comments and other parts as terminators. To this end, a separate interface is_oracle_slash is added in the oracle_fe_utils/ora_psqlscan.l file for detection. +``` +bool +is_oracle_slash(PsqlScanState state, const char *line) +{ + bool result = false; + + switch (state->start_state) + { + case INITIAL: + case xqs: /* treat these like INITIAL */ + { + int len, i; + bool has_slash = false; + + len = strlen(line); + for (i = 0; i < len; i++) + { + /* allow special char */ + if (line[i] == '\t' || + line[i] == '\n' || + line[i] == '\r' || + line[i] == ' ') + continue; + + if (line[i] == '/') + { + if (has_slash) + break; + has_slash = true; + continue; + } + /* others */ + break; + } + + if (i == len && has_slash) + result = true; + } + break; + default: + break; + } + + return result; +} + +``` + +=== SQL layer + +The SQL layer needs to be able to recognize the creation syntax for functions and stored procedures, and this is achieved by modifying ora_base_yylex. This function prefetches and caches tokens: if the token follows Oracle syntax, it organizes an SCONST and sends it to the PL/SQL layer; otherwise, it retrieves the previously preread tokens from the stack and processes them according to the native PostgreSQL logic. + +The following fields are added to the ora_base_yy_extra_type structure: +``` + /* + * The native PG only cache one-token info include yylloc, yylval and token + * number in yyextra, IvorySQL cache multiple tokens info using two arrays. + */ + int max_pushbacks; /* the max size of cache array */ + int loc_pushback; /* # of used tokens */ + int num_pushbacks; /* # of cached tokens */ + int *pushback_token; /* token number array */ + TokenAuxData *pushback_auxdata; /* auxdata array */ + + OraBodyStyle body_style; + int body_start; + int body_level; +``` + +Add operation interfaces for the token stack: +|==== +| push_back_token +| forward_token +| ora_internal_yylex +| internal_yylex +|==== + +In the ora_base_yylex function, when creating functions, procedures, or anonymous blocks, some tokens are preread. These tokens are cached into the stack using the aforementioned structure, and this is done to construct an SCONST that conforms to Oracle PL/SQL syntax and send it to the PL/iSQL layer for processing. For details, please refer to the source code. + + +=== PL/iSQL layer + +This part mainly modifies the pl_gram.y file to achieve compatibility with the syntax of PL/SQL functions and stored procedures. It enables compatibility with Oracle PL/SQL syntax forms without affecting PostgreSQL's native PL/pgSQL. Below is a code example for the compatibility of the DECLARE section; for more details, please refer to the IvorySQL source code. + +``` +/* + * The declaration section of the outermost block in Oracle does not have the DECLARE keyword. + */ +ora_outermost_pl_block: ora_decl_sect K_BEGIN proc_sect exception_sect K_END opt_label + { + PLiSQL_stmt_block *new; + + new = palloc0(sizeof(PLiSQL_stmt_block)); + + new->cmd_type = PLISQL_STMT_BLOCK; + new->lineno = plisql_location_to_lineno(@2); + new->stmtid = ++plisql_curr_compile->nstatements; + new->label = $1.label; + new->n_initvars = $1.n_initvars; + new->initvarnos = $1.initvarnos; + new->body = $3; + new->exceptions = $4; + + check_labels($1.label, $6, @6); + plisql_ns_pop(); + + $$ = (PLiSQL_stmt *)new; + } + ; + +ora_decl_sect: opt_block_label opt_ora_decl_start opt_ora_decl_stmts + { + if ($2) + { + if ($1 == NULL) + { + plisql_ns_push(NULL, PLISQL_LABEL_BLOCK); + } + } + } + opt_ora_decl_stmts + { + if ($4) + { + plisql_IdentifierLookup = IDENTIFIER_LOOKUP_NORMAL; + $$.label = ($1 == NULL ? plisql_curr_compile->namelabel : $1); + if ($2 && $1 == NULL) + $$.popname = true; + else + $$.popname = false; + /* Remember variables declared in decl_stmts */ + $$.n_initvars = plisql_add_initdatums(&($$.initvarnos)); + } + else + { + plisql_IdentifierLookup = IDENTIFIER_LOOKUP_NORMAL; + $$.label = ($1 == NULL ? plisql_curr_compile->namelabel : $1); + $$.n_initvars = 0; + if ($2 && $1 == NULL) + $$.popname = true; + else + $$.popname = false; + $$.initvarnos = NULL; + } + } + ; + +opt_ora_decl_start: K_DECLARE + { + /* Forget any variables created before block */ + plisql_add_initdatums(NULL); + /* + * Disable scanner lookup of identifiers while + * we process the decl_stmts + */ + plisql_IdentifierLookup = IDENTIFIER_LOOKUP_DECLARE; + $$ = true; + } + | /*EMPTY*/ + { + /* Forget any variables created before block */ + plisql_add_initdatums(NULL); + /* + * Disable scanner lookup of identifiers while + * we process the decl_stmts + */ + plisql_IdentifierLookup = IDENTIFIER_LOOKUP_DECLARE; + $$ = false; + } + ; + +opt_ora_decl_stmts: + ora_decl_stmts + { + $$ = true; + } + | /*EMPTY*/ + { + $$ = false; + } + +ora_decl_stmts: ora_decl_stmts ora_decl_stmt + | ora_decl_stmt + ; + +ora_decl_stmt: decl_statement + ; + +``` + diff --git a/EN/modules/ROOT/pages/master/7.7.adoc b/EN/modules/ROOT/pages/master/7.7.adoc index 9b01d61f..fd9a41f7 100644 --- a/EN/modules/ROOT/pages/master/7.7.adoc +++ b/EN/modules/ROOT/pages/master/7.7.adoc @@ -3,83 +3,533 @@ :imagesdir: ./_images -= Compatible with Oracle functions and stored procedures += PL/iSQL function and stored procedure -== Objective +== Purpose -- This document is intended to be compatible with the syntax of Oracle PLSQL functions and stored procedures, which we call PLISQL in IvorySQL. +PostgreSQL supports functions and stored procedures, but there are syntax differences between PostgreSQL and Oracle. To enable Oracle's PL/SQL statements to run on IvorySQL—i.e., to achieve "syntax compatibility"—IvorySQL adopts the following solution: If an Oracle clause has a counterpart clause with the same function in IvorySQL, it is directly mapped to the corresponding IvorySQL clause; otherwise, only the syntax of the Oracle clause is implemented, while its function is not. -== Function description +== Compatibility support -.FUNCTION -|==== -|THE FUNCTION SYNTAX SUPPORTS EDITIONABLE/NONEDITIONABLE -|THE FUNCTION syntax supports the RETURN, IS keywords, and does not specify language -|THE FUNCTION syntax functions have no arguments, and the function name does not follow () -|The maximum number of CREATE FUNCTION parameters is 32767 -|THE CREATE FUNCTION in END; End with / in psql -|THE CREATE FUNCTION syntax variable declaration is not preceded by the DECLARE keyword -|THE CREATE FUNCTION SYNTAX SUPPORTS THE OUT PARAMETER NOCOPY -|THE CREATE FUNCTION syntax supports sharing_clause -|THE CREATE FUNCTION syntax supports invoker_rights_clause, and the default permission is changed to DR (DEFINER) -|THE CREATE FUNCTION syntax supports ACCESSIBLE BY  -|THE CREATE FUNCTION SYNTAX SUPPORTS DEFAULT COLLATION -|THE CREATE FUNCTION syntax supports result_cache_clause  -|THE CREATE FUNCTION syntax supports aggregate_clause -|THE CREATE FUNCTION syntax supports pipelined_clause -|THE CREATE FUNCTION syntax supports sql_macro_clause -|ALTER FUNCTION syntax -|Functions and stored procedure-related views -|==== +The specific Oracle compatibility support includes the following aspects: -.Stored procedures -|==== -|THE CREATE PROCEDURE SYNTAX SUPPORTS EDITIONABLE/NONEDITIONABLE -|THE CREATE PROCEDURE syntax function has no arguments, no () after the function name -|The maximum number of CREATE PROCEDURE parameters is 32767 -|THE CREATE PROCEDURE in END; End with / in psql -|THE CREATE PROCEDURE syntax supports sharing_clause -|THE CREATE PROCEDURE SYNTAX SUPPORTS DEFAULT COLLATION -|THE CREATE PROCEDURE syntax supports invoker_rights_clause -|THE CREATE PROCEDURE syntax supports ACCESSIBLE BY  -|ALTER PROCEDURE syntax -|Stored procedures have no parameters, and invocation support is not carried out with () -|Stored procedure calls support EXEC -|When calling a stored procedure in PL/SQL, you can omit CALL and use the stored procedure name directly -|Both annotation methods are supported -- and /**/ -|==== +=== EDITIONABLE/NONEDITIONABLE is supported in CREATE FUNCTION syntax +``` +CREATE or replace EDITIONABLE FUNCTION ora_func RETURN integer AS +BEGIN + RETURN 1; +END; +/ -== Test cases +CREATE or replace NONEDITIONABLE FUNCTION ora_func RETURN integer IS +BEGIN + RETURN 1; +END; +/ +``` +=== Keyword 'RETURN' and 'IS' are supported in CREATE FUNCTION syntax +``` +CREATE or replace EDITIONABLE FUNCTION ora_func RETURN integer IS +BEGIN + RETURN 1; +END; +/ ``` -declare -i integer := 10; -begin - raise notice '%', i; - raise notice '%', main.i; -end; +=== In the CREATE FUNCTION syntax, a function can have no parameters, and no parentheses () after the function name +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = METADATA +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== Increase the number of parameters in CREATE FUNCTION syntax, the max value can be specified by configure command +``` +configure --help + --with-max-funarg=MAXFUNARG +``` + +=== Psql uses slash (/) as terminator of statement in CREATE FUNCTION syntax +``` +CREATE or replace EDITIONABLE FUNCTION ora_func RETURN integer IS +BEGIN + RETURN 1; +END; +/ +``` + +=== No DECLARE keyword before variable in CREATE FUNCTION syntax +``` +CREATE OR REPLACE +FUNCTION ora_func (num1 IN int, num2 IN int) +RETURN int +AS + num3 int :=10; + num4 int :=10; + num5 int; +BEGIN + num3 := num1 + num2; + num4 := num1 * num2; + num5 := num3 * num4; +RETURN num5; +END; +/ +CREATE FUNCTION + +select ora_func(5,9)from dual; + ora_func +---------- + 630 +(1 row) +``` + +=== Support NOCOPY for OUT parameter in CREATE FUNCTION syntax +``` +CREATE OR REPLACE FUNCTION test_nocopy(a IN int, b OUT NOCOPY int, c IN OUT NOCOPY int) +RETURN int +IS +BEGIN + b := a; + c := a; + return 1; +END; +/ +``` + +=== Support sharing clause in CREATE FUNCTION syntax +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = METADATA +IS +BEGIN + RETURN 1; +END; +/ + +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== Support invoker_rights (AUTHID) in CREATE FUNCTION syntax,and change default permission to be DR(DEFINER) +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID CURRENT_USER +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== Support ACCESSIBLE BY in CREATE FUNCTION syntax +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER ACCESSIBLE BY ( B ) +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER ACCESSIBLE BY ( A.B ) +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER ACCESSIBLE BY ( FUNCTION A.B ) +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D, PACKAGE E, +TRIGGER F, TYPE G ) +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== Support DEFAULT COLLATION in CREATE FUNCTION syntax +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +IS +BEGIN + RETURN 1; +END; / -NOTICE: 10 -NOTICE: 10 +``` +=== Support deterministic clause in CREATE FUNCTION syntax +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +IS +BEGIN + RETURN 1; +END; +/ ``` +=== Support parallel_enable clause in CREATE FUNCTION syntax +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE +IS +BEGIN + RETURN 1; +END; +/ ``` -DECLARE - grade CHAR(1); +=== Support result_cache clause in CREATE FUNCTION syntax +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON () +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +IS BEGIN - grade := 'B'; - CASE grade - WHEN 'A' THEN raise notice 'Excellent'; - WHEN 'B' THEN raise notice 'Very Good'; - END CASE; -EXCEPTION - WHEN CASE_NOT_FOUND THEN - raise notice 'No such grade'; + RETURN 1; END; / -NOTICE: Very Good +``` +=== Support aggregate clause in CREATE FUNCTION syntax ``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +AGGREGATE USING pg_catalog.int4 +IS +BEGIN + RETURN 1; +END; +/ +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +AGGREGATE USING int +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== Support pipelined clause in CREATE FUNCTION syntax +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +AGGREGATE USING int +PIPELINED +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== Support sql_macro clause in CREATE FUNCTION syntax +``` +CREATE or replace FUNCTION ora_func RETURN integer +SHARING = NONE AUTHID DEFINER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +DEFAULT COLLATION USING_NLS_COMP +DETERMINISTIC +PARALLEL_ENABLE ( PARTITION A BY RANGE ( B, C ) CLUSTER A BY ( E,F ) ) +RESULT_CACHE RELIES_ON ( data_source1, data_source2) +AGGREGATE USING int +PIPELINED TABLE POLYMORPHIC USING pg_catalog.int4 +SQL_MACRO +IS +BEGIN + RETURN 1; +END; +/ +``` + +=== Compatibility with ALTER FUNCTION syntax +``` +alter function public.test_func noneditionable; +alter function test_func compile; +alter function test_func compile debug; +alter function test_func compile debug sd = mv; +alter function test_func compile debug reuse settings; +``` + +=== Support EDITIONABLE/NONEDITIONABLE in CREATE PROCEDURE syntax +``` +CREATE OR REPLACE EDITIONABLE PROCEDURE ora_procedure +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ + +CREATE OR REPLACE NONEDITIONABLE PROCEDURE ora_procedure +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== In the CREATE PROCEDURE syntax, a procedure can have no parameters, and no parentheses () after the procedure name +``` +CREATE OR REPLACE EDITIONABLE PROCEDURE ora_procedure +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== Psql uses slash (/) as terminator of statement in CREATE PROCEDURE syntax +``` +CREATE OR REPLACE EDITIONABLE PROCEDURE ora_procedure +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== Support sharing clause in CREATE PROCEDURE syntax +``` +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = NONE +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== Support DEFAULT COLLATION clause in CREATE PROCEDURE syntax +``` +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== Support invoker_rights clause (AUTHID) in CREATE PROCEDURE syntax +``` +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID DEFINER +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== Support ACCESSIBLE BY clause in CREATE PROCEDURE syntax +``` +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( B ) +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( A.B ) +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( FUNCTION A.B ) +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D ) +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +CREATE OR REPLACE PROCEDURE ora_procedure +SHARING = METADATA +DEFAULT COLLATION USING_NLS_COMP +AUTHID CURRENT_USER +ACCESSIBLE BY ( FUNCTION A.B, PROCEDURE C.D, PACKAGE E, TRIGGER F, TYPE G ) +IS + p integer := 20; +begin + raise notice '%', p; +end; +/ +``` + +=== Compatibility with ALTER PROCEDURE syntax +``` +alter procedure test_proc editionable; +alter procedure public.test_proc noneditionable; +alter procedure test_proc compile; +alter procedure test_proc compile debug; +alter procedure test_proc compile debug sd = mv; +alter procedure test_proc compile debug reuse settings; +``` + +=== Function and procedure can have no parameter +``` +create or replace function f_noparentheses +return int is +begin +return 11; +end; +/ +select f_noparentheses from dual; + +create or replace procedure protest +as +begin +raise notice 'protest'; +end; +/ +CALL protest(); +``` + +=== Views related with function and stored procedure +``` +They can be found in file contrib/ivorysql_ora/src/sysview/sysview--1.0.sql. +Including DBA_PROCEDURES, ALL_PROCEDURES, USER_PROCEDURES, DBA_SOURCE, ALL_SOURCE, USER_SOURCE, DBA_ARGUMENTS, ALL_ARGUMENTS, USER_ARGUMENTS etc. +``` + +=== Support (--) and (/* */) + +=== pg_dump adds one slash (/) at the end of definition of function/procedure when backup SQL file \ No newline at end of file