Lesson 1: Creating phantom rows

 Create a phantom row
  1. Start two instances of Interactive SQL. See steps 1 through 4 of Tutorial: Understanding non-repeatable reads.

  2. Set the isolation level to 2 in the Sales Manager window by executing the following statement.

    SET TEMPORARY OPTION isolation_level = 2;
  3. Set the isolation level to 2 for the Accountant window by executing the following statement.

    SET TEMPORARY OPTION isolation_level = 2;
  4. In the Accountant window, enter the following statement to list all the departments.

    SELECT * FROM Departments
    ORDER BY DepartmentID;
    DepartmentID DepartmentName DepartmentHeadID
    100 R & D 501
    200 Sales 902
    300 Finance 1293
    400 Marketing 1576
    500 Shipping 703
  5. The Sales Manager decides to set up a new department to focus on the foreign market. Philip Chin, who has EmployeeID 129, heads the new department.

    INSERT INTO Departments
       ( DepartmentID, DepartmentName, DepartmentHeadID )
       VALUES( 600, 'Foreign Sales', 129 );
    COMMIT;

    The final statement creates the new entry for the new department. It appears as a new row at the bottom of the table in the Sales Manager's window.

    In the Sales Manager window, enter the following statement to list all the departments.

    SELECT *
    FROM Departments
    ORDER BY DepartmentID;
    DepartmentID DepartmentName DepartmentHeadID
    100 R & D 501
    200 Sales 902
    300 Finance 1293
    400 Marketing 1576
    500 Shipping 703
    600 Foreign Sales 129
  6. The Accountant, however, is not aware of the new department. At isolation level 2, the database server places locks to ensure that no row changes, but places no locks that stop other transactions from inserting new rows.

    The Accountant will only discover the new row if he executes his SELECT statement again. In the Accountant's window, execute the SELECT statement again. You will see the new row appended to the table.

    SELECT *
    FROM Departments
    ORDER BY DepartmentID;
    DepartmentID DepartmentName DepartmentHeadID
    100 R & D 501
    200 Sales 902
    300 Finance 1293
    400 Marketing 1576
    500 Shipping 703
    600 Foreign Sales 129

    The new row that appears is called a phantom row because, from the Accountant's point of view, it appears like an apparition, seemingly from nowhere. The Accountant is connected at isolation level 2. At that level, the database server acquires locks only on the rows that he is using. Other rows are left untouched, so there is nothing to prevent the Sales Manager from inserting a new row.

  7. The Accountant would prefer to avoid such surprises in future, so he raises the isolation level of his current transaction to level 3. Enter the following statements for the Accountant.

    SET TEMPORARY OPTION isolation_level = 3;
    SELECT *
    FROM Departments
    ORDER BY DepartmentID;
  8. The Sales Manager would like to add a second department to handle a sales initiative aimed at large corporate partners. Execute the following statement in the Sales Manager's window.

    INSERT INTO Departments
     ( DepartmentID, DepartmentName, DepartmentHeadID )
       VALUES( 700, 'Major Account Sales', 902 );

    The Sales Manager's window pauses during execution because the Accountant's locks block the statement. From the toolbar, click Stop (or click SQL » Stop) to interrupt this entry.

  9. To avoid changing the SQL Anywhere sample database, you should roll back the incomplete transaction that inserts the Major Account Sales department row and use a second transaction to delete the Foreign Sales department.

    1. Execute the following statement in the Sales Manager's window to rollback the last, incomplete transaction:

      ROLLBACK;
    2. Also in the Sales Manager's window, execute the following two statements to delete the row that you inserted earlier and commit this operation.

      DELETE FROM Departments
      WHERE DepartmentID = 600;
      COMMIT;
 Explanation
 See also