mirror of
				https://github.com/postgres/postgres.git
				synced 2025-10-31 00:03:57 -04:00 
			
		
		
		
	Add support for an optional INTO clause to PL/PgSQL's EXECUTE command.
This allows the result of executing a SELECT to be assigned to a row variable, record variable, or list of scalars. Docs and regression tests updated. Per Pavel Stehule, improvements and cleanup by Neil Conway.
This commit is contained in:
		
							parent
							
								
									0f011f6daa
								
							
						
					
					
						commit
						c59887f916
					
				| @ -1,5 +1,5 @@ | |||||||
| <!-- | <!-- | ||||||
| $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.69 2005/05/26 04:08:31 momjian Exp $ | $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.70 2005/06/07 02:47:15 neilc Exp $ | ||||||
| --> | --> | ||||||
| 
 | 
 | ||||||
| <chapter id="plpgsql">  | <chapter id="plpgsql">  | ||||||
| @ -1251,13 +1251,14 @@ NULL; | |||||||
|      <command>EXECUTE</command> statement is provided: |      <command>EXECUTE</command> statement is provided: | ||||||
| 
 | 
 | ||||||
| <synopsis> | <synopsis> | ||||||
| EXECUTE <replaceable class="command">command-string</replaceable>; | EXECUTE <replaceable class="command">command-string</replaceable> [ INTO <replaceable>target</replaceable> ]; | ||||||
| </synopsis> | </synopsis> | ||||||
| 
 | 
 | ||||||
|      where <replaceable>command-string</replaceable> is an expression |      where <replaceable>command-string</replaceable> is an expression | ||||||
|      yielding a string (of type |      yielding a string (of type <type>text</type>) containing the | ||||||
|      <type>text</type>) containing the command |      command to be executed and <replaceable>target</replaceable> is a | ||||||
|      to be executed.  This string is fed literally to the SQL engine. |      record variable, row variable, or a comma-separated list of | ||||||
|  |      simple variables and record/row fields. | ||||||
|     </para> |     </para> | ||||||
| 
 | 
 | ||||||
|     <para> |     <para> | ||||||
| @ -1276,16 +1277,22 @@ EXECUTE <replaceable class="command">command-string</replaceable>; | |||||||
|     </para> |     </para> | ||||||
| 
 | 
 | ||||||
|     <para> |     <para> | ||||||
|      The results from <command>SELECT</command> commands are discarded |      The <literal>INTO</literal> clause specifies where the results of | ||||||
|      by <command>EXECUTE</command>, and <command>SELECT INTO</command> |      a <command>SELECT</command> command should be assigned. If a row | ||||||
|      is not currently supported within <command>EXECUTE</command>. |      or variable list is provided, it must exactly match the structure | ||||||
|      So there is no way to extract a result from a dynamically-created |      of the results produced by the <command>SELECT</command> (when a | ||||||
|      <command>SELECT</command> using the plain <command>EXECUTE</command> |      record variable is used, it will configure itself to match the | ||||||
|      command.  There are two other ways to do it, however: one is to use the |      result's structure automatically). If multiple rows are returned, | ||||||
|      <command>FOR-IN-EXECUTE</> |      only the first will be assigned to the <literal>INTO</literal> | ||||||
|      loop form described in <xref linkend="plpgsql-records-iterating">, |      variable. If no rows are returned, NULL is assigned to the | ||||||
|      and the other is to use a cursor with <command>OPEN-FOR-EXECUTE</>, as |      <literal>INTO</literal> variable. If no <literal>INTO</literal> | ||||||
|      described in <xref linkend="plpgsql-cursor-opening">. |      clause is specified, the results of a <command>SELECT</command> | ||||||
|  |      command are discarded. | ||||||
|  |     </para> | ||||||
|  | 
 | ||||||
|  |     <para> | ||||||
|  |      <command>SELECT INTO</command> is not currently supported within | ||||||
|  |      <command>EXECUTE</command>. | ||||||
|     </para> |     </para> | ||||||
| 
 | 
 | ||||||
|     <para> |     <para> | ||||||
|  | |||||||
| @ -4,7 +4,7 @@ | |||||||
|  *						  procedural language |  *						  procedural language | ||||||
|  * |  * | ||||||
|  * IDENTIFICATION |  * IDENTIFICATION | ||||||
|  *	  $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.72 2005/05/26 04:08:31 momjian Exp $ |  *	  $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.73 2005/06/07 02:47:16 neilc Exp $ | ||||||
|  * |  * | ||||||
|  *	  This software is copyrighted by Jan Wieck - Hamburg. |  *	  This software is copyrighted by Jan Wieck - Hamburg. | ||||||
|  * |  * | ||||||
| @ -1250,19 +1250,62 @@ stmt_execsql	: execsql_start lno | |||||||
| 					} | 					} | ||||||
| 				; | 				; | ||||||
| 
 | 
 | ||||||
