0
votes

I am trying to create a interactive report with below query.

This runs perfectly in SQLPLUS but when I write this query in APEX and run the report, it throws error :

ORA-01427: single-row subquery returns more than one row

        SELECT --count(*) --31335
           hou.name ORGANISATION_NAME,            asp.vendor_name SUPPLIER_NAME,              asa.vendor_id SUPPLIER_NUMBER,
          asa.country SUPPLIER_SITE_COUNTRY_CODE,              ft1.territory_short_name  SUPPLIER_SITE_COUNTRY_DESC,                 
          case when  nvl(asa.inactive_date,sysdate) >= sysdate then             'Active'               else             'Inactive'             End SUPPLIER_SITE_STATUS,
          cbbv.bank_name BANK_NAME,
          ieb.IBAN IBAN,
         (select nvl(ppf.full_name, fu.user_name) 
          from fnd_user fu,  per_all_people_f ppf
          where fu.user_id = ieb.created_by
          and ppf.person_id (+) = fu.employee_id ) CREATED_BY,
          ieb.creation_date  CREATION_DATE,
          (select nvl(ppf.full_name, fu.user_name) 
          from fnd_user fu,  per_all_people_f ppf
          where fu.user_id = ieb.last_updated_by
          and ppf.person_id (+) = fu.employee_id ) UPDATED_BY,
          payees.bank_charge_bearer BANK_CHARGE_BEARER

         FROM apps.iby_pmt_instr_uses_all instrument,
          apps.iby_account_owners owners,
          apps.iby_external_payees_all payees,
          apps.iby_ext_bank_accounts ieb,
          apps.ap_supplier_sites_all asa,
          apps.ap_suppliers asp,
          apps.ce_bank_branches_v cbbv, 
          hr_operating_units hou  ,  fnd_lookup_values flv,  
          fnd_territories_tl ft1,
          fnd_territories_tl ft2

        WHERE  owners.ext_bank_account_id = ieb.ext_bank_account_id
        AND owners.ext_bank_account_id = instrument.instrument_id(+)
        AND payees.ext_payee_id        = instrument.ext_pmt_party_id(+)
        AND payees.payee_party_id      = owners.account_owner_party_id
        AND payees.supplier_site_id    = asa.vendor_site_id
        AND asa.vendor_id              = asp.vendor_id
        AND cbbv.branch_party_id(+)    = ieb.branch_id  
        and payees.org_id = 101
        and hou.organization_id = PAYEES.ORG_ID
        and FLV.LOOKUP_CODE = asp.vendor_type_lookup_code
        and flv.lookup_type  = 'VENDOR TYPE'
        and ft1.territory_code(+) = asa.country
        and ft2.territory_code(+) = ieb.country_code
        and PAYEES.BANK_CHARGE_BEARER = 'SHA';

This error doesn't occur if I just uncomment the last where condition i.e " --and PAYEES.BANK_CHARGE_BEARER = 'SHA'; "

This last condition is not even a subquery so I am not able to understand why this is error is coming in APEX. In SQLPLUS everything works fine. Also If I run the query in SQL Workshop of APEX application builder, there also it works fine. Only during the time when we RUN the application it gives this error.

Also, If I remove this condition from the query the application runs fine, but when I filter on this value "SHA" it gives me same error. It works fine if I select any other value like "OUR".

Can you please suggest what I should do to avoid this error.

1
What happens if you leave the last condition ('SHA'), but remove one and/or both UPDATED_BY and CREATED_BY queries? Because, those two seem to be the only obvious candidates to throw TOO_MANY_ROWS.Littlefoot

1 Answers

0
votes

You have two subqueries in your projection:

(select nvl(ppf.full_name, fu.user_name) 
 from fnd_user fu,  per_all_people_f ppf
 where fu.user_id = ieb.created_by
 and ppf.person_id (+) = fu.employee_id ) CREATED_BY,

and

(select nvl(ppf.full_name, fu.user_name) 
 from fnd_user fu,  per_all_people_f ppf
 where fu.user_id = ieb.last_updated_by
 and ppf.person_id (+) = fu.employee_id ) UPDATED_BY,

One or both of those queries is returning more than one record for a particular user/person combination. Your tables appear to be Oracle E-Business Suite tables. If so , per_all_people_f is a date tracked table and may have more than one record for a given person_id. You should add an additional predicate to your join conditions to limit ppf to a single record per fu. If you have created dates and updated dates in ieb then I'd use those otherwise use sysdate:

(select nvl(ppf.full_name, fu.user_name) 
 from fnd_user fu
 left join per_all_people_f ppf
   on ppf.person_id = fu.employee_id
  and trunc(sysdate) between ppf.effective_start_date and ppf.effective_end_date
 where fu.user_id = ieb.created_by) CREATED_BY,

or

(select nvl(ppf.full_name, fu.user_name) 
 from fnd_user fu
 left join per_all_people_f ppf
   on ppf.person_id = fu.employee_id
  and trunc(ieb.creation_date) between ppf.effective_start_date and ppf.effective_end_date
 where fu.user_id = ieb.created_by) CREATED_BY,

the changes to updated by would be similar, though left as an exercise for the reader ;)