Skip to main content

Use TREAT to Access Attributes of Object Subtypes

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:

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

Popular posts from this blog

Quick Guide to User-Defined Types in Oracle PL/SQL

A Twitter follower recently asked for more information on user-defined types in the PL/SQL language, and I figured the best way to answer is to offer up this blog post. PL/SQL is a strongly-typed language . Before you can work with a variable or constant, it must be declared with a type (yes, PL/SQL also supports lots of implicit conversions from one type to another, but still, everything must be declared with a type). PL/SQL offers a wide array of pre-defined data types , both in the language natively (such as VARCHAR2, PLS_INTEGER, BOOLEAN, etc.) and in a variety of supplied packages (e.g., the NUMBER_TABLE collection type in the DBMS_SQL package). Data types in PL/SQL can be scalars, such as strings and numbers, or composite (consisting of one or more scalars), such as record types, collection types and object types. You can't really declare your own "user-defined" scalars, though you can define subtypes  from those scalars, which can be very helpful from the p

The differences between deterministic and result cache features

 EVERY once in a while, a developer gets in touch with a question like this: I am confused about the exact difference between deterministic and result_cache. Do they have different application use cases? I have used deterministic feature in many functions which retrieve data from some lookup tables. Is it essential to replace these 'deterministic' key words with 'result_cache'?  So I thought I'd write a post about the differences between these two features. But first, let's make sure we all understand what it means for a function to be  deterministic. From Wikipedia : In computer science, a deterministic algorithm is an algorithm which, given a particular input, will always produce the same output, with the underlying machine always passing through the same sequence of states.  Another way of putting this is that a deterministic subprogram (procedure or function) has no side-effects. If you pass a certain set of arguments for the parameters, you will always get

My two favorite APEX 5 features: Regional Display Selector and Cards

We (the over-sized development team for the PL/SQL Challenge - myself and my son, Eli) have been busy creating a new website on top of the PLCH platform (tables and packages): The Oracle Dev Gym! In a few short months (and just a part time involvement by yours truly), we have leveraged Oracle Application Express 5 to create what I think is an elegant, easy-to-use site that our users will absolutely love.  We plan to initially make the Dev Gym available only for current users of PL/SQL Challenge, so we can get feedback from our loyal user base. We will make the necessary adjustments and then offer it for general availability later this year. Anyway, more on that as the date approaches (the date being June 27, the APEX Open Mic Night at Kscope16 , where I will present it to a packed room of APEX experts). What I want to talk about today are two features of APEX that are making me so happy these days: Regional Display Selector and Cards. Regional Display Sel