From 08b76543b71fe9d2358f225234828cfe7e563eae Mon Sep 17 00:00:00 2001 From: JiaoShuntian Date: Tue, 4 Nov 2025 15:38:13 +0800 Subject: [PATCH 1/2] Adding Oracle-compatible CALL INTO feature documentation and architecture design documentation --- CN/modules/ROOT/nav.adoc | 2 + CN/modules/ROOT/pages/master/6.3.12.adoc | 170 +++++++++++++++++++ CN/modules/ROOT/pages/master/7.22.adoc | 199 +++++++++++++++++++++++ EN/modules/ROOT/nav.adoc | 2 + EN/modules/ROOT/pages/master/6.3.12.adoc | 177 ++++++++++++++++++++ EN/modules/ROOT/pages/master/7.22.adoc | 199 +++++++++++++++++++++++ 6 files changed, 749 insertions(+) create mode 100644 CN/modules/ROOT/pages/master/6.3.12.adoc create mode 100644 CN/modules/ROOT/pages/master/7.22.adoc create mode 100644 EN/modules/ROOT/pages/master/6.3.12.adoc create mode 100644 EN/modules/ROOT/pages/master/7.22.adoc diff --git a/CN/modules/ROOT/nav.adoc b/CN/modules/ROOT/nav.adoc index 6b7078c..43a1484 100644 --- a/CN/modules/ROOT/nav.adoc +++ b/CN/modules/ROOT/nav.adoc @@ -36,6 +36,7 @@ **** xref:master/6.3.9.adoc[大小写转换] **** xref:master/6.3.10.adoc[sys_guid 函数] **** xref:master/6.3.11.adoc[空字符串转null] +**** xref:master/6.3.12.adoc[CALL INTO] *** 内置函数 **** xref:master/6.4.1.adoc[sys_context] **** xref:master/6.4.2.adoc[userenv] @@ -62,6 +63,7 @@ *** xref:master/7.19.adoc[19、嵌套子函数] *** xref:master/7.20.adoc[20、sys_guid 函数] *** xref:master/7.21.adoc[21、空字符串转null] +*** xref:master/7.22.adoc[22、CALL INTO] ** IvorySQL贡献指南 *** xref:master/8.1.adoc[社区贡献指南] *** xref:master/8.2.adoc[asciidoc语法快速参考] diff --git a/CN/modules/ROOT/pages/master/6.3.12.adoc b/CN/modules/ROOT/pages/master/6.3.12.adoc new file mode 100644 index 0000000..b64e87c --- /dev/null +++ b/CN/modules/ROOT/pages/master/6.3.12.adoc @@ -0,0 +1,170 @@ +:sectnums: +:sectnumlevels: 5 + +:imagesdir: ./_images + += CALL INTO + +== 目的 + +当前,PostgreSQL数据库的CALL语句存在以下限制: + +- 不支持INTO子句; +- 无法调用有返回值的函数; +- 无法将结果赋值给客户端变量(即 Oracle 中的绑定变量 / host variables)。 + +为提升对 Oracle 的兼容性,IvorySQL 实现了对 CALL func(...) INTO :var; 语法的支持,允许用户通过绑定变量(如 :x)接收函数返回值,并在行为(如精度检查、错误处理)上与 Oracle 保持一致。 + +== 整体设计思路 + +由于 PostgreSQL/IvorySQL 本身不支持 SQL 层直接向客户端变量赋值,因此本方案采用 “客户端重写 + 服务端协同” 的方式实现: + +- 当 CALL 语句包含绑定变量(如 :x)时: + + 客户端将其重写为一个特殊的匿名 PL 块(DO $$ ... $$); + 使用扩展查询协议发送,以便传递参数类型和精度信息; + 服务端执行该匿名块,并将结果返回给客户端; + 客户端再将结果写入对应的绑定变量。 + +- 当 CALL 语句不含绑定变量时: + + 行为与原生 PostgreSQL 完全一致,使用简单查询协议,不做任何重写。 + +== 实现原理 +=== 交互式终端 +为了在接口中兼容CALL [INTO]语句,需将其转换为匿名PL/SQL块,并借助匿名块对OUT参数的支持来实现功能等价。这就要求get_parameter_description函数能够正确识别CALL语句,并在遇到CALL INTO时,返回重写后的PL语句。 +相应地,get_hostvariables例程需要将这些信息(如是否为 CALL 语句、是否包含INTO、重写后的语句等)保存到HostVariable结构中。HostVariable的定义如下: +``` +typedef struct HostVariable +{ + HostVariableEntry *hostvars; + int length; + bool isdostmt; + bool iscallstmt; // 是否来自 CALL 语句 + char *convertcall; // 重写后的语句 +} HostVariable; +``` +=== 服务端 +在服务端需要修改语法解析器部分,在ora_gram.y中添加CALL INTO语法规则,并在action部分生成重写后的PL语句,如“x := add(1,2);” +``` +CallStmt: CALL func_application + { + CallStmt *n = makeNode(CallStmt); + n->funccall = castNode(FuncCall, $2); + $$ = (Node *)n; + } + | CALL func_application INTO ORAPARAM + { + CallStmt *n = makeNode(CallStmt); + OraParamRef *hostvar = makeNode(OraParamRef); + char *callstr = NULL; + n->funccall = castNode(FuncCall, $2); + hostvar->number = 0; + hostvar->location = @4; + hostvar->name = $4; + n->hostvariable = hostvar; + callstr = pnstrdup(pg_yyget_extra(yyscanner)->core_yy_extra.scanbuf + @2, @3 - @2); + n->callinto = psprintf("%s := %s;", $4, callstr); + pfree(callstr); + $$ = (Node *)n; + } + ; +``` +CallStmt结构需要保存INTO子句和转换后的PL语句 +``` +typedef struct CallStmt +{ + NodeTag type; + FuncCall *funccall; /* from the parser */ + FuncExpr *funcexpr; /* transformed call, with only input args */ + List *outargs; /* transformed output-argument expressions */ + OraParamRef *hostvariable; /* only used for get_parameter_description() */ + char *callinto; /* rewrite CALL INTO to a PL assign stmt */ +} CallStmt; +``` + +为区分普通 DO 语句和由 CALL 转换而来的匿名块,语法中新增GENERATED FROM CALL关键字: +``` +opt_do_from_where: + GENERATED FROM CALL { $$ = true; } + | /*EMPTY*/ { $$ = false; } + ; +``` +生成的 DoStmt 节点将设置 do_from_call = true,供执行器识别。 +``` +typedef struct DoStmt +{ + NodeTag type; + List *args; /* List of DefElem nodes */ + List *paramsmode; /* List of parameters mode */ + List *paramslen; /* List of length for parameter datatypes */ + bool do_from_call; /* True if DoStmt is come from CallStmt */ +} DoStmt; +``` +在IVY接口中,占位符信息是通过一个名为get_parameter_description的集合返回函数(SRF)获取的。该函数需要能够识别输入语句的类型,并在遇到CALL INTO语句时,返回重写后的PL/SQL赋值语句。 +为此,IvorySQL对该函数的返回结构(TupleDesc)进行了扩展:新增了一个hint 字段,专门用于返回CALL INTO语句重写后的PL代码;对于其他类型的语句,该字段保持为NULL。 +此外,原函数结果集的第一条元组的第一个字段原本仅用true/false来区分语句是否为匿名块。为了更准确地识别语句类型(尤其是CALL语句),现已将其修改为返回对应解析树的 CommandTag。 +所有这些元数据信息最终会被封装到一个用户上下文结构中,以便在 SRF 函数的多次调用之间高效传递和复用。 +``` +{ + OraParamExtralData *extral; + const char *cmdtag; + char *callintoexpr; +} outparam_fctx; +``` +接口层 +CALL涉及的ivy前缀的接口包括: + +IvyStmtExecute + +IvyStmtExecute2 + +IvyexecPreparedStatement + +IvyexecPreparedStatement2 + +在上述接口中,用户传入的CALL [INTO]语句会被重写为一种“特殊”的匿名块语句。为了明确标识这类由CALL转换而来的匿名块,在接口的语句类型定义中新增了一种专用类型。该类型的作用是在IvyHandleDostmt中正确识别此类语句,并生成形如 DO $$...$$ USING … -- GENERATED FROM CALL 的执行语句。 +``` +typedef enum IvyStmtType +{ + IVY_STMT_UNKNOW, + IVY_STMT_DO, + IVY_STMT_DOFROMCALL, /* new statementt ype */ + IVY_STMT_DOHANDLED, + IVY_STMT_OTHERS +} IvyStmtType; +``` +在重写 CALL 语句时,如果遇到调用函数的 CALL INTO 语句,接口需要对绑定变量的顺序进行内部调整。这一调整对用户是完全透明的:用户在绑定参数时,只需按照 CALL 语句中出现的顺序操作即可——即 INTO 子句中的变量在原语句中位于最后。 + +然而,在重写生成的特殊匿名块中,该 INTO 变量会作为赋值表达式的左值(即第一个参数)出现。因此,接口必须在内部将绑定顺序正确调整,确保执行逻辑与用户预期一致。 + +所有涉及此逻辑的接口例程都需要实现这一处理,相关例程如下: + +Ivyreplacenamebindtoposition + +Ivyreplacenamebindtoposition2 + +Ivyreplacenamebindtoposition3 + +在IvyexecPreparedStatement 和 IvyexecPreparedStatement2 这类接口中,用户需要显式提供每个参数的 paramvalues、paramlengths、paramformats 和 parammode。对于 CALL 语句,这些参数数组中的元素顺序必须根据重写后的匿名块结构进行位置调整,以确保绑定与执行逻辑一致。 + +其中,IvyexecPreparedStatement2 更为特殊:它要求用户额外提供一个 IvyBindOutInfo* 类型的输出绑定列表。该列表不仅用于绑定 OUT 参数,还被 IvyAssignPLISQLOutParameter 在获取 PL/SQL 过程返回结果时用来识别每个 OUT 参数的数据类型。因此,在处理 CALL语句时,接口会先对用户传入的 IvyBindOutInfo*列表进行位置重排(将INTO对应的输出变量移至首位),再将其写入IvyPreparedStatement语句句柄中,供后续赋值使用。 + +关于输出参数的精度处理:当CALL语句中的输出绑定变量与实际返回值的精度不匹配时,系统可能报错,也可能自动截断——具体行为取决于绑定变量的数据类型是否与过程/函数声明的参数类型完全一致。 +在PL/SQL inline handler中,每个OUT参数的精确数据类型均可通过ParamListInfo在绑定阶段获取。如果当前执行的匿名块是由CALL语句转换而来的特殊DoStmt,那么在执行赋值时,系统会进行如下判断: + +若ParamListInfo中记录的类型与函数/存储过程形参的类型完全相同,则采用强制类型转换赋值; +否则,采用隐式类型转换赋值。 + +这一机制旨在兼容Oracle的行为,确保在类型不完全匹配时仍能安全、合理地完成赋值。 +``` +-- 原始 CALL语句: +CALL my_func(:in1, :in2) INTO :out; +-- 重写为: +do $$BEGIN + :out := my_func(:in1, :in2); +END$$ using + out INOUT, in1 INOUT, in2 INOUT + paramslength -1,-1,-1 +GENERATED FROM CALL; +``` diff --git a/CN/modules/ROOT/pages/master/7.22.adoc b/CN/modules/ROOT/pages/master/7.22.adoc new file mode 100644 index 0000000..cfd1820 --- /dev/null +++ b/CN/modules/ROOT/pages/master/7.22.adoc @@ -0,0 +1,199 @@ +:sectnums: +:sectnumlevels: 5 + +:imagesdir: ./_images + += 兼容Oracle的CALL INTO + +== 目的 + +- IvorySQL中的CALL语句支持调用单独的函数存储过程,也可以是在包或对象类型中的函数和存储过程。CALL调用函数增加INTO子句语法,插入的目标是一个host variable。 + +== 功能说明 + +- CALL支持调用单独的或定义在包中函数和存储过程。 +- CALL调用函数时,增加INTO子句语法,插入的目标是一个host variable。 +- CALL调用无参或全取默认值的函数/存储过程不能省略空括号。 +- CALL在调用函数和存储过程时的参数或INTO子句中支持引用绑定变量。 +- CALL语句中OUT参数对应的绑定变量支持对精度和数据类型的验证。 +- 输出绑定变量不允许被重复绑定。 + +== 测试用例 + +=== call into调用函数,并插入host variable +[source,sql] +---- +-- 创建函数 +ivorysql=# create or replace function f_defs(a number default 1314) +ivorysql-# return number +ivorysql-# is +ivorysql-# begin +ivorysql-# raise notice '%', a; +ivorysql-# return a; +ivorysql-# end; +ivorysql-# / +CREATE FUNCTION +-- 声明绑定变量 +ivorysql=# variable x number +-- 调用函数并获取返回值 +ivorysql=# call f_defs() into :x; +NOTICE: 1314 + +Call completed. + +ivorysql=# print x + X +------ + 1314 +---- + +=== call调用包中的存储过程 +[source,sql] +---- +ivorysql=# create table tb1(c1 int); +CREATE TABLE +-- 创建包规范 +ivorysql=# create or replace package pkg is +ivorysql-# var1 integer; +ivorysql-# procedure test_p ; +ivorysql-# end; +ivorysql-# / +CREATE PACKAGE +-- 创建包体 +ivorysql=# create or replace package body pkg is +ivorysql-# procedure test_p is +ivorysql-# begin +ivorysql-# insert into tb1 values(1); +ivorysql-# end; +ivorysql-# begin +ivorysql-# var1 := 2; +ivorysql-# end; +ivorysql-# / +CREATE PACKAGE BODY +-- 调用包中的过程 +ivorysql=# call pkg.test_p(); +CALL +ivorysql=# select * from tb1; + c1 +----- + 1 +(1 row) +---- + +=== 无参和默认参数调用 +[source,sql] +---- +-- 创建带默认参数函数 +ivorysql=# CREATE OR REPLACE FUNCTION default_arg_func(p_num NUMBER DEFAULT 100) RETURN NUMBER AS +ivorysql-# BEGIN +ivorysql-# RETURN p_num + 5; +ivorysql-# END; +ivorysql-# / +CREATE FUNCTION +-- 正确调用默认参数函数(必须带括号) +ivorysql=# VARIABLE default_result NUMBER; +ivorysql=# CALL default_arg_func() INTO :default_result; -- 使用默认值100 + +Call completed. + +ivorysql=# PRINT default_result; + DEFAULT_RESULT +---------------- + 105 + +-- 带参数调用 +ivorysql=# CALL default_arg_func(200) INTO :default_result; + +Call completed. + +ivorysql=# PRINT default_result; + DEFAULT_RESULT +---------------- + 205 +---- + +=== 在参数或INTO子句中引用绑定变量 +[source,sql] +---- +-- 设置输入绑定变量 +ivorysql=# VARIABLE input_num NUMBER = 7; +-- 使用绑定变量作为参数调用函数 +ivorysql=# VARIABLE func_result NUMBER; +ivorysql=# CALL stand_alone_func(:input_num) INTO :func_result; + +Call completed. + +ivorysql=# PRINT func_result; + FUNC_RESULT +------------- + 14 +---- + +=== CALL语句中OUT参数支持精度和数据类型验证 +[source,sql] +---- +-- 创建带OUT参数的过程 +ivorysql=# CREATE OR REPLACE PROCEDURE out_param_proc( +ivorysql(# p_in IN VARCHAR2, +ivorysql(# p_out OUT VARCHAR2, +ivorysql(# p_num_out OUT NUMBER +ivorysql(# ) AS +ivorysql-# BEGIN +ivorysql-# p_out := p_in || ' processed'; +ivorysql-# p_num_out := LENGTH(p_in); +ivorysql-# END; +ivorysql-# / +CREATE PROCEDURE +-- 测试OUT参数类型匹配 +ivorysql=# VARIABLE out_var VARCHAR2(50); +ivorysql=# VARIABLE num_var NUMBER; +ivorysql=# CALL out_param_proc('Test input', :out_var, :num_var); + +Call completed. + +ivorysql=# PRINT out_var; + OUT_VAR +---------------------- + Test input processed + +ivorysql=# PRINT num_var; + NUM_VAR +--------- + 10 + +-- 测试OUT参数精度不足(会截断) +ivorysql=# VARIABLE short_out VARCHAR2(5); +ivorysql=# CALL out_param_proc('Long input string', :short_out, :num_var); + +Call completed. + +ivorysql=# PRINT short_out; + SHORT_OUT +----------- + Long + +-- 测试类型不匹配(会报错) +ivorysql=# VARIABLE wrong_type NUMBER; +ivorysql=# CALL out_param_proc('Test', :wrong_type, :num_var); +ERROR: invalid input syntax for type numeric: "Test processed" +---- + +=== 输出绑定变量不允许重复绑定 +[source,sql] +---- +-- 准备绑定变量 +ivorysql=# VARIABLE dup_var VARCHAR2(100); +-- 尝试重复绑定(会报错) +ivorysql=# CALL out_param_func('Test', :dup_var) INTO :dup_var; +ERROR: output parameter cannot be a duplicate bind +-- 正确做法:使用不同的绑定变量 +ivorysql=# VARIABLE out1 VARCHAR2(100); +ivorysql=# CALL out_param_proc('Correct usage', :out1, :num_var); + +Call completed. + +ivorysql=# PRINT out1; + OUT1 +------------------------- + Correct usage processed +---- diff --git a/EN/modules/ROOT/nav.adoc b/EN/modules/ROOT/nav.adoc index a61931b..a62506d 100644 --- a/EN/modules/ROOT/nav.adoc +++ b/EN/modules/ROOT/nav.adoc @@ -35,6 +35,7 @@ *** xref:master/6.3.9.adoc[Case Conversion] *** xref:master/6.3.10.adoc[sys_guid Function] *** xref:master/6.3.11.adoc[Empty String to NULL] +*** xref:master/6.3.12.adoc[CALL INTO] ** Built-in Functions *** xref:master/6.4.1.adoc[sys_context] *** xref:master/6.4.2.adoc[userenv] @@ -61,6 +62,7 @@ ** xref:master/7.19.adoc[19、Nested Subfunctions] ** xref:master/7.20.adoc[20、sys_guid Function] ** xref:master/7.21.adoc[21、Empty String to NULL] +** xref:master/7.22.adoc[22、CALL INTO] * xref:master/8.adoc[Community contribution] * xref:master/9.adoc[Tool Reference] * xref:master/10.adoc[FAQ] diff --git a/EN/modules/ROOT/pages/master/6.3.12.adoc b/EN/modules/ROOT/pages/master/6.3.12.adoc new file mode 100644 index 0000000..78a789e --- /dev/null +++ b/EN/modules/ROOT/pages/master/6.3.12.adoc @@ -0,0 +1,177 @@ +:sectnums: +:sectnumlevels: 5 + +:imagesdir: ./_images + += CALL INTO + +== Purpose + +Currently, PostgreSQL's CALL statement has the following limitations: + +- Does not support the INTO clause; +- Cannot call functions that return values; +- Cannot assign results to client-side variables (i.e., Oracle's binding variables / host variables). + +To enhance compatibility with Oracle, IvorySQL has implemented support for the CALL func(...) INTO :var; syntax, allowing users to receive function return values through binding variables (e.g., :x). This behavior (including precision checks and error handling) aligns with Oracle's standards. + +== Overall Design Approach + +Since PostgreSQL/IvorySQL inherently does not support direct assignment to client-side variables at the SQL level, this solution adopts a "client-side rewriting + server-side collaboration" approach: + +- When the CALL statement includes binding variables (e.g., :x): + + The client rewrites it into a special anonymous PL block (DO $$ ... $$); + Sends it using the extended query protocol to transmit parameter type and precision information; + The server executes this anonymous block and returns the result to the client; + The client then writes the result to the corresponding binding variable. + +- When the CALL statement does not contain binding variables: + + The behavior remains fully consistent with native PostgreSQL, using the simple query protocol without any rewriting. + +== Implementation Details +=== psql +To ensure compatibility with the CALL [INTO] statement in the interface, it must be converted into an anonymous PL/SQL block, leveraging the support for OUT parameters in anonymous blocks to achieve functional equivalence. + +This requires the get_parameter_description function to correctly identify CALL statements and, when encountering CALL INTO, return the rewritten PL statement. + +Correspondingly, the get_hostvariables routine needs to store this information (such as whether it is a CALL statement, whether it includes INTO, the rewritten statement, etc.) in the HostVariable structure. The definition of HostVariable is as follows: +``` +typedef struct HostVariable +{ + HostVariableEntry *hostvars; + int length; + bool isdostmt; + bool iscallstmt; // Whether it is from a CALL statement + char *convertcall; // Rewritten statement +} HostVariable; +``` +=== Server-side +On the server side, modifications are required in the syntax parser section. Add CALL INTO grammar rules in ora_gram.y, and generate rewritten PL statements in the action section, such as "x := add(1,2);". +``` +CallStmt: CALL func_application + { + CallStmt *n = makeNode(CallStmt); + n->funccall = castNode(FuncCall, $2); + $$ = (Node *)n; + } + | CALL func_application INTO ORAPARAM + { + CallStmt *n = makeNode(CallStmt); + OraParamRef *hostvar = makeNode(OraParamRef); + char *callstr = NULL; + n->funccall = castNode(FuncCall, $2); + hostvar->number = 0; + hostvar->location = @4; + hostvar->name = $4; + n->hostvariable = hostvar; + callstr = pnstrdup(pg_yyget_extra(yyscanner)->core_yy_extra.scanbuf + @2, @3 - @2); + n->callinto = psprintf("%s := %s;", $4, callstr); + pfree(callstr); + $$ = (Node *)n; + } + ; +``` +The CallStmt structure needs to store the INTO clause and the converted PL statement. +``` +typedef struct CallStmt +{ + NodeTag type; + FuncCall *funccall; /* from the parser */ + FuncExpr *funcexpr; /* transformed call, with only input args */ + List *outargs; /* transformed output-argument expressions */ + OraParamRef *hostvariable; /* only used for get_parameter_description() */ + char *callinto; /* rewrite CALL INTO to a PL assign stmt */ +} CallStmt; +``` +To distinguish between regular DO statements and anonymous blocks converted from CALL statements, a new keyword GENERATED FROM CALL is added to the syntax. +``` +opt_do_from_where: + GENERATED FROM CALL { $$ = true; } + | /*EMPTY*/ { $$ = false; } + ; +``` +The generated DoStmt node will set do_from_call = true for executor identification. +``` +typedef struct DoStmt +{ + NodeTag type; + List *args; /* List of DefElem nodes */ + List *paramsmode; /* List of parameters mode */ + List *paramslen; /* List of length for parameter datatypes */ + bool do_from_call; /* True if DoStmt is come from CallStmt */ +} DoStmt; +``` +In the IVY interface, placeholder information is obtained through a Set-Returning Function (SRF) called get_parameter_description. This function needs to identify the type of input statement and return the rewritten PL/SQL assignment statement when encountering CALL INTO statements. + +To achieve this, IvorySQL has extended the return structure (TupleDesc) of this function: a new hint field has been added specifically to return the rewritten PL code for CALL INTO statements; for other types of statements, this field remains NULL. + +Additionally, the first field of the first tuple in the original function result set previously used only true/false to distinguish whether the statement was an anonymous block. To more accurately identify statement types (especially CALL statements), it has now been modified to return the corresponding parse tree's CommandTag. + +All these metadata details are ultimately encapsulated into a user context structure to enable efficient passing and reuse across multiple invocations of the SRF function. +``` +{ + OraParamExtralData *extral; + const char *cmdtag; + char *callintoexpr; +} outparam_fctx; +``` +=== Interface layer +The IVY-prefixed interfaces involved in CALL include: + +IvyStmtExecute + +IvyStmtExecute2 + +IvyexecPreparedStatement + +IvyexecPreparedStatement2 + +In the aforementioned interfaces, user-provided CALL [INTO] statements are rewritten into a "special" anonymous block statement. To clearly identify such anonymous blocks converted from CALL statements, a dedicated type has been added to the statement type definitions of the interface. + +The purpose of this type is to correctly recognize such statements in IvyHandleDostmt and generate execution statements in the form of:DO $$...$$ USING … -- GENERATED FROM CALL +``` +typedef enum IvyStmtType +{ + IVY_STMT_UNKNOW, + IVY_STMT_DO, + IVY_STMT_DOFROMCALL, /* new statementt ype */ + IVY_STMT_DOHANDLED, + IVY_STMT_OTHERS +} IvyStmtType; +``` +When rewriting CALL statements, if encountering a CALL INTO statement that invokes a function, the interface needs to internally adjust the order of bound variables. This adjustment is completely transparent to users: when binding parameters, users only need to follow the order in which the variables appear in the CALL statement—that is, the variable in the INTO clause is positioned last in the original statement. + +However, in the rewritten special anonymous block, this INTO variable will appear as the left-hand side (i.e., the first parameter) of an assignment expression. Therefore, the interface must internally adjust the binding order correctly to ensure the execution logic matches the user's expectations. + +All interface routines involved in this logic must implement this handling. The relevant routines are as follows: + +Ivyreplacenamebindtoposition + +Ivyreplacenamebindtoposition2 + +Ivyreplacenamebindtoposition3 + +In interfaces such as IvyexecPreparedStatement and IvyexecPreparedStatement2, users must explicitly provide paramvalues, paramlengths, paramformats, and parammode for each parameter. For CALL statements, the order of elements in these parameter arrays must be adjusted according to the rewritten anonymous block structure to ensure binding consistency with the execution logic. + +Among them, IvyexecPreparedStatement2 is more specialized: it requires users to additionally provide an output binding list of type IvyBindOutInfo*. This list is not only used to bind OUT parameters but is also utilized by IvyAssignPLISQLOutParameter to identify the data type of each OUT parameter when retrieving PL/SQL procedure results. Therefore, when processing CALL statements, the interface first reorders the user-provided IvyBindOutInfo* list (moving the INTO-bound output variable to the first position) and then writes it into the IvyPreparedStatement statement handle for subsequent assignment. + +Regarding precision handling for output parameters: When there is a mismatch between the precision of an output binding variable in a CALL statement and the actual returned value, the system may either raise an error or automatically truncate—the specific behavior depends on whether the data type of the binding variable exactly matches the parameter type declared in the procedure/function. + +In the PL/SQL inline handler, the precise data type of each OUT parameter can be obtained through ParamListInfo during the binding phase. If the currently executed anonymous block is a special DoStmt converted from a CALL statement, the system performs the following checks during assignment: + +If the type recorded in ParamListInfo exactly matches the formal parameter type of the function/stored procedure, a forced type conversion is applied for assignment. +Otherwise, an implicit type conversion is used for assignment. +This mechanism is designed to be compatible with Oracle's behavior, ensuring safe and reasonable assignment even when types do not fully match. +``` +-- Original CALL statement: +CALL my_func(:in1, :in2) INTO :out; +-- Rewritten as: +do $$BEGIN + :out := my_func(:in1, :in2); +END$$ using + out INOUT, in1 INOUT, in2 INOUT + paramslength -1,-1,-1 +GENERATED FROM CALL; +``` diff --git a/EN/modules/ROOT/pages/master/7.22.adoc b/EN/modules/ROOT/pages/master/7.22.adoc new file mode 100644 index 0000000..73d05b9 --- /dev/null +++ b/EN/modules/ROOT/pages/master/7.22.adoc @@ -0,0 +1,199 @@ +:sectnums: +:sectnumlevels: 5 + +:imagesdir: ./_images + += Compatible with Oracle's CALL INTO + +== Objective + +- In IvorySQL, the CALL statement supports invoking standalone function stored procedures, as well as functions and stored procedures within packages or object types. The CALL syntax for invoking functions adds an INTO clause, where the insertion target is a host variable. + +== Feature Description + +- CALL supports invoking standalone functions and stored procedures, as well as those defined within packages. +- When using CALL to invoke functions, the INTO clause syntax is added, with the insertion target being a host variable. +- When calling functions/stored procedures with no parameters or all default values, empty parentheses cannot be omitted. +- CALL supports referencing bind variables in parameters or the INTO clause when invoking functions and stored procedures. +- The binding variables corresponding to OUT parameters in the CALL statement support validation of precision and data types. +- Output binding variables are not allowed to be repeatedly bound. + +== Test Cases + +=== Call INTO invokes a function and inserts the result into a host variable. +[source,sql] +---- +-- Create function +ivorysql=# create or replace function f_defs(a number default 1314) +ivorysql-# return number +ivorysql-# is +ivorysql-# begin +ivorysql-# raise notice '%', a; +ivorysql-# return a; +ivorysql-# end; +ivorysql-# / +CREATE FUNCTION +-- Declare bind variable +ivorysql=# variable x number +-- Call the function and retrieve the return value +ivorysql=# call f_defs() into :x; +NOTICE: 1314 + +Call completed. + +ivorysql=# print x + X +------ + 1314 +---- + +=== Call the stored procedure in the package +[source,sql] +---- +ivorysql=# create table tb1(c1 int); +CREATE TABLE +-- Create package specification +ivorysql=# create or replace package pkg is +ivorysql-# var1 integer; +ivorysql-# procedure test_p ; +ivorysql-# end; +ivorysql-# / +CREATE PACKAGE +-- Create package body +ivorysql=# create or replace package body pkg is +ivorysql-# procedure test_p is +ivorysql-# begin +ivorysql-# insert into tb1 values(1); +ivorysql-# end; +ivorysql-# begin +ivorysql-# var1 := 2; +ivorysql-# end; +ivorysql-# / +CREATE PACKAGE BODY +-- Call the procedure in the package +ivorysql=# call pkg.test_p(); +CALL +ivorysql=# select * from tb1; + c1 +----- + 1 +(1 row) +---- + +=== Call with no parameters or default parameters +[source,sql] +---- +-- Create a function with default parameters +ivorysql=# CREATE OR REPLACE FUNCTION default_arg_func(p_num NUMBER DEFAULT 100) RETURN NUMBER AS +ivorysql-# BEGIN +ivorysql-# RETURN p_num + 5; +ivorysql-# END; +ivorysql-# / +CREATE FUNCTION +-- Correctly call a function with default parameters (must include parentheses) +ivorysql=# VARIABLE default_result NUMBER; +ivorysql=# CALL default_arg_func() INTO :default_result; -- Use the default value of 100 + +Call completed. + +ivorysql=# PRINT default_result; + DEFAULT_RESULT +---------------- + 105 + +-- Call with parameters +ivorysql=# CALL default_arg_func(200) INTO :default_result; + +Call completed. + +ivorysql=# PRINT default_result; + DEFAULT_RESULT +---------------- + 205 +---- + +=== Reference bind variables in parameters or INTO clauses +[source,sql] +---- +-- Set input bind variables +ivorysql=# VARIABLE input_num NUMBER = 7; +-- Call a function using bind variables as parameters +ivorysql=# VARIABLE func_result NUMBER; +ivorysql=# CALL stand_alone_func(:input_num) INTO :func_result; + +Call completed. + +ivorysql=# PRINT func_result; + FUNC_RESULT +------------- + 14 +---- + +=== The OUT parameters in CALL statements support precision and data type validation +[source,sql] +---- +-- Create a procedure with OUT parameters +ivorysql=# CREATE OR REPLACE PROCEDURE out_param_proc( +ivorysql(# p_in IN VARCHAR2, +ivorysql(# p_out OUT VARCHAR2, +ivorysql(# p_num_out OUT NUMBER +ivorysql(# ) AS +ivorysql-# BEGIN +ivorysql-# p_out := p_in || ' processed'; +ivorysql-# p_num_out := LENGTH(p_in); +ivorysql-# END; +ivorysql-# / +CREATE PROCEDURE +-- Test OUT parameter type matching +ivorysql=# VARIABLE out_var VARCHAR2(50); +ivorysql=# VARIABLE num_var NUMBER; +ivorysql=# CALL out_param_proc('Test input', :out_var, :num_var); + +Call completed. + +ivorysql=# PRINT out_var; + OUT_VAR +---------------------- + Test input processed + +ivorysql=# PRINT num_var; + NUM_VAR +--------- + 10 + +-- Test insufficient OUT parameter precision (will be truncated) +ivorysql=# VARIABLE short_out VARCHAR2(5); +ivorysql=# CALL out_param_proc('Long input string', :short_out, :num_var); + +Call completed. + +ivorysql=# PRINT short_out; + SHORT_OUT +----------- + Long + +-- Test type mismatch (will throw an error) +ivorysql=# VARIABLE wrong_type NUMBER; +ivorysql=# CALL out_param_proc('Test', :wrong_type, :num_var); +ERROR: invalid input syntax for type numeric: "Test processed" +---- + +=== Output binding variables do not allow duplicate binding. +[source,sql] +---- +-- Prepare binding variables +ivorysql=# VARIABLE dup_var VARCHAR2(100); +-- Attempting duplicate binding (will throw an error) +ivorysql=# CALL out_param_func('Test', :dup_var) INTO :dup_var; +ERROR: output parameter cannot be a duplicate bind +-- Correct approach: Use different binding variables +ivorysql=# VARIABLE out1 VARCHAR2(100); +ivorysql=# CALL out_param_proc('Correct usage', :out1, :num_var); + +Call completed. + +ivorysql=# PRINT out1; + OUT1 +------------------------- + Correct usage processed +---- From 252abea1b70c65ba524801976cf11abc95871677 Mon Sep 17 00:00:00 2001 From: JiaoShuntian Date: Tue, 11 Nov 2025 17:52:18 +0800 Subject: [PATCH 2/2] fix CALL INTO feature typo --- CN/modules/ROOT/pages/master/6.3.12.adoc | 16 ++++++++-------- EN/modules/ROOT/pages/master/6.3.12.adoc | 8 ++++---- 2 files changed, 12 insertions(+), 12 deletions(-) diff --git a/CN/modules/ROOT/pages/master/6.3.12.adoc b/CN/modules/ROOT/pages/master/6.3.12.adoc index b64e87c..6b9480b 100644 --- a/CN/modules/ROOT/pages/master/6.3.12.adoc +++ b/CN/modules/ROOT/pages/master/6.3.12.adoc @@ -21,10 +21,10 @@ - 当 CALL 语句包含绑定变量(如 :x)时: - 客户端将其重写为一个特殊的匿名 PL 块(DO $$ ... $$); - 使用扩展查询协议发送,以便传递参数类型和精度信息; - 服务端执行该匿名块,并将结果返回给客户端; - 客户端再将结果写入对应的绑定变量。 + 客户端将其重写为一个特殊的匿名 PL 块(DO $$ ... $$); + 使用扩展查询协议发送,以便传递参数类型和精度信息; + 服务端执行该匿名块,并将结果返回给客户端; + 客户端再将结果写入对应的绑定变量。 - 当 CALL 语句不含绑定变量时: @@ -32,7 +32,7 @@ == 实现原理 === 交互式终端 -为了在接口中兼容CALL [INTO]语句,需将其转换为匿名PL/SQL块,并借助匿名块对OUT参数的支持来实现功能等价。这就要求get_parameter_description函数能够正确识别CALL语句,并在遇到CALL INTO时,返回重写后的PL语句。 +为了在接口中兼容CALL [INTO]语句,需将其转换为匿名PL/iSQL块,并借助匿名块对OUT参数的支持来实现功能等价。这就要求get_parameter_description函数能够正确识别CALL语句,并在遇到CALL INTO时,返回重写后的PL语句。 相应地,get_hostvariables例程需要将这些信息(如是否为 CALL 语句、是否包含INTO、重写后的语句等)保存到HostVariable结构中。HostVariable的定义如下: ``` typedef struct HostVariable @@ -101,7 +101,7 @@ typedef struct DoStmt bool do_from_call; /* True if DoStmt is come from CallStmt */ } DoStmt; ``` -在IVY接口中,占位符信息是通过一个名为get_parameter_description的集合返回函数(SRF)获取的。该函数需要能够识别输入语句的类型,并在遇到CALL INTO语句时,返回重写后的PL/SQL赋值语句。 +在IVY接口中,占位符信息是通过一个名为get_parameter_description的集合返回函数(SRF)获取的。该函数需要能够识别输入语句的类型,并在遇到CALL INTO语句时,返回重写后的PL/iSQL赋值语句。 为此,IvorySQL对该函数的返回结构(TupleDesc)进行了扩展:新增了一个hint 字段,专门用于返回CALL INTO语句重写后的PL代码;对于其他类型的语句,该字段保持为NULL。 此外,原函数结果集的第一条元组的第一个字段原本仅用true/false来区分语句是否为匿名块。为了更准确地识别语句类型(尤其是CALL语句),现已将其修改为返回对应解析树的 CommandTag。 所有这些元数据信息最终会被封装到一个用户上下文结构中,以便在 SRF 函数的多次调用之间高效传递和复用。 @@ -148,10 +148,10 @@ Ivyreplacenamebindtoposition3 在IvyexecPreparedStatement 和 IvyexecPreparedStatement2 这类接口中,用户需要显式提供每个参数的 paramvalues、paramlengths、paramformats 和 parammode。对于 CALL 语句,这些参数数组中的元素顺序必须根据重写后的匿名块结构进行位置调整,以确保绑定与执行逻辑一致。 -其中,IvyexecPreparedStatement2 更为特殊:它要求用户额外提供一个 IvyBindOutInfo* 类型的输出绑定列表。该列表不仅用于绑定 OUT 参数,还被 IvyAssignPLISQLOutParameter 在获取 PL/SQL 过程返回结果时用来识别每个 OUT 参数的数据类型。因此,在处理 CALL语句时,接口会先对用户传入的 IvyBindOutInfo*列表进行位置重排(将INTO对应的输出变量移至首位),再将其写入IvyPreparedStatement语句句柄中,供后续赋值使用。 +其中,IvyexecPreparedStatement2 更为特殊:它要求用户额外提供一个 IvyBindOutInfo* 类型的输出绑定列表。该列表不仅用于绑定 OUT 参数,还被 IvyAssignPLISQLOutParameter 在获取 PL/iSQL 过程返回结果时用来识别每个 OUT 参数的数据类型。因此,在处理 CALL语句时,接口会先对用户传入的 IvyBindOutInfo*列表进行位置重排(将INTO对应的输出变量移至首位),再将其写入IvyPreparedStatement语句句柄中,供后续赋值使用。 关于输出参数的精度处理:当CALL语句中的输出绑定变量与实际返回值的精度不匹配时,系统可能报错,也可能自动截断——具体行为取决于绑定变量的数据类型是否与过程/函数声明的参数类型完全一致。 -在PL/SQL inline handler中,每个OUT参数的精确数据类型均可通过ParamListInfo在绑定阶段获取。如果当前执行的匿名块是由CALL语句转换而来的特殊DoStmt,那么在执行赋值时,系统会进行如下判断: +在PL/iSQL inline handler中,每个OUT参数的精确数据类型均可通过ParamListInfo在绑定阶段获取。如果当前执行的匿名块是由CALL语句转换而来的特殊DoStmt,那么在执行赋值时,系统会进行如下判断: 若ParamListInfo中记录的类型与函数/存储过程形参的类型完全相同,则采用强制类型转换赋值; 否则,采用隐式类型转换赋值。 diff --git a/EN/modules/ROOT/pages/master/6.3.12.adoc b/EN/modules/ROOT/pages/master/6.3.12.adoc index 78a789e..0b73b26 100644 --- a/EN/modules/ROOT/pages/master/6.3.12.adoc +++ b/EN/modules/ROOT/pages/master/6.3.12.adoc @@ -32,7 +32,7 @@ Since PostgreSQL/IvorySQL inherently does not support direct assignment to clien == Implementation Details === psql -To ensure compatibility with the CALL [INTO] statement in the interface, it must be converted into an anonymous PL/SQL block, leveraging the support for OUT parameters in anonymous blocks to achieve functional equivalence. +To ensure compatibility with the CALL [INTO] statement in the interface, it must be converted into an anonymous PL/iSQL block, leveraging the support for OUT parameters in anonymous blocks to achieve functional equivalence. This requires the get_parameter_description function to correctly identify CALL statements and, when encountering CALL INTO, return the rewritten PL statement. @@ -103,7 +103,7 @@ typedef struct DoStmt bool do_from_call; /* True if DoStmt is come from CallStmt */ } DoStmt; ``` -In the IVY interface, placeholder information is obtained through a Set-Returning Function (SRF) called get_parameter_description. This function needs to identify the type of input statement and return the rewritten PL/SQL assignment statement when encountering CALL INTO statements. +In the IVY interface, placeholder information is obtained through a Set-Returning Function (SRF) called get_parameter_description. This function needs to identify the type of input statement and return the rewritten PL/iSQL assignment statement when encountering CALL INTO statements. To achieve this, IvorySQL has extended the return structure (TupleDesc) of this function: a new hint field has been added specifically to return the rewritten PL code for CALL INTO statements; for other types of statements, this field remains NULL. @@ -155,11 +155,11 @@ Ivyreplacenamebindtoposition3 In interfaces such as IvyexecPreparedStatement and IvyexecPreparedStatement2, users must explicitly provide paramvalues, paramlengths, paramformats, and parammode for each parameter. For CALL statements, the order of elements in these parameter arrays must be adjusted according to the rewritten anonymous block structure to ensure binding consistency with the execution logic. -Among them, IvyexecPreparedStatement2 is more specialized: it requires users to additionally provide an output binding list of type IvyBindOutInfo*. This list is not only used to bind OUT parameters but is also utilized by IvyAssignPLISQLOutParameter to identify the data type of each OUT parameter when retrieving PL/SQL procedure results. Therefore, when processing CALL statements, the interface first reorders the user-provided IvyBindOutInfo* list (moving the INTO-bound output variable to the first position) and then writes it into the IvyPreparedStatement statement handle for subsequent assignment. +Among them, IvyexecPreparedStatement2 is more specialized: it requires users to additionally provide an output binding list of type IvyBindOutInfo*. This list is not only used to bind OUT parameters but is also utilized by IvyAssignPLISQLOutParameter to identify the data type of each OUT parameter when retrieving PL/iSQL procedure results. Therefore, when processing CALL statements, the interface first reorders the user-provided IvyBindOutInfo* list (moving the INTO-bound output variable to the first position) and then writes it into the IvyPreparedStatement statement handle for subsequent assignment. Regarding precision handling for output parameters: When there is a mismatch between the precision of an output binding variable in a CALL statement and the actual returned value, the system may either raise an error or automatically truncate—the specific behavior depends on whether the data type of the binding variable exactly matches the parameter type declared in the procedure/function. -In the PL/SQL inline handler, the precise data type of each OUT parameter can be obtained through ParamListInfo during the binding phase. If the currently executed anonymous block is a special DoStmt converted from a CALL statement, the system performs the following checks during assignment: +In the PL/iSQL inline handler, the precise data type of each OUT parameter can be obtained through ParamListInfo during the binding phase. If the currently executed anonymous block is a special DoStmt converted from a CALL statement, the system performs the following checks during assignment: If the type recorded in ParamListInfo exactly matches the formal parameter type of the function/stored procedure, a forced type conversion is applied for assignment. Otherwise, an implicit type conversion is used for assignment.