Examples

The following examples illustrate both the usefulness and the dangers of using nondeterministic computed columns and index keys. All examples in this document are intended only for illustrative purposes.


Example 1

CREATE TABLE Renting
     (Cust_ID INT, Cust_Name VARCHAR(30),
     Formatted_Name COMPUTE format_name(Cust_Name),      Property_ID INT,Property_Name COMPUTE 
     get_pname(Property_ID), start_date COMPUTE
     today_date()MATERIALIZED, Rent_due COMPUTE
     rent_calculator(Property_ID, Cust_ID,      Start_Date))

The table Renting in this example stores rental information on various properties. It contains these fields:

Table 7-8: Fields in the Renting table

Field

Definition

Cust_ID

ID of the customer

Cust_Name

Name of the customer

Formatted_Name

Customer’s name in a standard format

Property_ID

ID of the property rented

Property_Name

Name of the property in a standard format

Start_Date

Starting day of the rent

Rent_Due

Amount of rent due today

Formatted_Name, Property_Name, Start_Date, and Rent_Due are defined as computed columns.


How the deterministic property affects virtual computed columns


How the deterministic property affects materialized computed columns

Adaptive Server guarantees repeatable reads on materialized computed columns, regardless of their deterministic property, because they are not reevaluated when you reference them in a query. Instead, Adaptive Server uses the preevaluated values.

Deterministic materialized computed columns always have the same values, however often they are reevaluated.

Nondeterministic materialized computed columns must adhere to these rules:

In Example 1, Start_Date is a nondeterministic materialized computed column. Its results differ, depending on what day you insert the row. For instance, if the rental period begins on “02/05/04,” “02/05/04” is inserted into the column, and later references to Start_Date use this value. If you decide to reference this value later, on 06/05/04, the query continues to return “02/05/04,” not “06/05/04,” as you would expect if the expression was evaluated every time you query the column.


Example 2

Suppose you use the table created in Example 1, Renting, and create an index on the virtual computed column Property_Name, transforming Property_Name into a materialized computed column. Then, you insert a new record:

Property_ID=10

Inserting this new record calls getpname(10) from the table Property, executing this JDBC query:

SELECT Property_Name from Property where Property_ID=10

The query returns “Rose Palace,” which is stored in the data row. This all works, unless someone changes the name of the property by issuing this query:

UPDATE Property SET Property_Name ='Red Rose Palace'
     where Property_ID = 10

The query returns “Rose Palace,” so Adaptive Server stores “Rose Palace.” This update command on the table Property invalidates the stored value of Property_Name in the table Renting, which must also be updated to “Red Rose Palace.” Because Property_Name is defined on the column Property_ID in the table Renting, not on the column Property_Name in the table Property, it is not automatically updated. Future reference to Property_Name may produce incorrect results.

To avoid this situation, create a trigger on the table Property:

CREATE TRIGGER my_t ON Property FOR UPDATE AS
     IF UPDATE(Property_Name)
     BEGIN
     UPDATE Renting SET Renting.Property_ID=Property.Property_ID
          FROM Renting, Property
          WHERE Renting.Property_ID=Property.Property_ID
     END

When this trigger updates the column Property_Name in the table Property, it also updates the column Renting.Property_ID, the base column of Property_Name. This automatic update triggers Adaptive Server to reevaluate Property_Name and update the value stored in the data row. Each time Adaptive Server updates the column Property_Name in the table Property, the materialized computed column Property_Name in the table Renting is refreshed, and shows the correct value.