RE: workaround for odciaggregate bug?

If I'm understanding this question correctly, and that's a big IF, I've
done a hack for this that may help.  I "adjusted" the type body code to
allow a prefix surrounded by a special delimited, in my case "~".
Anything inside that is used to help sort rows before aggregating them
into a list, then the delimiters are removed.

Any example call would be: <function name>('~' || TO_CHAR(<numeric col
for sorting>, '999') || '~' || <column/value for aggregated string>).

Here's what I added to the type:

        ...
FOR r IN (SELECT column_value FROM table (self.vals) ORDER BY 1) LOOP
   /*
    * It is assumed that any additional value used to sort the columns
is surrounded
    * by '~', so strip them off before returning the string.
    */
    result := result ||
SUBSTR(r.column_value,1,INSTR(r.column_value,'~',1,1)-1) || 
SUBSTR(r.column_value,INSTR(r.column_value,'~',1,2)+1);
END LOOP;
RETURN ODCIConst.Success;
        ...

Hope that makes sense.  

David C. Herring  | DBA, Acxiom Automotive
 
630-944-4762 office | 630-430-5988 cell | 630-944-4989 fax
1501 Opus Pl | Downers Grove, IL, 60515 | U.S.A. | www.acxiom.com
 

-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx] On Behalf Of Stauffer, Robert G
Sent: Tuesday, January 27, 2009 1:27 PM
To: Stephane Faroult
Cc: oracle-l@xxxxxxxxxxxxx
Subject: RE: workaround for odciaggregate bug?

Stephane,

Thanks.  Your query does the trick.

And, true, it doesn't make sense to expect the row ordering to work -
especially since ODCIAggregate seems to have been targeted at numeric
aggregation.

Thanks to Ian, Mark, and Charles for your help, too.



Bob Stauffer
DBA
D&E Communications
Ephrata, PA
rstauffer@xxxxxxxxxxxxxxxxxxxx
717-738-8737 
-----Original Message-----
From: Stephane Faroult [mailto:sfaroult@xxxxxxxxxxxx] 
Sent: Friday, January 23, 2009 17:26
To: Stauffer, Robert G
Cc: oracle-l@xxxxxxxxxxxxx
Subject: Re: workaround for odciaggregate bug?

Robert,

    I'm not sure it really qualifies as a bug, because row ordering is
something that has no meaning in the relational theory, and therefore
Oracle is free to return rows in whichever order it wants - only the
final "order by" counts.
But there is another solution than stringAgg, and this one works "by
design":

SQL> select acctnbr,
  2          replace(path, '|', '') result
  3  from (select acctnbr,
  4            sys_connect_by_path(prodcount, '|') path,
  5            rn,
  6            cnt
  7         from (select acctnbr,
  8              prodcount,
  9              row_number() over (partition by acctnbr
 10                         order by snapshotdate) rn,
 11              count(snapshotdate) over (partition by acctnbr) cnt
 12           from testtable)
 13         connect by acctnbr = prior acctnbr
 14            and rn = 1 + prior rn
 15         start with rn = 1)
 16  where rn = cnt
 17  order by acctnbr
 18  /

ACCTNBR    RESULT
---------- --------------------
0123456789 010203

HTH

S. Faroult

Stauffer, Robert G wrote:
> All,
>
> 9.2.0.7 and 10.1.0.4 on AIX 5.2
>
> I'm trying to use ODCIAggregate and Tom Kyte's stringAgg function to
> concatenate a number in multiple rows into a string.  Below is the
> output of the select statements I ran.  Create scripts for the table,
> type, and function are below the output.  I'm expecting the returned
> string to be '010203' but it returns '010032'.  Unfortunately, it
looks
> like there's a bug (7194959 to be fixed in 11.2) in ODCIAggregate that
> "unsorts" the sorted data when it creates the concatenated string.
I've
> looked around (asktom, metalink, etc.) and can't seem to find a
> work-around for this method.  Has anyone come up with one?
>   



**DISCLAIMER
This e-mail message and any files transmitted with it are intended for
the use of the individual or entity to which they are addressed and may
contain information that is privileged, proprietary and confidential. If
you are not the intended recipient, you may not use, copy or disclose to
anyone the message or any information contained in the message. If you
have received this communication in error, please notify the sender and
delete this e-mail message. The contents do not represent the opinion of
D&E except to the extent that it relates to their official business.
--
http://www.freelists.org/webpage/oracle-l


***************************************************************************
The information contained in this communication is confidential, is
intended only for the use of the recipient named above, and may be legally
privileged.

If the reader of this message is not the intended recipient, you are
hereby notified that any dissemination, distribution or copying of this
communication is strictly prohibited.

If you have received this communication in error, please resend this
communication to the sender and delete the original message or any copy
of it from your computer system.

Thank You.
****************************************************************************

--
http://www.freelists.org/webpage/oracle-l


Other related posts: