The TREAT function comes in very handy when working with an object type hierarchy, and you need to access attributes or methods of a subtype of a row or column's declared type. This topic was covered in a PL/SQL Challenge quiz offered in March 2016.
Suppose I have the following type hierarchy and I use them as column types in my meals table:
I then insert some rows into the table:
Notice that even though appetizer and main_course are defined as food_t, I can assign dessert_t and cake_t instances to those columns, because object types support substitutability (the best way to understand that is: every dessert is a food, but not every food is a dessert).
Let's take a look at some of the ways I can use TREAT.
1. I want to find all the meals in which the main course is actually a dessert.
And now with "pure" SQL:
If I forget the TREAT in the SELECT list, such as:
I will see this error:
3. Set to NULL any desserts that are not cakes.
Suppose I have the following type hierarchy and I use them as column types in my meals table:
CREATE TYPE food_t AS OBJECT (
name VARCHAR2 (100),
food_group VARCHAR2 (100),
grown_in VARCHAR2 (100)
)
NOT FINAL;
/
CREATE TYPE dessert_t UNDER food_t (
contains_chocolate CHAR (1),
year_created NUMBER (4)
)
NOT FINAL;
/
CREATE TYPE cake_t UNDER dessert_t (
diameter NUMBER,
inscription VARCHAR2 (200)
);
/
CREATE TABLE meals
(
served_on DATE,
appetizer food_t,
main_course food_t,
dessert dessert_t
);
I then insert some rows into the table:
BEGIN
INSERT INTO meals
VALUES (SYSDATE + 1,
food_t ('Shrimp cocktail', 'PROTEIN', 'Ocean'),
food_t ('Stir fry tofu', 'PROTEIN', 'Vat'),
cake_t ('Apple Pie',
'FRUIT', 'Baker''s Square',
'N', 2001, 8, NULL));
INSERT INTO meals
VALUES (SYSDATE + 1,
food_t ('Fried Calamari', 'PROTEIN', 'Ocean'),
dessert_t ('Butter cookie',
'CARBOHYDRATE', 'Oven', 'N', 2001),
cake_t ('French Silk Pie',
'CARBOHYDRATE', 'Baker''s Square',
Y', 2001, 6, 'To My Favorite Frenchman'));
INSERT INTO meals
VALUES (SYSDATE + 1,
food_t ('Fried Calamari', 'PROTEIN', 'Ocean'),
cake_t ('French Silk Pie',
'CARBOHYDRATE', 'Baker''s Square',
'Y', 2001, 6, 'To My Favorite Frenchman'),
dessert_t ('Butter cookie',
'CARBOHYDRATE', 'Oven', 'N', 2001));
COMMIT;
END;
/
Notice that even though appetizer and main_course are defined as food_t, I can assign dessert_t and cake_t instances to those columns, because object types support substitutability (the best way to understand that is: every dessert is a food, but not every food is a dessert).
Let's take a look at some of the ways I can use TREAT.
1. I want to find all the meals in which the main course is actually a dessert.
SELECT *
FROM meals
WHERE TREAT (main_course AS dessert_t) IS NOT NULL
2. Show whether or not those dessert-centric meals contain chocolate. First with PL/SQL:
DECLARE
l_dessert dessert_t;
BEGIN
FOR rec IN (
SELECT * FROM meals
WHERE TREAT (main_course AS dessert_t) IS NOT NULL)
LOOP
l_dessert := TREAT (rec.main_course AS dessert_t);
DBMS_OUTPUT.put_line (
rec.main_course.name || '-' ||
l_dessert.contains_chocolate);
END LOOP;
END;
/
And now with "pure" SQL:
SELECT TREAT (m.main_course AS dessert_t).contains_chocolate
FROM meals m
WHERE TREAT (main_course AS dessert_t) IS NOT NULL
The thing to realize in both these cases is that even though I have identified only those meals for which the main course is a dessert, I still must explicitly TREAT or narrow the main_course column to dessert_t, before I will be able to reference the contains_chocolate attribute.
If I forget the TREAT in the SELECT list, such as:
SELECT m.main_course.contains_chocolate
FROM meals m
WHERE TREAT (main_course AS dessert_t) IS NOT NULL
I will see this error:
ORA-00904: "M"."MAIN_COURSE"."CONTAINS_CHOCOLATE": invalid identifier
3. Set to NULL any desserts that are not cakes.
UPDATE meal
SET dessert = TREAT (dessert AS cake_t);
Comments
Post a Comment