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

2001-06-13 Thread Mark Liggayu

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;

I appreciate all the help


-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Mark Liggayu
  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).



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

2001-06-13 Thread lhoska

It may not be the real fix but you need a space before 'RECEIVED'
on line 3.
line 3: SUM(INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_QUANTITY) RECEIVED.

Another thing: you don't need to say ALL in your select.  ALL is a default.


-Original Message-
Sent: Wednesday, June 13, 2001 5:52 PM
To: Multiple recipients of list ORACLE-L


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;

I appreciate all the help


-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Mark Liggayu
  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: 
  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).



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

2001-06-13 Thread Kevin Lange

I have had this problem before as well.  I do not know if it the only way,
but my solution was to include those two internal SQL statements as part of
the from and then use the variable.

i.e.

INSERT INTO AWW_ISSUED
SELECT ALL 
INV.MTL_MATERIAL_TRANSACTIONS.INVENTORY_ITEM_ID,

SUM(INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_QUANTITY)RECEIVED
FROMINV.MTL_MATERIAL_TRANSACTIONS,
(SELECT TO_DATE('01' ||
SUBSTR(TO_CHAR(SYSDATE),3,9))FIRST_DATE FROM DUAL) A,
(SELECT LAST_DAY(SYSDATE) LAST_DATE FROM DUAL) B
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 A.first_date AND B.last_date
GROUP BY INV.MTL_MATERIAL_TRANSACTIONS.INVENTORY_ITEM_ID;

Of course, since you are just selecting a function, why don't you see if you
can just select that value:

INSERT INTO AWW_ISSUED
SELECT ALL 
INV.MTL_MATERIAL_TRANSACTIONS.INVENTORY_ITEM_ID,

SUM(INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_QUANTITY)RECEIVED
FROMINV.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 TO_DATE('01' || SUBSTR(TO_CHAR(SYSDATE),3,9)) AND LAST_DAY(SYSDATE)
GROUP BY INV.MTL_MATERIAL_TRANSACTIONS.INVENTORY_ITEM_ID;


-Original Message-
Sent: Wednesday, June 13, 2001 4:52 PM
To: Multiple recipients of list ORACLE-L


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;

I appreciate all the help


-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Mark Liggayu
  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: Kevin Lange
  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).



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

2001-06-13 Thread Jacques Kilchoer
Title: RE: HELP !!! scrpt works with sql plus but not in a procedure





see answer below


 -Original Message-
 From: Mark Liggayu [mailto:[EMAIL PROTECTED]]
 
 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', 'MMDD') and date_field  ('20010701', 'MMDD') ...
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', 'MMDD')
 and to_date ('200010630', 'MMDD')
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





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

2001-06-13 Thread MacGregor, Ian A.

I don't think, inline views work in a procedure, he said with a 75% confidence level.  
Their use here is suspect anyway.  

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)

is equivalent to..

AND  INV.MTL_MATERIAL_TRANSACTIONS.TRANSACTION_DATE BETWEEN
TO_DATE('01' || SUBSTR(TO_CHAR(SYSDATE),3,9) and
LAST_DAY(SYSDATE)

I'm also confused by the following

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)

These where clauses conflict unless it is June '01, then they are redundant. 


Ian MacGregor 
Stanford Linear Accelerator Center
[EMAIL PROTECTED]   


-Original Message-
Sent: Wednesday, June 13, 2001 2:52 PM
To: Multiple recipients of list ORACLE-L


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;

I appreciate all the help


-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Mark Liggayu
  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: MacGregor, Ian A.
  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).