Block inserts and block fetches can be used to enhance the performance of an ODBC application.
They allow you to insert or retrieve rows in blocks, rather than individually. This reduces the data flows and line turnaround between the client and the server. Block fetches can be accomplished using either the SQLFetch (forward only) or SQLExtendedFetch or SQLFetchScroll API.
A block fetch:
The C example below does a block insert of 6 rows of data followed by two block fetches of two rows.
#define NUM_ROWS_INSERTED 6 #define NAME_LEN 10 HSTMT hstmt; SQLINTEGER rowcnt = NUM_ROWS_INSERTED; SQLCHAR itemNames[NUM_ROWS_INSERTED][NAME_LEN+1] = { "puzzle ", "candy bar ", "gum ","kite ", "toy car ", "crayons " }; SQLINTEGER itemPrices[NUM_ROWS_INSERTED] = { 5, 2, 1, 10, 3, 4 }; SQLCHAR queryItemNames[NUM_ROWS_INSERTED][NAME_LEN+1]; // Name return array SQLINTEGER queryItemPrices[NUM_ROWS_INSERTED]; // price return array SQLINTEGER cbqueryItemNames[NUM_ROWS_INSERTED], cbqueryItemPrices[NUM_ROWS_INSERTED]; rc = SQLAllocHandle(SQL_HANDLE_STMT, hdbc, &hstmt); rc = SQLExecDirect(hstmt, "CREATE TABLE ITEMS (NAME VARCHAR(10), PRICE INT)", SQL_NTS); // set the paramset size to 6 as we are block inserting 6 rows of data rc = SQLSetStmtAttr(hstmt, SQL_ATTR_PARAMSET_SIZE, (SQLPOINTER)rowcnt, SQL_IS_INTEGER); // bind the arrays to the parameters rc = SQLBindParameter(hstmt, 1, SQL_PARAM_INPUT, SQL_C_CHAR, SQL_VARCHAR, NAME_LEN, 0, itemNames[0], NAME_LEN + 1, NULL); rc = SQLBindParameter(hstmt, 2, SQL_PARAM_INPUT, SQL_C_LONG, SQL_INTEGER, NUM_ROWS_INSERTED, 0, &itemPrices[0], sizeof(long), NULL); // do the block insert rc = SQLExecDirect(hstmt, "INSERT INTO ITEMS ? ROWS VALUES(?,?)", SQL_NTS); // set up things for the block fetch // We set the concurrency below to SQL_CONCUR_READ_ONLY, but since SQL_CONCUR_READ_ONLY // is the default this API call is not necessary. If update was required then you would use // SQL_CONCUR_LOCK value as the last parameter. rc = SQLSetStmtAttr(hstmt, SQL_ATTR_CONCURRENCY, (SQLPOINTER)SQL_CONCUR_READ_ONLY, SQL_IS_INTEGER); // We set the cursor type to SQL_CURSOR_FORWARD_ONLY, but since SQL_CURSOR_FORWARD_ONLY // is the default this API call is not necessary. rc = SQLSetStmtAttr(hstmt, SQL_ATTR_CURSOR_TYPE, (SQLPOINTER)SQL_CURSOR_FORWARD_ONLY, SQL_IS_INTEGER); // We want to block fetch 2 rows at a time so we need to set SQL_ATTR_ROW_ARRAY_SIZE to 2. // If we were going to use SQLExtendedFetch instead of SQLFetchScroll we would instead need // to set the statement attribute SQL_ROWSET_SIZE to 2. rc = SQLSetStmtAttr(hstmt, SQL_ATTR_ROW_ARRAY_SIZE, (SQLPOINTER)2, SQL_IS_INTEGER); rc = SQLExecDirect(hstmt, "SELECT NAME, PRICE FROM ITEMS WHERE PRICE < 5", SQL_NTS); // bind arrays to hold the data for each column in the result set rc = SQLBindCol(hstmt, 1, SQL_C_CHAR, queryItemNames, NAME_LEN + 1, cbqueryItemNames); rc = SQLBindCol(hstmt, 2, SQL_C_LONG, queryItemPrices, sizeof(long), cbqueryItemPrices); // We know that there are 4 rows that fit the criteria for the SELECT statement so we call // two fetches to get all the data rc = SQLFetchScroll(hstmt, SQL_FETCH_FIRST, 0); // at this point 2 rows worth of data will have been fetched and put into the buffers // that were bound by SQLBindCol rc = SQLFetchScroll(hstmt, SQL_FETCH_NEXT, 0); // at this point 2 rows worth of data will have been fetched and put into the buffers // that were bound by SQLBindCol. Note that this second fetch overwrites the data in // those buffers with the new data // ... // Application processes the data in bound columns... // ...