Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: SQL Query

Re: SQL Query

From: sundeep maini <sundeep_maini_at_yahoo.com>
Date: Thu, 25 Sep 2003 14:14:51 -0800
Message-ID: <F001.005D1153.20030925141451@fatcity.com>


Mike,

Just wanted to supplement your example with another one from my environment (uses nested tables with CAST and MULTISET to achieve the same):

SELECT c.customer_id

      ,customer_name
      ,utils.code_table_to_string(CAST( MULTISET(
        SELECT distinct dlr_dealer_code
          FROM dealer_customers dc
		       ,dlr_dealer_master_t
         WHERE dc.customer_id = dc_in.customer_id
		   AND dlr_dealer_id = dc.dealer_id
		 ORDER BY dlr_dealer_code
		) AS code_table_t
	  )) spans_these_dealers
 FROM customers c
     ,(
       SELECT customer_id
	     FROM dealer_customers 
		GROUP BY customer_id
		HAVING COUNT(distinct dealer_id) > 1
	  ) dc_in

WHERE dc_in.customer_id = c.customer_id;

Does eseentially the same thing. In this case it concatenates the dealer_codes per customer (identifies customers spanning multiple dealers) on the same row. Here is a sample of the output:

2969473096	Mountain Enterprises Inc	D100,D470,D480
2969473121	K C Construction	        B010,B150,B190
2969473195	GOODFELLOW BROS	                H140,H330

The TYPE code_table_t is defined as:
TYPE CODE_TABLE_T IS table of varchar2(3000);

And the conversion function is very similar in its functionality to dbms_utility.comma_to_table procedure:

FUNCTION code_table_to_string (in_table code_table_t, in_rec_sep varchar2 DEFAULT config.c_rec_sep)

   RETURN delimited_list_t
 IS
   v_list delimited_list_t;
 BEGIN
   FOR i IN 1..in_table.COUNT
   LOOP

     IF i = 1
	 THEN
	   v_list := in_table(1);
	 ELSE
       v_list := v_list||in_rec_sep||in_table(i);
	 END IF;

   END LOOP;
   RETURN v_list;
 END code_table_to_string;

As opposed your suggestion of using the following:

SELECT id, CONCAT_LIST(CURSOR(
> SELECT text
> FROM mike m_in

       ORDER BY ordr

> WHERE m_in.id = m.id)) list

> FROM ( select distinct id from mike) m; --- Mike Spalinger <Michael.Spalinger_at_Sun.COM> wrote:
> Imran,
> 
> Tom Kyte has a thread that might help:
>

http://asktom.oracle.com/pls/ask/f?p=4950:8:1554835115460038644::NO::F4950_P8_DISPLAYID,F4950_P8_CRITERIA:229614022562,
> 
> Essentially, you can do this:
> 
> CREATE or replace FUNCTION CONCAT_LIST( cur SYS_REFCURSOR )
>    RETURN  VARCHAR2 IS

> ret VARCHAR2(32000);
> tmp VARCHAR2(4000);
> BEGIN
> loop
> fetch cur into tmp;
> exit when cur%NOTFOUND;
> ret := ret || ' ' || tmp;
> end loop;
> RETURN ret;
> END; > / > > SQL> select * from mike; >
> ID TEXT ORDR
> ---------- ---------- ----------
> 1 B 2
> 1 A 1
> 1 C 3
> > SELECT id, SUBSTR(CONCAT_LIST(CURSOR(
> SELECT text
> FROM (select id, text, ordr from mike order by ordr) ee
> WHERE e.id = ee.id)),1,40) list
> FROM ( select distinct id from mike) e; >
> ID LIST
> ---------- --------------------
> 1 A B C
> > Mike > > > Imran Ashraf wrote: > > Hi, > > > > I have the following data , table Temp > > > > ID Text Order > > 1 B 2 > > 1 A 1 > > 1 C 3 > > > > > > I want to write a query which says: wherever there is more than 1 > occurrence > > of ID then concatenate the text in the order specified in the > order column. > > So i would get: > > > > ID Text > > 1 A B C > > > > Any suggestions? > > > > Thanks > > > > Imran > > > -- > Please see the official ORACLE-L FAQ: http://www.orafaq.net > -- > Author: Mike Spalinger > INET: Michael.Spalinger_at_Sun.COM > > Fat City Network Services -- 858-538-5051 http://www.fatcity.com > San Diego, California -- Mailing list and web hosting > services > --------------------------------------------------------------------- > To REMOVE yourself from this mailing list, send an E-Mail message > to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in > the message BODY, include a line containing: UNSUB ORACLE-L > (or the name of mailing list you want to be removed from). You may > also send the HELP command for other information (like subscribing). ===== Sundeep Maini Consultant Currently on Assignement at Caterpillar Peoria sundeep_maini_k_at_cat.com __________________________________

Do you Yahoo!?
The New Yahoo! Shopping - with improved product search http://shopping.yahoo.com
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: sundeep maini
  INET: sundeep_maini_at_yahoo.com

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Thu Sep 25 2003 - 17:14:51 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US