A null-indicator variable is placed in an SQL statement immediately after the host variable, and is prefixed with a colon. A space can separate the null-indicator variable from the host variable, but is not required. However, do not put a comma between the host variable and the null-indicator variable. You can also specify a null-indicator variable by using the optional INDICATOR keyword, which you place between the host variable and its null indicator.
The null-indicator variable is examined for a negative value. If the value is not negative, the application can use the returned value of the host variable. If the value is negative, the fetched value is null and the host variable should not be used. The database manager does not change the value of the host variable in this case.
If the data type can handle nulls, the application must provide a null indicator. Otherwise, an error may occur. If a null indicator is not used, an SQLCODE -305 (SQLSTATE 22002) is returned.
When processing INSERT or UPDATE statements, the database manager checks the null-indicator variable, if one exists. If the indicator variable is negative, the database manager sets the target column value to null, if nulls are allowed.
If the null-indicator variable is zero or positive, the database manager uses the value of the associated host variable.
Starting in DB2® V10.1 Fix Pack 2 and later, if the new PRECOMPILE UNSAFENULL option is set to YES, the NULL values will not cause unspecified indicator variable error. This option is applicable only when COMPATIBILITY_MODE is set to ORA.
Starting in DB2 V10.1 Fix Pack 2 and later, application can check sqlca.sqlerrd[2] to get cumulative sum of number of rows populated successfully till the last FETCH using same cursor.
The SQLWARN1 field in the SQLCA structure might contain an X or W if the value of a string column is truncated when it is assigned to a host variable. The field contains an N if a null terminator is truncated.
The value returned in the null-indicator variable will be the length of the resultant character string in the application's code page.
In all other cases involving data truncation (as opposed to null terminator truncation), the database manager returns a W. In this case, the database manager returns a value in the null-indicator variable to the application that is the length of the resultant character string in the code page of the select list item (either the application code page, the database code page, or nothing).
EXEC SQL BEGIN DECLARE SECTION;
char cm[3];
short cmind;
EXEC SQL END DECLARE SECTION;
| Language | Example Source Code |
|---|---|
| C and C++ |
|
| COBOL |
|
| FORTRAN |
|
| REXX |
|