| stmt_dynexecute : K_EXECUTE lno expr_until_semi | stmt_dynexecute : K_EXECUTE lno  | ||||||
| 					{ | 					{ | ||||||
| 						PLpgSQL_stmt_dynexecute *new; | 						PLpgSQL_stmt_dynexecute *new; | ||||||
|  | 						PLpgSQL_expr *expr; | ||||||
|  | 						int endtoken; | ||||||
|  | 
 | ||||||
|  | 						expr = read_sql_construct(K_INTO, ';', "INTO|;", "SELECT ", | ||||||
|  | 												  true, true, &endtoken); | ||||||
| 
 | 
 | ||||||
| 						new = palloc(sizeof(PLpgSQL_stmt_dynexecute)); | 						new = palloc(sizeof(PLpgSQL_stmt_dynexecute)); | ||||||
| 						new->cmd_type = PLPGSQL_STMT_DYNEXECUTE; | 						new->cmd_type = PLPGSQL_STMT_DYNEXECUTE; | ||||||
| 						new->lineno   = $2; | 						new->lineno   = $2; | ||||||
| 						new->query	  = $3; | 						new->query    = expr; | ||||||
|  | 
 | ||||||
|  | 						new->rec = NULL; | ||||||
|  | 						new->row = NULL; | ||||||
|  | 
 | ||||||
|  | 						/* | ||||||
|  | 						 * If we saw "INTO", look for an additional | ||||||
|  | 						 * row or record var. | ||||||
|  | 						 */ | ||||||
|  | 						if (endtoken == K_INTO) | ||||||
|  | 						{ | ||||||
|  | 							switch (yylex()) | ||||||
|  | 							{ | ||||||
|  | 								case T_ROW: | ||||||
|  | 									check_assignable((PLpgSQL_datum *) yylval.row); | ||||||
|  | 									new->row = yylval.row; | ||||||
|  | 									break; | ||||||
|  | 
 | ||||||
|  | 								case T_RECORD: | ||||||
|  | 									check_assignable((PLpgSQL_datum *) yylval.row); | ||||||
|  | 									new->rec = yylval.rec; | ||||||
|  | 									break; | ||||||
|  | 
 | ||||||
|  | 								case T_SCALAR: | ||||||
|  | 									new->row = read_into_scalar_list(yytext, yylval.scalar); | ||||||
|  | 									break; | ||||||
|  | 
 | ||||||
|  | 								default: | ||||||
|  | 									plpgsql_error_lineno = $2; | ||||||
|  | 									ereport(ERROR, | ||||||
|  | 											(errcode(ERRCODE_SYNTAX_ERROR), | ||||||
|  | 											 errmsg("syntax error at \"%s\"", | ||||||
|  | 													yytext), | ||||||
|  | 											 errdetail("Expected record or row variable."))); | ||||||
|  | 							} | ||||||
|  | 							if (yylex() != ';') | ||||||
|  | 								yyerror("syntax error"); | ||||||
|  | 						} | ||||||
| 
 | 
 | ||||||
| 						$$ = (PLpgSQL_stmt *)new; | 						$$ = (PLpgSQL_stmt *)new; | ||||||
| 					} | 					} | ||||||
| 				; | 				; | ||||||
| 
 | 
 | ||||||
|  | 
 | ||||||
