DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports Events Over 2 million developers have joined DZone. Join Today! Thanks for visiting DZone today,
Edit Profile Manage Email Subscriptions Moderation Admin Console How to Post to DZone Article Submission Guidelines
View Profile
Sign Out
Refcards
Trend Reports
Events
Zones
Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
  1. DZone
  2. Data Engineering
  3. Databases
  4. Why Won't MULTISET Work for Me?

Why Won't MULTISET Work for Me?

Struggling to get MULTISET in PL/SQL to work for you? Check out this article, which explains how to make it work.

Steven Feuerstein user avatar by
Steven Feuerstein
·
Oct. 25, 18 · Tutorial
Like (1)
Save
Tweet
Share
5.52K Views

Join the DZone community and get the full member experience.

Join For Free

I recently got an email from an Oracle Database developer who was trying to get the MULTISET operator to work in his code.

He'd created nested tables of records and found that MULTISET UNION would work but MULTISET EXCEPT would not.

When he ran his code he got this error:

PLS-00306: wrong number or types of arguments in call to 'MULTISET_EXCEPT_ALL"

I will confess that it took me longer than I'd like to admit (but I just did!) to get to the heart of his problem, so I figure others might get similarly befuddled. Time for a blog post!

Let's explore some of the nuances behind musing MULTISET, centered around this important statement from the documentation:

Two objects of nonscalar type are comparable if they are of the same named type and there is a one-to-one correspondence between their elements. In addition, nested tables of user-defined object types, even if their elements are comparable, must have MAP methods defined on them to be used in equality or IN conditions.

Note: the code shown below may be executed on LiveSQL here.

First, I create some database objects.

CREATE TABLE limbs
(
   nm        VARCHAR2 (100),
   avg_len   NUMBER
)
/

BEGIN
   INSERT INTO limbs VALUES (1, 'arm');
   INSERT INTO limbs VALUES (2, 'leg');
   INSERT INTO limbs VALUES (3, 'tail');
   COMMIT;
END;
/

CREATE OR REPLACE TYPE limb_ot IS OBJECT
(
   nm VARCHAR2 (100),
   avg_len NUMBER
)
/

Now let's see if I can get the MULTISET operators to work. First, MULTISET UNION:

DECLARE
   TYPE limbs_t IS TABLE OF limb_ot;
   l_limbs   limbs_t;
BEGIN
     SELECT limb_ot (l.nm, l.avg_len)
       BULK COLLECT INTO l_limbs
       FROM limbs l
   ORDER BY l.nm;

   l_limbs := l_limbs MULTISET UNION l_limbs;
   DBMS_OUTPUT.put_line ('Lots of limbs! ' || l_limbs.COUNT);
END;
/

Lots of limbs! 6

So far so good. Now MULTISET EXCEPT:

DECLARE
   TYPE limbs_t IS TABLE OF limb_ot;
   l_limbs   limbs_t;
BEGIN
     SELECT limb_ot (l.nm, l.avg_len)
       BULK COLLECT INTO l_limbs
       FROM limbs l
   ORDER BY l.nm;

   l_limbs := l_limbs MULTISET EXCEPT l_limbs;
   DBMS_OUTPUT.put_line ('Lots of limbs! ' || l_limbs.COUNT);
END;
/

PLS-00306: wrong number or types of arguments in call to 'MULTISET_EXCEPT_ALL"

OK, you might now be saying: "Hey, that's a bug! MULTISET EXCEPT is broken." But wait, let's do some more testing. How about a nested table of numbers? Does MULTISET EXCEPT work with that? 

DECLARE
   TYPE limbs_t IS TABLE OF NUMBER;
   l_limbs   limbs_t;
BEGIN
     SELECT l.avg_len
       BULK COLLECT INTO l_limbs
       FROM limbs l
   ORDER BY l.nm;

   l_limbs := l_limbs MULTISET EXCEPT l_limbs;
   DBMS_OUTPUT.put_line ('Lots of limbs! ' || l_limbs.COUNT);
END;
/

Lots of limbs! 0

No problem there: I "minused" a collection from itself and nothing was left. So MULTISET EXCEPT works, but only under some circumstances. But why then did MULTISET UNION work?

