Shows information about locks in the database, for both the IQ store and the catalog store.
sp_iqlocks ([connection,] [[ owner.]table_name] max_locks,] [sort_order])
DBA authority required. Users without DBA authority must be granted EXECUTE permission to run the stored procedure.
Table 7-43 lists the optional sp_iqlocks parameters you can specify to restrict results.
Name |
Data type |
Description |
---|---|---|
connection |
integer |
Connection ID. With this option, the procedure returns information about locks for the specified connection only. Default is zero, which returns information about all connections. |
owner.table_ name |
char (128) |
Table name. With this option, the procedure returns information about locks for the specified table only. Default is NULL, which returns information about all tables in the database. If you do not specify owner, it is assumed that the caller of the procedure owns the table. |
max_locks |
integer |
Maximum number of locks for which to return information. Default is 0, which returns all lock information. |
sort_order |
char(1) |
Order in which to return information:
|
Displays information about current locks in the database. Depending on the options you specify, you can restrict results to show locks for a single connection, a single table, or a specified number of locks.
sp_iqlocks displays the following information, sorted as specified in the sort_order parameter:
Column |
Description |
---|---|
conn_name |
The name of the current connection. |
conn_id |
Connection ID that has the lock. |
user_id |
User associated with this connection ID. |
table_type |
The type of table. This type is either BASE for a table, GLBTMP for global temporary table, or MVIEW for a materialized view. |
creator |
The owner of the table. |
table_name |
Table on which the lock is held. |
index_id |
The index ID or NULL |
lock_class |
String of characters indicating the type of lock:
All locks listed have one of S, E, EW, or SW, and may also have P, A, or both. Phantom and antiphantom locks also have a qualifier of T or *:
Sybase IQ obtains a share lock before a write lock. If a connection has exclusive lock, share lock does not appear. For write locks, if a connection has all-exclusive, share, and write locks, it is EW. |
lock_type |
Value identifying the lock (dependent on the lock class) |
row_identifier |
The identifier for the row or NULL. |
If sp_iqlocks cannot find the
connection ID or user name of the user who has a lock on a table,
it displays a 0 (zero) for the connection ID and User unavailable
for
the user name.
Exclusive, phantom, or antiphantom locks can be placed on SQL Anywhere tables, but not on Sybase IQ tables. Unless you have explicitly taken out locks on a table in the catalog store, you never see these types of locks (or their qualifiers T, *, and nnn) in a Sybase IQ database. For information on how locking works in SQL Anywhere tables, see SQL Anywhere Server – SQL Usage.
The example shows the sp_iqlocks procedure call and its output in a Sybase IQ database. The procedure is called with all default options, so that the output shows all locks, sorted by connection.
call sp_iqlocks()
conn_name conn_id user_id table_type creator table_name ========= ======= ======= ========== ======= ========== con1 70187172 'mary' BASE DBA t1 index_id lock_class lock_duration lock_type row_identifier ======== ========== ============= ========= ============== ASIQ_IDX_T452_C19_FP Table Position Table 1