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

Running out of PGA memory with MULTISET ops? Watch out for DISTINCT!

A PL/SQL team inside Oracle made excellent use of nested tables and MULTISET operators in SQL, blending data in tables with procedurally-generated datasets (nested tables).  All was going well when they hit the dreaded: ORA-04030: out of process memory when trying to allocate 2032 bytes  They asked for my help.  The error occurred on this SELECT: SELECT  *    FROM header_tab trx    WHERE (generated_ntab1 SUBMULTISET OF trx.column_ntab)       AND ((trx.column_ntab MULTISET             EXCEPT DISTINCT generated_ntab2) IS EMPTY) The problem is clearly related to the use of those nested tables. Now, there was clearly sufficient PGA for the nested tables themselves. So the problem was in executing the MULTISET-related functionality. We talked for a bit about dropping the use of nested tables and instead doing everything in SQL, to avoid the PGA error. That would, however require lots of work, revamping algorithms, ensuring correctness, you know the score. Then my eyes snagge

How to Pick the Limit for BULK COLLECT

This question rolled into my In Box today: In the case of using the LIMIT clause of BULK COLLECT, how do we decide what value to use for the limit? First I give the quick answer, then I provide support for that answer Quick Answer Start with 100. That's the default (and only) setting for cursor FOR loop optimizations. It offers a sweet spot of improved performance over row-by-row and not-too-much PGA memory consumption. Test to see if that's fast enough (likely will be for many cases). If not, try higher values until you reach the performance level you need - and you are not consuming too much PGA memory.  Don't hard-code the limit value: make it a parameter to your subprogram or a constant in a package specification. Don't put anything in the collection you don't need. [from Giulio Dottorini] Remember: each session that runs this code will use that amount of memory. Background When you use BULK COLLECT, you retrieve more than row with each fetch,

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