A SELECT statement that returns only a single row can be prepared dynamically, followed by an EXECUTE with an INTO clause to retrieve the one-row result. SELECT statements that return multiple rows, however, are managed using dynamic cursors.
With dynamic cursors, results are put into a host variable list or a SQLDA that is specified on the FETCH statement (FETCH INTO and FETCH USING DESCRIPTOR). Since the number of select list items is usually unknown to the C programmer, the SQLDA route is the most common. The DESCRIBE SELECT LIST statement sets up a SQLDA with the types of the select list items. Space is then allocated for the values using the fill_sqlda or fill_s_sqlda functions, and the information is retrieved by the FETCH USING DESCRIPTOR statement.
The typical scenario is as follows:
EXEC SQL BEGIN DECLARE SECTION; char comm[200]; EXEC SQL END DECLARE SECTION; int actual_size; SQLDA * sqlda; ... sprintf( comm, "select * from %s", table_name ); EXEC SQL PREPARE S1 FROM :comm; /* Initial guess of 10 columns in result. If it is wrong, it is corrected right after the first DESCRIBE by reallocating sqlda and doing DESCRIBE again. */ sqlda = alloc_sqlda( 10 ); EXEC SQL DESCRIBE SELECT LIST FOR S1 INTO sqlda; if( sqlda->sqld > sqlda->sqln ) { actual_size = sqlda->sqld; free_sqlda( sqlda ); sqlda = alloc_sqlda( actual_size ); EXEC SQL DESCRIBE SELECT LIST FOR S1 INTO sqlda; } fill_sqlda( sqlda ); EXEC SQL DECLARE C1 CURSOR FOR S1; EXEC SQL OPEN C1; EXEC SQL WHENEVER NOTFOUND {break}; for( ;; ) { EXEC SQL FETCH C1 USING DESCRIPTOR sqlda; /* do something with data */ } EXEC SQL CLOSE C1; EXEC SQL DROP STATEMENT S1; |
To avoid consuming unnecessary resources, ensure that statements are dropped after use.
For a complete example using cursors for a dynamic select statement, see Dynamic cursor sample.
For more information about the functions mentioned above, see Library function reference.
Send feedback about this page via email or DocCommentXchange | Copyright © 2008, iAnywhere Solutions, Inc. - SQL Anywhere 11.0.0 |