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: HELP !!! scrpt works with sql plus but not in a procedure

RE: HELP !!! scrpt works with sql plus but not in a procedure

From: Jacques Kilchoer <Jacques.Kilchoer_at_quest.com>
Date: Wed, 13 Jun 2001 17:12:40 -0700
Message-ID: <F001.00328ABF.20010613162552@fatcity.com>

see answer below

> -----Original Message-----
> From: Mark Liggayu [mailto:markliggayu_at_allweatherwindows.com]
>
> I have this script that works fine in sql plus but when I
> attach it to a
> procedure in my report it gives me an error
>
>       "error 101 Encountered a symbol SELECT when expecting
> one of the following"
> The error surfaces when the bolded line (choosing the date)
> is included in
> the script.
> What is the possible fix for this?
>
>       INSERT INTO AWW_ISSUED
>       SELECT ALL INV.MTL_MATERIAL_TRANSACTIONS.INVENTORY_ITEM_ID,
>       SUM(INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_QUANTITY)RECEIVED
>       FROM INV.MTL_MATERIAL_TRANSACTIONS
>       WHERE (INV.MTL_MATERIAL_TRANSACTIONS.ORGANIZATION_ID=3
>       AND INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_TYPE_ID
> IN (1, 31, 32, 33,
> 34, 36, 40, 41, 42, 18, 2, 50, 51, 12, 61, 21, 4, 80)
>       AND INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_QUANTITY > 0)
>       AND  INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_DATE
> BETWEEN '01-JUN-01' AND
> '30-JUN-01'
>       AND  INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_DATE
> BETWEEN (SELECT
> TO_DATE('01' || SUBSTR(TO_CHAR(SYSDATE),3,9)) FROM DUAL)     
>       AND (SELECT
> LAST_DAY(SYSDATE) FROM DUAL)
>       GROUP BY INV.MTL_MATERIAL_TRANSACTIONS.INVENTORY_ITEM_ID;
A couple of points to mention -
a) sysdate is a function that can be used directly in an expression, so you don't need the "select ... from dual" b) I would always convert dates explicitly, because otherwise you are depending on the date format set for your database instance and session, and that format is subject to change.

c) If you want all values for a particular month, e.g. all values for the month of June 2001, your comparison should be written as

where ... date_field >= to_date ('20010601', 'YYYYMMDD') and date_field < ('20010701', 'YYYYMMDD') ... all values for the current month could be found with the following comparison: where ... date_field >= trunc (sysdate, 'MM') and date_field < trunc (last_day (sysdate)) + 1

trunc (sysdate, 'MM') will return the first day of the current month. It is well worth the time spent reading the manual on SQL date functions.

Remember that Oracle date fields can contain time values as well.

That being said, I would rewrite the query as follows, and I think this may eliminate the error. (P.S. I don't know which line you had "in bold" since your message arrived in text format.)

INSERT INTO AWW_ISSUED
 SELECT ALL INV.MTL_MATERIAL_TRANSACTIONS.INVENTORY_ITEM_ID,  SUM(INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_QUANTITY)  RECEIVED FROM INV.MTL_MATERIAL_TRANSACTIONS
WHERE (INV.MTL_MATERIAL_TRANSACTIONS.ORGANIZATION_ID=3

 AND INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_TYPE_ID 
     IN (1, 31, 32, 33,
         34, 36, 40, 41, 42, 18, 2, 50, 51, 12, 61, 21, 4, 80)
 AND INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_QUANTITY > 0)
  AND  INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_DATE 
     BETWEEN to_date ('20010601', 'YYYYMMDD')
            and to_date ('200010630', 'YYYYMMDD')
 AND  INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_DATE 
      BETWEEN trunc (sysdate, 'MM') and last_day (sysdate)
        GROUP BY INV.MTL_MATERIAL_TRANSACTIONS.INVENTORY_ITEM_ID ;




Jacques R. Kilchoer
(949) 754-8816
Quest Software, Inc.
8001 Irvine Center Drive
Irvine, California 92618
U.S.A.
http://www.quest.com Received on Wed Jun 13 2001 - 19:12:40 CDT

Original text of this message

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