| stmt_open		: K_OPEN lno cursor_varptr | stmt_open		: K_OPEN lno cursor_varptr | ||||||
| 					{ | 					{ | ||||||
| 						PLpgSQL_stmt_open *new; | 						PLpgSQL_stmt_open *new; | ||||||
|  | |||||||
| @ -3,7 +3,7 @@ | |||||||
|  *			  procedural language |  *			  procedural language | ||||||
|  * |  * | ||||||
|  * IDENTIFICATION |  * IDENTIFICATION | ||||||
|  *	  $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.141 2005/05/26 04:08:31 momjian Exp $ |  *	  $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.142 2005/06/07 02:47:17 neilc Exp $ | ||||||
|  * |  * | ||||||
|  *	  This software is copyrighted by Jan Wieck - Hamburg. |  *	  This software is copyrighted by Jan Wieck - Hamburg. | ||||||
|  * |  * | ||||||
| @ -2202,6 +2202,13 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate, | |||||||
| 	Oid			restype; | 	Oid			restype; | ||||||
| 	char	   *querystr; | 	char	   *querystr; | ||||||
| 	int			exec_res; | 	int			exec_res; | ||||||
|  | 	PLpgSQL_rec *rec = NULL; | ||||||
|  | 	PLpgSQL_row *row = NULL; | ||||||
|  | 
 | ||||||
|  | 	if (stmt->rec != NULL) | ||||||
|  | 		rec = (PLpgSQL_rec *) (estate->datums[stmt->rec->recno]); | ||||||
|  | 	else if (stmt->row != NULL) | ||||||
|  | 		row = (PLpgSQL_row *) (estate->datums[stmt->row->rowno]); | ||||||
| 
 | 
 | ||||||
| 	/*
 | 	/*
 | ||||||
| 	 * First we evaluate the string expression after the EXECUTE keyword. | 	 * First we evaluate the string expression after the EXECUTE keyword. | ||||||
| @ -2221,9 +2228,27 @@ exec_stmt_dynexecute(PLpgSQL_execstate *estate, | |||||||
| 	/*
 | 	/*
 | ||||||
| 	 * Call SPI_execute() without preparing a saved plan. The returncode can | 	 * Call SPI_execute() without preparing a saved plan. The returncode can | ||||||
| 	 * be any standard OK.	Note that while a SELECT is allowed, its | 	 * be any standard OK.	Note that while a SELECT is allowed, its | ||||||
| 	 * results will be discarded. | 	 * results will be discarded unless an INTO clause is specified. | ||||||
| 	 */ | 	 */ | ||||||
| 	exec_res = SPI_execute(querystr, estate->readonly_func, 0); | 	exec_res = SPI_execute(querystr, estate->readonly_func, 0); | ||||||
|  | 
 | ||||||
|  | 	/* Assign to INTO variable */ | ||||||
|  | 	if (rec || row) | ||||||
|  | 	{ | ||||||
|  | 		if (exec_res != SPI_OK_SELECT) | ||||||
|  | 			ereport(ERROR, | ||||||
|  | 					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED), | ||||||
|  | 					 errmsg("EXECUTE ... INTO is only for SELECT"))); | ||||||
|  | 		else | ||||||
|  | 		{ | ||||||
|  | 			if (SPI_processed == 0) | ||||||
|  | 				exec_move_row(estate, rec, row, NULL, SPI_tuptable->tupdesc); | ||||||
|  | 			else | ||||||
|  | 				exec_move_row(estate, rec, row, | ||||||
|  | 							  SPI_tuptable->vals[0], SPI_tuptable->tupdesc); | ||||||
|  | 		} | ||||||
|  | 	} | ||||||
|  | 
 | ||||||
