Ops. Sent the email before I pasted in the final example. Here it is... 1 SELECT s.study_id, s.status, sp.status 2 FROM study s, site_placement sp 3 WHERE s.study_id = 5014 4 AND s.study_id = sp.study_id(+) 5 AND s.status = 'A' 6* AND sp.status = 'A' SQL> /
no rows selected No rows are returned. This is the original problem. Adding the outer join to sp.status solves it. Thanks Ron. Thanks to everyone for all the feedback!! Much appreciated!!!! -----Original Message----- Sent: Tuesday, October 02, 2001 4:13 PM To: '[EMAIL PROTECTED]' Hmm... I need to better explain this. The query should.... ...always return S records, if the s.status = 'A'. ...should return SP records if the sp.status = 'A'. A for active records. ...should NOT return SP records if the sp.status = 'D'. D for logically deleted records. ----------------------------------------- The developers took your approach, they deleted that line, and then had Crystal Reports filter out the SP "D" records. They tested it and it works, so there leaving it alone. ----------------------------------------- What Ron suggested is working. I sent it to the developers and there testing it out. 1 SELECT s.study_id, s.status, sp.status 2 FROM study s, site_placement sp 3 WHERE s.study_id = 5014 4 AND s.study_id = sp.study_id(+) 5 AND s.status = 'A' 6* AND sp.status(+) = 'A' SQL> / STUDY_ID S S ---------- - - 5014 A The S record came out, but the SP record did not because it's status = 'D'. SQL> SELECT s.study_id, s.status, sp.status 2 FROM study s, site_placement sp 3 WHERE s.study_id = 5008 4 AND s.study_id = sp.study_id(+) 5 AND s.status = 'A' 6 AND sp.status(+) = 'A' 7 / STUDY_ID S S ---------- - - 5008 A A 5008 A A 5008 A A For study 5008, there are active SP records, so the query is returning them. Finally, to complete this example... We are learning the hard way that logically deleted records are causing havoc for our developers...and the DBA, who has a huge headache... -----Original Message----- Sent: Tuesday, October 02, 2001 4:01 PM To: Multiple recipients of list ORACLE-L "I'm trying to get this SQL to return rows from the S table even if there are records in the SP table with status of 'D'(logically deleted)." Then why are you specifically querying the sp.status for values of 'A'? SELECT s.study_id, s.status, sp.status FROM s, sp WHERE s.study_id = 5014 AND s.study_id = sp.study_id(+) AND s.status = 'A' AND sp.status = 'A' <== Drop this and clause?? Tom Mercadante Oracle Certified Professional -----Original Message----- Sent: Tuesday, October 02, 2001 3:00 PM To: Multiple recipients of list ORACLE-L SELECT s.study_id, s.status, sp.status FROM s, sp WHERE s.study_id = 5014 AND s.study_id = sp.study_id(+) AND s.status = 'A' AND sp.status = 'A' I'm stuck trying to figure out how to make this SQL work, and am starting to wonder if it's even possible. I'm trying to get this SQL to return rows from the S table even if there are records in the SP table with status of 'D'(logically deleted). What am I missing??!?!?!? TIA!!!! Chris -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Grabowy, Chris INET: [EMAIL PROTECTED] 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: [EMAIL PROTECTED] (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: Mercadante, Thomas F INET: [EMAIL PROTECTED] 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: [EMAIL PROTECTED] (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: Grabowy, Chris INET: [EMAIL PROTECTED] 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: [EMAIL PROTECTED] (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).