The key thing to remember is this: MULTISET UNION is equivalent to MULTISET UNION ALL. In other words, the MULTISET operators do not by default remove duplicates (which is the case for SQL UNION. You have to specify DISTINCT if you want that to happen. And when I add DISTINCT in the block below, guess what?

DECLARE
   TYPE limbs_t IS TABLE OF limb_ot;
   l_limbs   limbs_t;
BEGIN
     SELECT limb_ot (l.nm, l.avg_len)
       BULK COLLECT INTO l_limbs
       FROM limbs l
   ORDER BY l.nm;

   l_limbs := l_limbs MULTISET UNION DISTINCT l_limbs;
   DBMS_OUTPUT.put_line ('Lots of limbs! ' || l_limbs.COUNT);
END;
/

PLS-00306: wrong number or types of arguments in call to 'MULTISET_UNION_DISTINCT"

Now it fails, just like EXCEPT. What's different? Now the PL/SQL engine must compare the contents of the two collections and to do that, it needs a map method, which returns values that can be used for comparing and sorting. Let's add one to limb_ot: I will specify a mapping based on the length of the name.

There is no way to create a map method on a record type and t 

CREATE OR REPLACE TYPE limb_ot AUTHID DEFINER 
   IS OBJECT
(
   nm VARCHAR2 (100),
   avg_len NUMBER,
   MAP MEMBER FUNCTION limb_map RETURN NUMBER
)
/

CREATE OR REPLACE TYPE BODY limb_ot
IS
   MAP MEMBER FUNCTION limb_map RETURN NUMBER
   IS
   BEGIN
      RETURN LENGTH (self.nm);
   END;
END;
/

And when I add DISTINCT in the block below, guess what? It works!

DECLARE
   TYPE limbs_t IS TABLE OF limb_ot;
   l_limbs   limbs_t;
BEGIN
     SELECT limb_ot (l.nm, l.avg_len)
       BULK COLLECT INTO l_limbs
       FROM limbs l
   ORDER BY l.nm;

   l_limbs := l_limbs MULTISET UNION DISTINCT l_limbs;
   DBMS_OUTPUT.put_line ('Lots of limbs! ' || l_limbs.COUNT);
END;
/

Lots of limbs! 2

Well, I didn't get an error. But did it work? Aren't there three distinct rows in the table? Why does it show a COUNT of 2? Because the map method only uses the length of the name for comparison. Both "arm" and "leg" have three characters, so those two rows are not considered distinct for the purposes of the comparison. Tricky, eh?

What? You don't believe me? OK, fine, let's change the map function so that all three rows return distinct values and then:

CREATE OR REPLACE TYPE BODY limb_ot
IS
   MAP MEMBER FUNCTION limb_map
      RETURN NUMBER
   IS
   BEGIN
      RETURN LENGTH (self.nm) + self.avg_len;
   END;
END;
/

DECLARE
   TYPE limbs_t IS TABLE OF limb_ot;

   l_limbs   limbs_t;
BEGIN
     SELECT limb_ot (l.nm, l.avg_len)
       BULK COLLECT INTO l_limbs
       FROM limbs l
   ORDER BY l.nm;

   l_limbs := l_limbs MULTISET UNION DISTINCT l_limbs;
   DBMS_OUTPUT.put_line ('Lots of limbs! ' || l_limbs.COUNT);
END;
/

Lots of limbs! 3

So if you are going to ask Oracle Database to compare object type instances in a nested table, you'd better provide a map method! 

And what if you want to compare records in a nested table with a MULTISET operator? You are out of luck. You cannot do this. There is no mechanism built into PL/SQL to compare two records, and there is no way to create a map method on a record type.

Database

Published at DZone with permission of Steven Feuerstein, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Popular on DZone

  • Easy Smart Contract Debugging With Truffle’s Console.log
  • Why It Is Important To Have an Ownership as a DevOps Engineer
  • Spring Cloud: How To Deal With Microservice Configuration (Part 1)
  • How To Create and Edit Excel XLSX Documents in Java

Comments

Partner Resources

X

ABOUT US

  • About DZone
  • Send feedback
  • Careers
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 600 Park Offices Drive
  • Suite 300
  • Durham, NC 27709
  • support@dzone.com
  • +1 (919) 678-0300

Let's be friends: