Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations SkipVought on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

Select Sub Query 1

Status
Not open for further replies.

ibib3

IS-IT--Management
Feb 14, 2002
14
0
0
GB
Hi
can any one help me please,

I have two tables, OP that holds surgical operation details and MED that holds the medical staff associated with an operation.

The MED.s_role indicates the role of the medical staff eg. S1 - Principle Surgeon and S2-Assistant Surgeon.

When I first ran the query below it worked for one consultant but when I tried a second consultant -'LLOSN' it is bringing back the error message ORA-01427: single-row subquery returns more than one row.

After checking I found out that it is possible to have more than one surgeon sharing a particular role hence the error message.


Query:

SELECT
OP.theatre AS theatrecode,
OP.s_date AS opdate,
OP.session_id AS sessionid,
OP.opno,
(select MED.staff_id
from MED
where OP.opno = MED.opno and MED.s_role = 'S1') Surgeon1,
(select MED.staff_id
from MED
where OP.opno = MED.opno and MED.s_role = 'S2') surgeon2
FROM
OP
WHERE
OP.consultant = 'LLOSN'


Result:

THEAT OPDATE SESSI OPNO SURGEON1 SURGEON2
----- --------- ----- ---------- --------- ---------
SD01 18-NOV-04 SDU01 35073 FORJ THOJ1
SJD01 23-NOV-04 BU002 35434 KIMM CROB
SJD01 23-NOV-04 BU002 35452 KIMM
SJD02 23-NOV-04 BU004 35475 CROB LLOSN
SJG03 23-NOV-04 GGU02 35538 LLOSN
SJG03 23-NOV-04 GGU02 35541 LLOSN
SJG03 23-NOV-04 GGU02 35546 THOJ1
SJG03 23-NOV-04 GGU02 35548 LLOSN
SJG03 23-NOV-04 GGU02 35552 LLOSN
SJD01 24-NOV-04 BU003 35730 LLOSN CROB
SJD01 24-NOV-04 BU003 35733 LLOSN
ERROR:
ORA-01427: single-row subquery returns more than one row

Is there a way of showing both surgeons who are sharing the role and stop the error message from occuring?

 


You need to "OUTER JOIN" OP table to the MED table instead of the inline select.
[3eyes]

----------------------------------------------------------------------------
The person who says it can't be done should not interrupt the person doing it. -- Chinese proverb
 
...Or, you can build a user-defined function (in PL/SQL) such as this:
Code:
create or replace function get_med (op_no_in number, role_in varchar2) return varchar2 is
    hold_meds varchar2(100);
begin
    for x in (select staff_id from med where opno = op_no_in and s_role = role_in) loop
        hold_meds := hold_meds||', '||x.staff_id;
    end loop;
    return ltrim(hold_meds,', ');
end;
/

Function created.
...then use the function in this adjustment to your original code:
Code:
col surgeons1 format a15
col surgeons2 format a15
SELECT
    OP.theatre AS theatrecode,
    OP.s_date AS opdate,
    OP.session_id AS sessionid,
    OP.opno,
    get_med (op.opno,'S1') Surgeons1,
    get_med (op.opno,'S2') Surgeons2
FROM OP
WHERE OP.consultant = 'LLOSN';

THEATRECOD OPDATE    SESSIONID        OPNO SURGEONS1       SURGEONS2
---------- --------- ---------- ---------- --------------- ---------------
SD01       18-NOV-04 SDU01           35073 FORJ            THOJ1
SJD01      23-NOV-04 BU002           35434 KIMM            CROB
SJD01      23-NOV-04 BU002           35452 KIMM
SJD01      24-NOV-04 BU003           35734 CROB, THOJ1     KIMM, FORJ
Let us know if you have questions.

[santa]Mufasa
(aka Dave of Sandy, Utah, USA)
[I provide low-cost, remote Database Administration services: www.dasages.com]
“Beware of those that seek to protect you from harm or risk. The cost will be your freedoms and your liberty.”
 
Thanks for replying LKBrwnDBA but doesn't that just give a row per surgeon with duplicate op details? I want to be able to have all the surgeons on a single row with the op data, using one query if possible.

regards
 
Thanks SantaMufasa this looks to be just what I need.

regards
 

Or, following Mufasa's lead, you could also do it without creating a function:
Code:
COL surgeon1 for a30 wra
COL surgeon2 for a30 wra
SELECT op.theatre AS theatrecode, op.s_date AS opdate,
       op.session_id AS sessionid, op.opno, m1.s1s AS surgeon1,
       m2.s2s AS surgeon2
  FROM op,
       (SELECT     opno,
                   SUBSTR (MAX (SYS_CONNECT_BY_PATH (staff_id, ',')), 2) s1s
              FROM (SELECT opno, staff_id,
                           ROW_NUMBER () OVER (PARTITION BY opno ORDER BY staff_id) rn
                      FROM med
                     WHERE s_role = 'S1')
        START WITH rn = 1
        CONNECT BY PRIOR rn = rn - 1 AND PRIOR opno = opno
          GROUP BY opno) m1,
       (SELECT     opno,
                   SUBSTR (MAX (SYS_CONNECT_BY_PATH (staff_id, ',')), 2) s2s
              FROM (SELECT opno, staff_id,
                           ROW_NUMBER () OVER (PARTITION BY opno ORDER BY staff_id) rn
                      FROM med
                     WHERE s_role = 'S2')
        START WITH rn = 1
        CONNECT BY PRIOR rn = rn - 1 AND PRIOR opno = opno
          GROUP BY opno) m2
 WHERE op.consultant = 'LLOSN' AND op.opno = m1.opno AND op.opno = m2.opno;
[noevil]


----------------------------------------------------------------------------
The person who says it can't be done should not interrupt the person doing it. -- Chinese proverb
 

Ooops, you may need to "outer join" (+) the M2 query.
[thumbsup2]



----------------------------------------------------------------------------
The person who says it can't be done should not interrupt the person doing it. -- Chinese proverb
 
LK,

I have not Oracle 8i upon which to run your code, but can Oracle Analytical Functions run on Oracle 8i?

[santa]Mufasa
(aka Dave of Sandy, Utah, USA)
[I provide low-cost, remote Database Administration services: www.dasages.com]
“Beware of those that seek to protect you from harm or risk. The cost will be your freedoms and your liberty.”
 


Ooops, don't think so...
Forgot it's 8i forum [morning]
.


----------------------------------------------------------------------------
The person who says it can't be done should not interrupt the person doing it. -- Chinese proverb
 

ibib3: GET RID OF 8i AS SOON AS POSSIBLE!
[thumbsdown]

----------------------------------------------------------------------------
The person who says it can't be done should not interrupt the person doing it. -- Chinese proverb
 

Thanks for all of your help much appreciated.

8i does have some analytical functions, i've used lag before.
 

I haven't worked with 8i since 2004 and tend to forget it still exists!
.

----------------------------------------------------------------------------
The person who says it can't be done should not interrupt the person doing it. -- Chinese proverb
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top