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

Home -> Community -> Mailing Lists -> Oracle-L -> Case Statement

Case Statement

From: Koivu, Lisa <lisa.koivu_at_efairfield.com>
Date: Wed, 25 Jul 2001 05:51:41 -0700
Message-ID: <F001.003544F9.20010725060527@fatcity.com>

Good morning everyone,

Has anyone used the case statement against a ton of data (like below)?  I"m wondering if it's slow.  I found that RANK() could be slow if it was running against a larger dataset.

Any insights are appreciated.
Thanks
Lisa Koivu
The Vicodin-enhanced DBA

-----Original Message-----

From:   Ron Thomas [SMTP:rthomas_at_hypercom.com]
Sent:   Tuesday, July 24, 2001 5:36 PM
To:     Multiple recipients of list ORACLE-L
Subject:        RE: Need SQL Example

If you are on 8, then you can use case.  Here is a simple example.

<snippet>
 SUM(
  CASE
    WHEN TRUNC(SYSDATE)-APS.due_date < 1 THEN
      DECODE(AI.exchange_rate,
        NULL, APS.amount_remaining,
              ROUND(AI.exchange_rate*APS.amount_remaining,2))
    ELSE
      0
  END )                                    payment_due_current,
 SUM(
  CASE
    WHEN TRUNC(SYSDATE)-APS.due_date BETWEEN  1 AND 30 THEN
      DECODE(AI.exchange_rate,
        NULL, APS.amount_remaining,
              ROUND(AI.exchange_rate*APS.amount_remaining,2))
    ELSE
      0
  END )                                   payment_due_1_30,
 SUM(
  CASE
    WHEN TRUNC(SYSDATE)-APS.due_date BETWEEN 31 AND 60 THEN
      DECODE(AI.exchange_rate,
        NULL, APS.amount_remaining,
              ROUND(AI.exchange_rate*APS.amount_remaining,2))
    ELSE
      0
  END )                                   payment_due_31_60,
 SUM(
  CASE
    WHEN TRUNC(SYSDATE)-APS.due_date > 60 THEN
      DECODE(AI.exchange_rate,
        NULL, APS.amount_remaining,
              ROUND(AI.exchange_rate*APS.amount_remaining,2))
    ELSE
      0
  END )                                    payment_due_60,
</SNIPPET>

Ron Thomas
Hypercom, Inc
rthomas_at_hypercom.com
"I'm too sexy for my code." - Awk Sed Fred

                                                                                                
                    epost_at_kcc.com                                                               
                    Sent by:             To:     ORACLE-L_at_fatcity.com                           
                    root_at_fatcity.        cc:                                                    
                    com                  Subject:     RE: Need SQL Example                      
                                                                                                
                                                                                                
                    07/24/01                                                                    
                    12:20 PM                                                                    
                    Please                                                                      
                    respond to                                                                  
                    ORACLE-L                                                                    
                                                                                                
                                                                                                

Yeah that one is great, thanks. - Ethan

-----Original Message-----
Sent: Tuesday, July 24, 2001 11:28 AM
To: Multiple recipients of list ORACLE-L

"Post, Ethan" wrote:

>
> Anyone got a good example of flipping a range of values into columner
> buckets.  I have done this in the past but my solutions always seem so
> convoluted, it seems I have seen more elegant examples in the past.  I
want
> to use decode so it will run on older versions of Oracle.
>
> Pseudo Example:
>
> select
>    sum(decode(if value between 0 and 64 then return 1 else 0))
> count_of_this_bucket,
>    sum(decode(if value between 65 and 128 then return 1 else 0))
> count_of_this_bucket,...
> from
>    table
>
> Thanks,
> Ethan


select sum(decode(sign(value - 64), 1, 0, 1)) count_of_this_bucket,
       sum(decode(sign(value - 129) * sign(value - 64), -1, 1, 0))
count_of_this_bucket,...

  Not certain that it is as elegant as you wish, but easy to decline.

--
Regards,


Stephane Faroult
Oriole Corporation
Voice:  +44  (0) 7050-696-269
Fax:    +44  (0) 7050-696-449
Performance Tools & Free Scripts
--------------------------------------------------------------
http://www.oriole.com, designed by Oracle DBAs for Oracle DBAs
--------------------------------------------------------------
--
Please see the official ORACLE-L FAQ: http://www.orafaq.com
--
Author: Stephane Faroult

  INET: sfaroult_at_oriole.com
Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051 San Diego, California        -- Public Internet access / Mailing Lists -------------------------------------------------------------------- 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). ------------------------------------------------------------------------------ This e-mail is intended for the use of the addressee(s) only and may contain privileged, confidential, or proprietary information that is exempt from disclosure under law.  If you have received this message in error, please inform us promptly by reply e-mail, then delete the e-mail and destroy any printed copy.   Thank you. ============================================================================== -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Post, Ethan
  INET: epost_at_kcc.com
Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051 San Diego, California        -- Public Internet access / Mailing Lists -------------------------------------------------------------------- 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). -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Ron Thomas
  INET: rthomas_at_hypercom.com
Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051 San Diego, California        -- Public Internet access / Mailing Lists -------------------------------------------------------------------- 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 Wed Jul 25 2001 - 07:51:41 CDT

Original text of this message

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