Language element reference v16
An embedded SQL statement allows your client application to interact with the server. An embedded directive is an instruction to the ECPGPlus compiler.
You can embed any EDB Postgres Advanced Server SQL statement in a C program. Each statement must begin with the keywords EXEC SQL
and must be terminated with a semi-colon (;). In the C program, a SQL statement takes the form:
Where sql_command_body
represents a standard SQL statement. You can use a host variable anywhere that the SQL statement expects a value expression. For more information about substituting host variables for value expressions, see Declaring host variables.
ECPGPlus extends the PostgreSQL server-side syntax for some statements. Syntax differences are noted in the reference information that follows. For a complete reference to the supported syntax of other SQL commands, see the PostgreSQL core documentation.
ALLOCATE DESCRIPTOR
Use the ALLOCATE DESCRIPTOR
statement to allocate an SQL descriptor area:
Where:
array_size
is a variable that specifies the number of array elements to allocate for the descriptor.array_size
can be anINTEGER
value or a host variable.descriptor_name
is the host variable that contains the name of the descriptor or the name of the descriptor. This value can take the form of an identifier, a quoted string literal, or of a host variable.variable_count
specifies the maximum number of host variables in the descriptor. The default value ofvariable_count
is100
.
The following code fragment allocates a descriptor named emp_query
that can be processed as an array (emp_array)
:
CALL
Use the CALL
statement to invoke a procedure or function on the server. The CALL
statement works only on EDB Postgres Advanced Server. The CALL
statement comes in two forms. The first form is used to call a function:
The second form is used to call a procedure:
Where:
program_name
is the name of the stored procedure or function that theCALL
statement invokes. The program name can be schema qualified, package qualified, or both. If you don't specify the schema or package in which the program resides, ECPGPlus uses the value ofsearch_path
to locate the program.actual_arguments
specifies a comma-separated list of arguments required by the program. Eachactual_argument
corresponds to a formal argument expected by the program. Each formal argument can be anIN
parameter, anOUT
parameter, or anINOUT
parameter.:ret_variable
specifies a host variable that receives the value returned if the program is a function.:ret_indicator
specifies a host variable that receives the indicator value returned if the program is a function.
For example, the following statement invokes the get_job_desc
function with the value contained in the :ename
host variable and captures the value returned by that function in the :job
host variable:
CLOSE
Use the CLOSE
statement to close a cursor and free any resources currently in use by the cursor. A client application can't fetch rows from a closed cursor. The syntax of the CLOSE
statement is:
Where cursor_name
is the name of the cursor closed by the statement. The cursor name can take the form of an identifier or of a host variable.
The OPEN
statement initializes a cursor. Once initialized, a cursor result set remains unchanged unless the cursor is reopened. You don't need to CLOSE
a cursor before reopening it.
To manually close a cursor named emp_cursor
, use the command:
A cursor is automatically closed when an application terminates.
COMMIT
Use the COMMIT
statement to complete the current transaction, making all changes permanent and visible to other users. The syntax is:
Where database_name
is the name of the database or host variable that contains the name of the database in which the work resides. This value can take the form of an unquoted string literal or of a host variable.
For compatibility, ECPGPlus accepts the COMMENT
clause without error but doesn't store any text included with the COMMENT
clause.
Include the RELEASE
clause to close the current connection after performing the commit.
For example, the following command commits all work performed on the dept
database and closes the current connection:
By default, statements are committed only when a client application performs a COMMIT
statement. Include the -t
option when invoking ECPGPlus to specify for a client application to invoke AUTOCOMMIT
functionality. You can also control AUTOCOMMIT
functionality in a client application with the following statements:
and
CONNECT
Use the CONNECT
statement to establish a connection to a database. The CONNECT
statement is available in two forms. One form is compatible with Oracle databases, and the other is not.
The first form is compatible with Oracle databases:
Where:
user_name
is a host variable that contains the role that the client application uses to connect to the server.password
is a host variable that contains the password associated with that role.connection_id
is a host variable that contains a slash-delimited user name and password used to connect to the database.
Include the AT
clause to specify the database to which the connection is established. database_name
is the name of the database to which the client is connecting. Specify the value in the form of a variable or as a string literal.
Include the USING
clause to specify a host variable that contains a null-terminated string identifying the database to which to establish the connection.
The ALTER AUTHORIZATION
clause is supported for syntax compatibility only. ECPGPlus parses the ALTER AUTHORIZATION
clause and reports a warning.
Using the first form of the CONNECT
statement, a client application might establish a connection with a host variable named user
that contains the identity of the connecting role and a host variable named password
that contains the associated password using the following command:
A client application can also use the first form of the CONNECT
statement to establish a connection using a single host variable named :connection_id
. In the following example, connection_id
contains the slash-delimited role name and associated password for the user:
The syntax of the second form of the CONNECT
statement is:
Where credentials
is one of the following:
In the second form:
database_name
is the name or identity of the database to which the client is connecting. Specify database_name
as a variable or as a string literal in one of the following forms:
Where:
hostname
is the name or IP address of the server on which the database resides.port
is the port on which the server listens.You can also specify a value of
DEFAULT
to establish a connection with the default database, using the default role name. If you specifyDEFAULT
as the target database, don't include aconnection_name
orcredentials
.connection_name
is the name of the connection to the database.connection_name
takes the form of an identifier (that is, not a string literal or a variable). You can open multiple connections by providing a uniqueconnection_name
for each connection.If you don't specify a name for a connection,
ecpglib
assigns a name ofDEFAULT
to the connection. You can refer to the connection by name (DEFAULT
) in anyEXEC SQL
statement.CURRENT
is the most recently opened or the connection mentioned in the most-recentSET CONNECTION TO
statement. If you don't refer to a connection by name in anEXEC SQL
statement, ECPG assumes the name of the connection to beCURRENT
.user_name
is the role used to establish the connection with the EDB Postgres Advanced Server database. The privileges of the specified role are applied to all commands performed through the connection.password
is the password associated with the specifieduser_name
.
The following code fragment uses the second form of the CONNECT
statement to establish a connection to a database named edb
using the role alice
and the password associated with that role, 1safepwd
:
The name of the connection is acctg_conn
. You can use the connection name when changing the connection name using the SET CONNECTION
statement.
DEALLOCATE DESCRIPTOR
Use the DEALLOCATE DESCRIPTOR
statement to free memory in use by an allocated descriptor. The syntax of the statement is:
Where descriptor_name
is the name of the descriptor. This value can take the form of a quoted string literal or of a host variable.
The following example deallocates a descriptor named emp_query
:
DECLARE CURSOR
Use the DECLARE CURSOR
statement to define a cursor. The syntax of the statement is:
Where:
database_name
is the name of the database on which the cursor operates. This value can take the form of an identifier or of a host variable. If you don't specify a database name, the default value ofdatabase_name
is the default database.cursor_name
is the name of the cursor.select_statement
is the text of theSELECT
statement that defines the cursor result set. TheSELECT
statement can't contain anINTO
clause.statement_name
is the name of a SQL statement or block that defines the cursor result set.
The following example declares a cursor named employees
:
The cursor generates a result set that contains the employee number, employee name, salary, and commission for each employee record that's stored in the emp
table.
DECLARE DATABASE
Use the DECLARE DATABASE
statement to declare a database identifier for use in subsequent SQL statements (for example, in a CONNECT
statement). The syntax is:
Where database_name
specifies the name of the database.
The following example shows declaring an identifier for the acctg
database:
After invoking the command declaring acctg
as a database identifier, you can reference the acctg
database by name when establishing a connection or in AT
clauses.
This statement has no effect and is provided for Pro*C compatibility only.
DECLARE STATEMENT
Use the DECLARE STATEMENT
directive to declare an identifier for an SQL statement. EDB Postgres Advanced Server supports two versions of the DECLARE STATEMENT
directive:
and
Where:
statement_name
specifies the identifier associated with the statement.database_name
specifies the name of the database. This value may take the form of an identifier or of a host variable that contains the identifier.
A typical usage sequence that includes the DECLARE STATEMENT
directive is:
This statement has no effect and is provided for Pro*C compatibility only.
DELETE
Use the DELETE
statement to delete one or more rows from a table. The syntax for the ECPGPlus DELETE
statement is the same as the syntax for the SQL statement, but you can use parameter markers and host variables any place that an expression is allowed. The syntax is:
- Include the
FOR exec_count
clause to specify the number of times the statement executes. This clause is valid only if theVALUES
clause references an array or a pointer to an array. table
is the name (optionally schema qualified) of an existing table. Include theONLY
clause to limit processing to the specified table. If you don't include theONLY
clause, any tables inheriting from the named table are also processed.alias
is a substitute name for the target table.using_list
is a list of table expressions, allowing columns from other tables to appear in theWHERE
condition.- Include the
WHERE
clause to specify the rows to delete. If you don't include aWHERE
clause in the statement,DELETE
deletes all rows from the table, leaving the table definition intact. condition
is an expression, host variable, or parameter marker that returns a value of typeBOOLEAN
. Those rows for whichcondition
returns true are deleted.cursor_name
is the name of the cursor to use in theWHERE CURRENT OF
clause. The row to be deleted is the one most recently fetched from this cursor. The cursor must be a nongrouping query on theDELETE
statements target table. You can't specifyWHERE CURRENT OF
in aDELETE
statement that includes a Boolean condition.
The RETURN/RETURNING
clause specifies an output_expression
or host_variable_list
that's returned by the DELETE
command after each row is deleted:
output_expression
is an expression to be computed and returned by theDELETE
command after each row is deleted.output_name
is the name of the returned column. Include * to return all columns.host_variable_list
is a comma-separated list of host variables and optional indicator variables. Each host variable receives a corresponding value from theRETURNING
clause.
For example, the following statement deletes all rows from the emp
table, where the sal
column contains a value greater than the value specified in the host variable, :max_sal:
For more information about using the DELETE
statement, see the PostgreSQL core documentation.
DESCRIBE
Use the DESCRIBE
statement to find the number of input values required by a prepared statement or the number of output values returned by a prepared statement. The DESCRIBE
statement is used to analyze a SQL statement whose shape is unknown at the time you write your application.
The DESCRIBE
statement populates an SQLDA
descriptor. To populate a SQL descriptor, use the ALLOCATE DESCRIPTOR
and DESCRIBE...DESCRIPTOR
statements.
Where:
statement_name
is the identifier associated with a prepared SQL statement or PL/SQL block.descriptor
is the name of C variable of typeSQLDA*
. You must allocate the space for the descriptor by callingsqlald()
and initialize the descriptor before executing theDESCRIBE
statement.
When you execute the first form of the DESCRIBE
statement, ECPG populates the given descriptor with a description of each input variable required by the statement. For example, given two descriptors:
You might prepare a query that returns information from the emp
table:
The command requires one input variable for the parameter marker (?).
After describing the bind variables for this statement, you can examine the descriptor to find the number of variables required and the type of each variable.
When you execute the second form, ECPG populates the given descriptor with a description of each value returned by the statement. For example, the following statement returns three values: