1212# See the License for the specific language governing permissions and
1313# limitations under the License.
1414
15+ import importlib
1516import inspect
1617import re
1718import sys
@@ -408,50 +409,200 @@ def execute_sql_string(
408409 db_connection .client .rollback ()
409410
410411 def call_stored_procedure (
411- self , spName : str , spParams : Optional [List [str ]] = None , sansTran : bool = False , alias : Optional [str ] = None
412+ self ,
413+ spName : str ,
414+ spParams : Optional [List ] = None ,
415+ sansTran : bool = False ,
416+ alias : Optional [str ] = None ,
417+ additional_output_params : Optional [List ] = None ,
412418 ):
413419 """
414420 Calls a stored procedure `spName` with the `spParams` - a *list* of parameters the procedure requires.
415- Use the special *CURSOR* value for OUT params, which should receive result sets -
416- they will be converted to appropriate DB variables before calling the procedure.
417- This is necessary only for some databases (e.g. Oracle or PostgreSQL).
418-
419- The keywords always *returns two lists*:
420- - *Param values* - the copy of procedure parameters (modified, if the procedure changes the OUT params).
421- The list is empty, if procedures receives no params.
422- - *Result sets* - the list of lists, each of them containing results of some query, if the procedure
423- returns them or put them in the OUT params of type *CURSOR* (like in Oracle or PostgreSQL).
424-
425- It also depends on the database, how the procedure returns the values - as params or as result sets.
426- E.g. calling a procedure in *PostgreSQL* returns even a single value of an OUT param as a result set.
427-
428- Simple example:
429- | @{Params} = | Create List | Jerry | out_second_name |
430- | @{Param values} @{Result sets} = | Call Stored Procedure | Get_second_name | ${Params} |
431- | # ${Param values} = ['Jerry', 'Schneider'] |
432- | # ${result sets} = [] |
433-
434- Example with a single CURSOR parameter (Oracle DB):
435- | @{Params} = | Create List | CURSOR |
436- | @{Param values} @{Result sets} = | Call Stored Procedure | Get_all_second_names | ${Params} |
437- | # ${Param values} = [<oracledb.Cursor on <oracledb.Connection ...>>] |
438- | # ${result sets} = [[('See',), ('Schneider',)]] |
439-
440- Example with multiple CURSOR parameters (Oracle DB):
441- | @{Params} = | Create List | CURSOR | CURSOR |
442- | @{Param values} @{Result sets} = | Call Stored Procedure | Get_all_first_and_second_names | ${Params} |
443- | # ${Param values} = [<oracledb.Cursor on <oracledb.Connection ...>>, <oracledb.Cursor on <oracledb.Connection ...>>] |
444- | # ${result sets} = [[('Franz Allan',), ('Jerry',)], [('See',), ('Schneider',)]] |
421+ *Returns two lists* - the _parameter values_ and the _result sets_.
422+
423+ Use the special *CURSOR* value for OUT params, which should receive result sets - relevant only for some databases (e.g. Oracle or PostgreSQL).
424+
425+ Use the `additional_output_params` list for OUT params of a procedure in MSSQL.
445426
446427 Use optional ``alias`` parameter to specify what connection should be used for the query if you have more
447428 than one connection open.
448429
449- Use optional `sansTran` to run command without an explicit transaction commit or rollback:
450- | @{Param values} @{Result sets} = | Call Stored Procedure | DBName.SchemaName.StoredProcName | ${Params} | True |
430+ Use optional `sansTran` to run command without an explicit transaction commit or rollback.
431+
432+ = Handling parameters and result sets =
433+ Handling the input and output parameters and the result sets is very different
434+ depending on the database itself and on the Python database driver - i.e. how it implements the `cursor.callproc()` function.
435+
436+ == Common case (e.g. MySQL) ==
437+ Generally a procedure call requires all parameter values (IN and OUT) put together in a list - `spParams`.
438+
439+ Calling the procedure returns *two lists*:
440+ - *Param values* - the copy of procedure parameters (modified, if the procedure changes the OUT params). The list is empty, if procedures receives no params.
441+ - *Result sets* - the list of lists, each of them containing results of some query, if the procedure returns them.
442+
443+ == Oracle (oracledb, cx_Oracle) ==
444+ Oracle procedures work fine with simple IN and OUT params, but require some special handling of result sets.
445+
446+ === Simple case with IN and OUT params (no result sets) ===
447+ Consider the following procedure:
448+ | CREATE OR REPLACE PROCEDURE
449+ | get_second_name (person_first_name IN VARCHAR, person_second_name OUT VARCHAR) AS
450+ | BEGIN
451+ | SELECT last_name
452+ | INTO person_second_name
453+ | FROM person
454+ | WHERE first_name = person_first_name;
455+ | END;
456+
457+ Calling the procedure in Robot Framework:
458+ | @{params}= Create List Jerry OUTPUT
459+ | # Second parameter value can be anything, it will be replaced anyway
460+ |
461+ | ${param values} ${result sets}= Call Stored Procedure get_second_name ${params}
462+ | # ${param values} = ['Jerry', 'Schneider']
463+ | # ${result sets} = []
464+
465+ === Oracle procedure returning a result set ===
466+ If a procedure in Oracle should return a result set, it must take OUT parameters of a special type -
467+ _SYS_REFCURSOR_.
468+
469+ Consider the following procedure:
470+ | get_all_second_names (second_names_cursor OUT SYS_REFCURSOR) AS
471+ | BEGIN
472+ | OPEN second_names_cursor for
473+ | SELECT LAST_NAME FROM person;
474+ | END;
475+
476+ Calling the procedure in Robot Framework requires the special value *CURSOR* for the OUT parameters,
477+ they will be converted to appropriate DB variables before calling the procedure.
478+ | @{params}= Create List CURSOR
479+ | # The parameter must have this special value CURSOR
480+ |
481+ | ${param values} ${result sets}= Call Stored Procedure get_all_second_names ${params}
482+ | # ${param values} = [<oracledb.Cursor on <oracledb.Connection ...>>]
483+ | # ${result sets} = [[('Franz Allan',), ('Jerry',)], [('See',), ('Schneider',)]]
484+
485+ === Oracle procedure returning multiple result sets ===
486+ If a procedure takes multiple OUT parameters of the _SYS_REFCURSOR_ type, they all must have
487+ the special *CURSOR* value when calling the procedure:
488+ | @{params} = Create List CURSOR CURSOR
489+ | ${param values} ${result sets} = Call Stored Procedure Get_all_first_and_second_names ${params}
490+ | # ${param values} = [<oracledb.Cursor on <oracledb.Connection ...>>, <oracledb.Cursor on <oracledb.Connection ...>>]
491+ | # ${result sets} = [[('Franz Allan',), ('Jerry',)], [('See',), ('Schneider',)]]
492+
493+ == PostgreSQL (psycopg2, psycopg3) ==
494+ PostgreSQL doesn't return single values as params, only as result sets.
495+ It also supports special handling of result sets over OUT params of a special type (like Oracle).
496+
497+ === Simple case with IN and OUT params (no CURSOR parameters) ===
498+ Consider the following procedure:
499+ | CREATE FUNCTION
500+ | get_second_name (IN person_first_name VARCHAR(20),
501+ | OUT person_second_name VARCHAR(20))
502+ | LANGUAGE plpgsql
503+ | AS
504+ | '
505+ | BEGIN
506+ | SELECT LAST_NAME INTO person_second_name
507+ | FROM person
508+ | WHERE FIRST_NAME = person_first_name;
509+ | END
510+ | ';
511+
512+ Calling the procedure in Robot Framework:
513+ | @{params}= Create List Jerry
514+ | ${param values} ${result sets}= Call Stored Procedure get_second_name ${params}
515+ | # ${param values} = ['Jerry']
516+ | # ${result sets} = [[('Schneider',)]]
517+
518+ === PostgreSQL procedure with CURSOR parameters ===
519+ If a procedure in PostgreSQL should return a proper result set, it must take OUT parameters of a special type -
520+ _refcursor_.
521+
522+ Consider the following procedure:
523+ | CREATE FUNCTION
524+ | get_all_first_and_second_names(result1 refcursor, result2 refcursor)
525+ | RETURNS SETOF refcursor
526+ | LANGUAGE plpgsql
527+ | AS
528+ | '
529+ | BEGIN
530+ | OPEN result1 FOR SELECT FIRST_NAME FROM person;
531+ | RETURN NEXT result1;
532+ | OPEN result2 FOR SELECT LAST_NAME FROM person;
533+ | RETURN NEXT result2;
534+ | END
535+ | ';
536+
537+ Calling the procedure in Robot Framework requires the special value *CURSOR* for the OUT parameters,
538+ they will be converted to appropriate DB variables before calling the procedure.
539+ | @{params}= Create List CURSOR CURSOR
540+ | # The parameters must have this special value CURSOR
541+ |
542+ | ${param values} ${result sets}= Call Stored Procedure get_all_first_and_second_names ${params}
543+ | # ${param values} = ['CURSOR_0', 'CURSOR_1']
544+ | # ${result sets} = [[('Franz Allan',), ('Jerry',)], [('See',), ('Schneider',)]
545+
546+ == MS SQL Server (pymssql) ==
547+ The _pymssql_ driver doesn't natively support getting the OUT parameter values after calling a procedure.
548+ - This requires special handling of OUT parameters using the `additional_output_params` argument.
549+ - Furthermore, it's not possible to fetch the OUT parameter values for a procedure, which returns a result set AND has OUT parameters.
550+
551+ === Simple case with IN and OUT params (no result sets) ===
552+ Consider the following procedure:
553+ | CREATE PROCEDURE
554+ | return_out_param_without_result_sets
555+ | @my_input VARCHAR(20),
556+ | @my_output INT OUTPUT
557+ | AS
558+ | BEGIN
559+ | IF @my_input = 'give me 1'
560+ | BEGIN
561+ | SELECT @my_output = 1;
562+ | END
563+ | ELSE
564+ | BEGIN
565+ | SELECT @my_output = 0;
566+ | END
567+ | END;
568+
569+ Calling the procedure in Robot Framework requires putting the IN parameters as usual in the `spParams` argument,
570+ but the sample values of OUT parameters must be put in the argument `additional_output_params`.
571+
572+ | @{params}= Create List give me 1
573+ | @{out_params}= Create List ${9}
574+ | ${param values} ${result sets}= Call Stored Procedure return_out_param_without_result_sets
575+ | ... ${params} additional_output_params=${out_params}
576+ | # ${result sets} = [[('Franz Allan',), ('Jerry',)], [('See',), ('Schneider',)]]
577+ | # ${param values} = ('give me 1', 1)
578+
579+ The library uses the sample values in the `additional_output_params` list to determine the number and the type
580+ of OUT parameters - so they are type-sensitive, the type must be the same as in the procedure itself.
581+
582+ === MS SQL procedure returning a result set (no OUT params) ===
583+ If a procedure doesn't have any OUT params and returns only result sets, they are handled in a normal way.
584+ Consider the following procedure:
585+ | CREATE PROCEDURE get_all_first_and_second_names
586+ | AS
587+ | BEGIN
588+ | SELECT FIRST_NAME FROM person;
589+ | SELECT LAST_NAME FROM person;
590+ | RETURN;
591+ | END;
592+
593+ Calling the procedure in Robot Framework:
594+ | ${param values} ${result sets}= Call Stored Procedure get_all_first_and_second_names
595+ | ${param values} = ()
596+ | ${result sets} = [[('Franz Allan',), ('Jerry',)], [('See',), ('Schneider',)]]
597+
598+ === MS SQL procedure returning result sets AND OUT params ===
599+ This case is *not fully supported* by the library - the OUT params won't be fetched.
451600 """
452601 db_connection = self .connection_store .get_connection (alias )
453602 if spParams is None :
454603 spParams = []
604+ if additional_output_params is None :
605+ additional_output_params = []
455606 cur = None
456607 try :
457608 if db_connection .module_name == "pymssql" :
@@ -494,7 +645,6 @@ def call_stored_procedure(
494645 result_sets .append (list (result_set ))
495646
496647 elif db_connection .module_name in ["psycopg2" , "psycopg3" ]:
497- cur = db_connection .client .cursor ()
498648 # check if "CURSOR" params were passed - they will be replaced
499649 # with cursor variables for storing the result sets
500650 params_substituted = spParams .copy ()
@@ -521,13 +671,20 @@ def call_stored_procedure(
521671 result_sets .append (list (result_set ))
522672
523673 else :
524- logger .info (
525- f"CAUTION! Calling a stored procedure for '{ db_connection .module_name } ' is not tested, "
526- "results might be invalid!"
527- )
528- cur = db_connection .client .cursor ()
674+ if db_connection .module_name == "pymssql" :
675+ mssql = importlib .import_module ("pymssql" )
676+ spParams = spParams .copy ()
677+ for param in additional_output_params :
678+ spParams .append (mssql .output (type (param ), param ))
679+
680+ else :
681+ logger .info (
682+ f"Calling a stored procedure for '{ db_connection .module_name } '. "
683+ "No special handling is known, so trying the common way with return params and result sets."
684+ )
685+
529686 param_values = cur .callproc (spName , spParams )
530- logger .info ("Reading the procedure results .." )
687+ logger .info ("Reading the procedure result sets .." )
531688 result_sets_available = True
532689 while result_sets_available :
533690 result_set = []
0 commit comments