定位更新和删除语句
应用程序可以使用定位的更新或删除语句更新或删除结果集中的当前行。 一些数据源支持定位更新和删除语句,但不是所有数据源都支持它们。 要确定数据源是否支持定位更新和删除语句,应用程序可以使用 SQL_DYNAMIC_CURSOR_ATTRIBUTES1、SQL_FORWARD_ONLY_CURSOR_ATTRIBUTES1、SQL_KEYSET_CURSOR_ATTRIBUTES1 或 SQL_STATIC_CURSOR_ATTRIBUTES1 InfoType 来调用 SQLGetInfo(具体取决于游标的类型)。 请注意,ODBC 游标库可模拟定位的更新和删除语句。
要使用定位的更新或删除语句,应用程序必须使用 SELECT FOR UPDATE 语句创建结果集。 此语句的语法为:
SELECT [ALL | DISTINCT] select-list
FROM table-reference-list
[WHERE search-condition]
FOR UPDATE OF [column-name [, column-name]...]
然后,应用程序将光标定位于要更新或删除的行上。 它可以通过调用 SQLFetchScroll 来检索包含所需行的行集,并调用 SQLSetPos 将行集游标定位于该行上。 然后,应用程序在与结果集使用的语句不同的语句上执行定位更新或删除语句。 这些语句的语法为:
UPDATE table-name
SET column-identifier = {expression | NULL}
[, column-identifier = {expression | NULL}]...
WHERE CURRENT OF cursor-name
DELETE FROM table-name WHERE CURRENT OF cursor-name
请注意,这些语句需要游标名称。 应用程序可以在执行创建结果集的语句之前使用 SQLSetCursorName 指定游标名称,也可以让数据源在创建游标时自动生成游标名称。 在后一种情况下,应用程序通过调用 SQLGetCursorName 来检索此游标名称以用于定位更新和删除语句。
例如,以下代码允许用户滚动浏览 Customers 表并删除客户记录或更新其地址和电话号码。 它调用 SQLSetCursorName 以在创建客户的结果集之前指定游标名称,并使用三个语句句柄:结果集的 hstmtCust、定位更新语句的 hstmtUpdate 和定位删除语句的 hstmtDelete。 尽管代码可以将单独的变量绑定到定位更新语句中的参数,但它会更新行集缓冲区并绑定这些缓冲区的元素。 这会使行集缓冲区与更新的数据保持同步。
#define POSITIONED_UPDATE 100
#define POSITIONED_DELETE 101
SQLUINTEGER CustIDArray[10];
SQLCHAR NameArray[10][51], AddressArray[10][51],
PhoneArray[10][11];
SQLINTEGER CustIDIndArray[10], NameLenOrIndArray[10],
AddressLenOrIndArray[10],
PhoneLenOrIndArray[10];
SQLUSMALLINT RowStatusArray[10], Action, RowNum;
SQLHSTMT hstmtCust, hstmtUpdate, hstmtDelete;
// Set the SQL_ATTR_BIND_TYPE statement attribute to use column-wise
// binding. Declare the rowset size with the SQL_ATTR_ROW_ARRAY_SIZE
// statement attribute. Set the SQL_ATTR_ROW_STATUS_PTR statement
// attribute to point to the row status array.
SQLSetStmtAttr(hstmtCust, SQL_ATTR_ROW_BIND_TYPE, SQL_BIND_BY_COLUMN, 0);
SQLSetStmtAttr(hstmtCust, SQL_ATTR_ROW_ARRAY_SIZE, 10, 0);
SQLSetStmtAttr(hstmtCust, SQL_ATTR_ROW_STATUS_PTR, RowStatusArray, 0);
// Bind arrays to the CustID, Name, Address, and Phone columns.
SQLBindCol(hstmtCust, 1, SQL_C_ULONG, CustIDArray, 0, CustIDIndArray);
SQLBindCol(hstmtCust, 2, SQL_C_CHAR, NameArray, sizeof(NameArray[0]),
NameLenOrIndArray);
SQLBindCol(hstmtCust, 3, SQL_C_CHAR, AddressArray, sizeof(AddressArray[0]),
AddressLenOrIndArray);
SQLBindCol(hstmtCust, 4, SQL_C_CHAR, PhoneArray, sizeof(PhoneArray[0]),
PhoneLenOrIndArray);
// Set the cursor name to Cust.
SQLSetCursorName(hstmtCust, "Cust", SQL_NTS);
// Prepare positioned update and delete statements.
SQLPrepare(hstmtUpdate,
"UPDATE Customers SET Address = ?, Phone = ? WHERE CURRENT OF Cust",
SQL_NTS);
SQLPrepare(hstmtDelete, "DELETE FROM Customers WHERE CURRENT OF Cust", SQL_NTS);
// Execute a statement to retrieve rows from the Customers table.
SQLExecDirect(hstmtCust,
"SELECT CustID, Name, Address, Phone FROM Customers FOR UPDATE OF Address, Phone",
SQL_NTS);
// Fetch and display the first 10 rows.
SQLFetchScroll(hstmtCust, SQL_FETCH_NEXT, 0);
DisplayData(CustIDArray, CustIDIndArray, NameArray, NameLenOrIndArray, AddressArray,
AddressLenOrIndArray, PhoneArray, PhoneLenOrIndArray, RowStatusArray);
// Call GetAction to get an action and a row number from the user.
while (GetAction(&Action, &RowNum)) {
switch (Action) {
case SQL_FETCH_NEXT:
case SQL_FETCH_PRIOR:
case SQL_FETCH_FIRST:
case SQL_FETCH_LAST:
case SQL_FETCH_ABSOLUTE:
case SQL_FETCH_RELATIVE:
// Fetch and display the requested data.
SQLFetchScroll(hstmtCust, Action, RowNum);
DisplayData(CustIDArray, CustIDIndArray, NameArray, NameLenOrIndArray,
AddressArray, AddressLenOrIndArray, PhoneArray,
PhoneLenOrIndArray, RowStatusArray);
break;
case POSITIONED_UPDATE:
// Get the new data and place it in the rowset buffers.
GetNewData(AddressArray[RowNum - 1], &AddressLenOrIndArray[RowNum - 1],
PhoneArray[RowNum - 1], &PhoneLenOrIndArray[RowNum - 1]);
// Bind the elements of the arrays at position RowNum-1 to the
// parameters of the positioned update statement.
SQLBindParameter(hstmtUpdate, 1, SQL_PARAM_INPUT, SQL_C_CHAR, SQL_CHAR,
50, 0, AddressArray[RowNum - 1], sizeof(AddressArray[0]),
&AddressLenOrIndArray[RowNum - 1]);
SQLBindParameter(hstmtUpdate, 2, SQL_PARAM_INPUT, SQL_C_CHAR, SQL_CHAR,
10, 0, PhoneArray[RowNum - 1], sizeof(PhoneArray[0]),
&PhoneLenOrIndArray[RowNum - 1]);
// Position the rowset cursor. The rowset is 1-based.
SQLSetPos(hstmtCust, RowNum, SQL_POSITION, SQL_LOCK_NO_CHANGE);
// Execute the positioned update statement to update the row.
SQLExecute(hstmtUpdate);
break;
case POSITIONED_DELETE:
// Position the rowset cursor. The rowset is 1-based.
SQLSetPos(hstmtCust, RowNum, SQL_POSITION, SQL_LOCK_NO_CHANGE);
// Execute the positioned delete statement to delete the row.
SQLExecute(hstmtDelete);
break;
}
}
// Close the cursor.
SQLCloseCursor(hstmtCust);