Storing structured type objects in table columns
About this task
Furthermore, you can define a type hierarchy of addresses to model different formats of addresses that are used in different countries or regions. For example, you might want to include both a US address type, which contains a zip code, and a Brazilian address type, for which the neighborhood attribute is required.
Address_t
,
which has three subtypes, each with an additional attribute that reflects
some aspect of how addresses are formed in that region.
CREATE TYPE Address_t AS
(street VARCHAR(30),
number CHAR(15),
city VARCHAR(30),
state VARCHAR(10))
MODE DB2SQL;
CREATE TYPE Germany_addr_t UNDER Address_t AS
(family_name VARCHAR(30))
MODE DB2SQL;
CREATE TYPE Brazil_addr_t UNDER Address_t AS
(neighborhood VARCHAR(30))
MODE DB2SQL;
CREATE TYPE US_addr_t UNDER Address_t AS
(zip CHAR(10))
MODE DB2SQL;
When objects are stored as column values, the attributes are not externally represented as they
are with objects stored in rows of tables. Instead, you must use methods to manipulate their
attributes. Db2
generates both observer methods to return attributes, and mutator methods
to change attributes. The following example uses one observer method and two mutator methods, one
for the Number
attribute and one for the Street
attribute, to
change an address:
UPDATE Employee
SET Address=Address..Number('4869')..Street('Appletree')
WHERE Name='Franky'
AND Address..State='CA';
In the preceding example,
the SET clause of the UPDATE statement invokes the Number
and Street
mutator
methods to update attributes of the instances of type Address_t
.
UPDATE Employee
SET Address..Number = '4869',
Address..Street = 'Appletree'
WHERE Name='Franky' AND Address..State='CA'
The WHERE clause restricts the operation of the update statement with two predicates: an equality
comparison for the Name
column, and an equality comparison that invokes the
State
observer method of the Address
column.