| 	switch (exec_res) | 	switch (exec_res) | ||||||
| 	{ | 	{ | ||||||
| 		case SPI_OK_SELECT: | 		case SPI_OK_SELECT: | ||||||
|  | |||||||
| @ -3,7 +3,7 @@ | |||||||
|  *			  procedural language |  *			  procedural language | ||||||
|  * |  * | ||||||
|  * IDENTIFICATION |  * IDENTIFICATION | ||||||
|  *	  $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.60 2005/05/26 04:08:31 momjian Exp $ |  *	  $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.61 2005/06/07 02:47:18 neilc Exp $ | ||||||
|  * |  * | ||||||
|  *	  This software is copyrighted by Jan Wieck - Hamburg. |  *	  This software is copyrighted by Jan Wieck - Hamburg. | ||||||
|  * |  * | ||||||
| @ -524,6 +524,8 @@ typedef struct | |||||||
| {								/* Dynamic SQL string to execute */ | {								/* Dynamic SQL string to execute */ | ||||||
| 	int			cmd_type; | 	int			cmd_type; | ||||||
| 	int			lineno; | 	int			lineno; | ||||||
|  | 	PLpgSQL_rec *rec;					/* INTO record or row variable */ | ||||||
|  | 	PLpgSQL_row *row; | ||||||
| 	PLpgSQL_expr *query; | 	PLpgSQL_expr *query; | ||||||
| } PLpgSQL_stmt_dynexecute; | } PLpgSQL_stmt_dynexecute; | ||||||
| 
 | 
 | ||||||
|  | |||||||
| @ -2380,3 +2380,38 @@ ERROR:  control reached end of function without RETURN | |||||||
| CONTEXT:  PL/pgSQL function "missing_return_expr" | CONTEXT:  PL/pgSQL function "missing_return_expr" | ||||||
| drop function void_return_expr(); | drop function void_return_expr(); | ||||||
| drop function missing_return_expr(); | drop function missing_return_expr(); | ||||||
|  | -- | ||||||
|  | -- EXECUTE ... INTO test | ||||||
|  | -- | ||||||
|  | create table eifoo (i integer, y integer); | ||||||
|  | create type eitype as (i integer, y integer); | ||||||
|  | create or replace function execute_into_test(varchar) returns record as $$ | ||||||
|  | declare | ||||||
|  |     _r record; | ||||||
|  |     _rt eifoo%rowtype; | ||||||
|  |     _v eitype; | ||||||
|  |     i int; | ||||||
|  |     j int; | ||||||
|  |     k int; | ||||||
|  | begin | ||||||
|  |     execute 'insert into '||$1||' values(10,15)'; | ||||||
|  |     execute 'select (row).* from (select row(10,1)::eifoo) s' into _r; | ||||||
|  |     raise notice '% %', _r.i, _r.y; | ||||||
|  |     execute 'select * from '||$1||' limit 1' into _rt; | ||||||
|  |     raise notice '% %', _rt.i, _rt.y; | ||||||
|  |     execute 'select *, 20 from '||$1||' limit 1' into i, j, k; | ||||||
|  |     raise notice '% % %', i, j, k; | ||||||
|  |     execute 'select 1,2' into _v; | ||||||
|  |     return _v; | ||||||
|  | end; $$ language plpgsql; | ||||||
|  | select execute_into_test('eifoo'); | ||||||
|  | NOTICE:  10 1 | ||||||
|  | NOTICE:  10 15 | ||||||
|  | NOTICE:  10 15 20 | ||||||
|  |  execute_into_test  | ||||||
|  | ------------------- | ||||||
|  |  (1,2) | ||||||
|  | (1 row) | ||||||
|  | 
 | ||||||
|  | drop table eifoo cascade; | ||||||
|  | drop type eitype cascade; | ||||||
|  | |||||||
| @ -2018,3 +2018,35 @@ select missing_return_expr(); | |||||||
| 
 | 
 | ||||||
| drop function void_return_expr(); | drop function void_return_expr(); | ||||||
| drop function missing_return_expr(); | drop function missing_return_expr(); | ||||||
|  | 
 | ||||||
|  | -- | ||||||
|  | -- EXECUTE ... INTO test | ||||||
|  | -- | ||||||
|  | 
 | ||||||
|  | create table eifoo (i integer, y integer); | ||||||
|  | create type eitype as (i integer, y integer); | ||||||
|  | 
 | ||||||
|  | create or replace function execute_into_test(varchar) returns record as $$ | ||||||
|  | declare | ||||||
|  |     _r record; | ||||||
|  |     _rt eifoo%rowtype; | ||||||
|  |     _v eitype; | ||||||
|  |     i int; | ||||||
|  |     j int; | ||||||
|  |     k int; | ||||||
|  | begin | ||||||
|  |     execute 'insert into '||$1||' values(10,15)'; | ||||||
|  |     execute 'select (row).* from (select row(10,1)::eifoo) s' into _r; | ||||||
|  |     raise notice '% %', _r.i, _r.y; | ||||||
|  |     execute 'select * from '||$1||' limit 1' into _rt; | ||||||
|  |     raise notice '% %', _rt.i, _rt.y; | ||||||
|  |     execute 'select *, 20 from '||$1||' limit 1' into i, j, k; | ||||||
|  |     raise notice '% % %', i, j, k; | ||||||
|  |     execute 'select 1,2' into _v; | ||||||
|  |     return _v; | ||||||
|  | end; $$ language plpgsql; | ||||||
|  | 
 | ||||||
|  | select execute_into_test('eifoo'); | ||||||
|  | 
 | ||||||
|  | drop table eifoo cascade; | ||||||
|  | drop type eitype cascade; | ||||||
|  | |||||||
		Loading…
	
	
			
			x
			
			
		
	
		Reference in New Issue
	
	Block a user