If you do not specify a derived-column name, the behavior of the database server depends on the data types of the elements in the underlying collection.
Although a collection-derived table appears to contain columns of individual data types, these columns are, in fact, the fields of a ROW data type. The data type of the ROW type as well as the column name depend on several factors.
If the data type of the elements of the underlying collection expression is type, the database server determines the ROW type of the collection-derived table by the following rules:
The extended examples that the following table shows illustrate these rules. The table uses the following schema for its examples:
CREATE ROW TYPE person (name CHAR(255), id INT); CREATE TABLE parents ( name CHAR(255), id INT, children LIST (person NOT NULL) ); CREATE TABLE parents2 ( name CHAR(255), id INT, children_ids LIST (INT NOT NULL) );
ROW
Type |
Explicit
Derived- Column List |
Resulting ROW Type of the Collection-Derived Table | Code Example |
---|---|---|---|
Yes | No | Type |
SELECT (SELECT c_table.name FROM TABLE(parents.children) c_table WHERE c_table.id = 1002) FROM parents WHERE parents.id = 1001 In this example, the ROW type of c_table is parents. |
Yes | Yes | Unnamed ROW type of which the column type is Type and the column name is the name in the derived-column list |
SELECT (SELECT c_table.c_name FROM TABLE(parents.children) c_table(c._name, c_id) WHERE c_table.c_id = 1002) FROM parents WHERE parents.id = 1001 In this example, the ROW type of c_table is
|
No | No | Unnamed ROW that contains one column of Type that is assigned an implementation-dependent name | In the following example, if you do not specify c_id, the database server assigns a name to the derived column. In this case, the ROW type of c_table is ROW(server_defined_name INT). |
No | Yes | Unnamed ROW type that contains one column of Type whose name is in the derived-column list |
SELECT(SELECT c_table.c_id FROM TABLE(parents2.child_ids) c_table (c_id) WHERE c_table.c_id = 1002) FROM parents WHERE parents.id = 1001 Here the ROW type of c_table is ROW(c_id INT). |
The following program fragment creates a collection-derived table using an SPL function that returns a single value:
CREATE TABLE wanted(person_id int); CREATE FUNCTION wanted_person_count (person_set SET(person NOT NULL)) RETURNS INT; RETURN( SELECT COUNT (*) FROM TABLE (person_set) c_table, wanted WHERE c_tabel.id = wanted.person_id); END FUNCTION;
The next program fragment shows the more general case of creating a collection-derived table using an SPL function that returns multiple values:
-- Table of categories and child categories, -- allowing any number of levels of subcategories CREATE TABLE CategoryChild ( categoryId INTEGER, childCategoryId SMALLINT ); INSERT INTO CategoryChild VALUES (1, 2); INSERT INTO CategoryChild VALUES (1, 3); INSERT INTO CategoryChild VALUES (1, 4); INSERT INTO CategoryChild VALUES (2, 5); INSERT INTO CategoryChild VALUES (2, 6); INSERT INTO CategoryChild VALUES (5, 7); INSERT INTO CategoryChild VALUES (7, 8); INSERT INTO CategoryChild VALUES (7, 9); INSERT INTO CategoryChild VALUES (4, 10); -- "R" == ROW type CREATE ROW TYPE categoryLevelR ( categoryId INTEGER, level SMALLINT ); -- DROP FUNCTION categoryDescendants ( -- INTEGER, SMALLINT ); CREATE FUNCTION categoryDescendants ( pCategoryId INTEGER, pLevel SMALLINT DEFAULT 0 ) RETURNS MULTISET (categoryLevelR NOT NULL) -- "p" == Prefix for Parameter names -- "l" == Prefix for Local variable names DEFINE lCategoryId LIKE CategoryChild.categoryId; DEFINE lRetSet MULTISET (categoryLevelR NOT NULL); DEFINE lCatRow categoryLevelR; -- TRACE ON; -- Must initialize collection before inserting rows LET lRetSet = 'MULTISET{}' :: MULTISET (categoryLevelR NOT NULL);
FOREACH SELECT childCategoryId INTO lCategoryId FROM CategoryChild WHERE categoryId = pCategoryId; INSERT INTO TABLE (lRetSet) VALUES (ROW (lCategoryId, pLevel+1)::categoryLevelR); -- INSERT INTO TABLE (lRetSet); -- EXECUTE FUNCTION categoryDescendantsR ( lCategoryId, -- pLevel+1 ); -- Need to iterate over results and insert into SET. -- See the SQL Tutorial, pg. 10-52: -- "Tip: You can only insert one value at a time -- into a simple collection." FOREACH EXECUTE FUNCTION categoryDescendantsR ( lCategoryId, pLevel+1 ) INTO lCatRow; INSERT INTO TABLE (lRetSet) VALUES (lCatRow); END FOREACH; END FOREACH; RETURN lRetSet; END FUNCTION ; -- "R" == recursive -- DROP FUNCTION categoryDescendantsR (INTEGER, SMALLINT); CREATE FUNCTION categoryDescendantsR ( pCategoryId INTEGER, pLevel SMALLINT DEFAULT 0 ) RETURNS categoryLevelR; DEFINE lCategoryId LIKE CategoryChild.categoryId; DEFINE lCatRow categoryLevelR; FOREACH SELECT childCategoryId INTO lCategoryId FROM CategoryChild WHERE categoryId = pCategoryId RETURN ROW (lCategoryId, pLevel+1)::categoryLevelR WITH RESUME; FOREACH EXECUTE FUNCTION categoryDescendantsR ( lCategoryId, pLevel+1 ) INTO lCatRow RETURN lCatRow WITH RESUME; END FOREACH; END FOREACH; END FUNCTION; -- Test the functions: SELECT lev, col FROM TABLE (( categoryDescendants (1, 0) )) AS CD (col, lev);Enterprise Edition Home | Express Edition Home | [ Top of Page | Previous Page | Next Page | Contents | Index ]