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: Outer join sql help?

RE: Outer join sql help?

From: Norrell, Brian <BNorrell_at_QuadraMed.com>
Date: Wed, 12 Dec 2001 10:38:42 -0800
Message-ID: <F001.003DB0AA.20011212101533@fatcity.com>

SELECT a.LEAVE_CATEG_ID,

         a.LEAVE_TYPE_CD,
         a.LPET_LONG_DD, 
         Sum(l.ORIGINAL_INPUT_AM)

  FROM EFF_LEVPOL_EVNT_TYPE_TBL a, LEAVE_DETL_TBL l
 WHERE a.LEAVE_TYPE_CD(+) = l.evnt_type_cd
   AND l.INTERNAL_EMPL_ID='0000000357'
   AND l.EFFECTIVE_DT Between TO_DATE('01/01/2001','MM/DD/YYYY') 
                          And TO_DATE('12/31/2001','MM/DD/YYYY')
 GROUP BY a.LEAVE_CATEG_ID, a.LEAVE_TYPE_CD, a.LPET_LONG_DD;

This should work if you are looking for LEAVE_DETL_TBL records without records in EFF_LEVPOL_EVNT_TYPE, which does not sound right.

I'm thinking you want the "a" records even when there is no supporting "l" records:
SELECT a.LEAVE_CATEG_ID,

         a.LEAVE_TYPE_CD,
         a.LPET_LONG_DD, 
         Sum(l.ORIGINAL_INPUT_AM)

  FROM EFF_LEVPOL_EVNT_TYPE_TBL a, LEAVE_DETL_TBL l
 WHERE l.LEAVE_TYPE_CD(+) = a.evnt_type_cd
   AND l.INTERNAL_EMPL_ID(+) = '0000000357'
   AND l.EFFECTIVE_DT Between TO_DATE('01/01/2001','MM/DD/YYYY') 
                          And TO_DATE('12/31/2001','MM/DD/YYYY')
 GROUP BY a.LEAVE_CATEG_ID, a.LEAVE_TYPE_CD, a.LPET_LONG_DD;

But then the date range gives you a problem, so: SELECT a.LEAVE_CATEG_ID,

         a.LEAVE_TYPE_CD,
         a.LPET_LONG_DD, 
         Sum(decode(sign(l.EFFECTIVE_DT -
TO_DATE('01/01/2001','MM/DD/YYYY'),
                  1,0,NULL,0,
                  decode(l.EFFECTIVE_DT -
TO_DATE('12/31/2001','MM/DD/YYYY'),
                        1, 0 , l.ORIGINAL_INPUT_AM
          )      )      )

  FROM EFF_LEVPOL_EVNT_TYPE_TBL a, LEAVE_DETL_TBL l  WHERE l.LEAVE_TYPE_CD(+) = a.evnt_type_cd    AND l.INTERNAL_EMPL_ID(+) = '0000000357'  GROUP BY a.LEAVE_CATEG_ID, a.LEAVE_TYPE_CD, a.LPET_LONG_DD;

Nasty - or is my initial guess off base?

Brian Norrell
Manager, MPI Development
QuadraMed
511 E John Carpenter Frwy, Su 500
Irving, TX 75062
(972) 831-6600

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Norrell, Brian
  INET: BNorrell_at_QuadraMed.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 Dec 12 2001 - 12:38:42 CST

Original text of this message

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