×
The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.
On 16-Jun-2011 11:31 , Gqcy wrote:
Is there a way, when I write a record with a identity column, that
the SQL can return the value?
I would like to push that value to other files, but am I stuck to
retrieving the record again to find out the value of the identity
column?
A couple means for which fetching the just-inserted row is not required:
1) Since v6r1 the "SELECT FROM INSERT" support:
http://publib.boulder.ibm.com/infocenter/iseries/v6r1m0/topic/sqlp/rbafysfins.htm
"The following example uses a table defined as follows:
CREATE TABLE EMPSAMP
(EMPNO INTEGER GENERATED ALWAYS AS IDENTITY,
NAME CHAR(30),
SALARY DECIMAL(10,2),
DEPTNO SMALLINT,
LEVEL CHAR(30),
HIRETYPE VARCHAR(30) NOT NULL DEFAULT 'New Employee',
HIREDATE DATE NOT NULL WITH DEFAULT)
To insert a row for a new employee and see the values that were used for
EMPNO, HIRETYPE, and HIREDATE, use the following statement:
SELECT EMPNO, HIRETYPE, HIREDATE
FROM FINAL TABLE
( INSERT INTO EMPSAMP
( NAME , SALARY , DEPTNO , LEVEL )
VALUES('Mary Smith', 35000.00, 11, 'Associate')
)
The returned values are the generated value for EMPNO, 'New Employee'
for HIRETYPE, and the current date for HIREDATE."
2) The [non-deterministic] scalar function IDENTITY_VAL_LOCAL
http://publib.boulder.ibm.com/infocenter/iseries/v6r1m0/topic/db2/rbafzscaidentity.htm
"Examples
* Set the variable IVAR to the value assigned to the identity
column in the EMPLOYEE table. The value returned from the function in
the VALUES statement should be 1.
CREATE TABLE EMPLOYEE
(EMPNO INTEGER GENERATED ALWAYS AS IDENTITY,
NAME CHAR(30),
SALARY DECIMAL(5,2),
DEPT SMALLINT)
INSERT INTO EMPLOYEE
(NAME, SALARY, DEPTNO)
VALUES('Rupert', 989.99, 50)
VALUES IDENTITY_VAL_LOCAL() INTO :IVAR
"
Regards, Chuck
As an Amazon Associate we earn from qualifying purchases.