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: Dynamic SQL question

RE: Dynamic SQL question

From: Igor Neyman <ineyman_at_perceptron.com>
Date: Fri, 19 Mar 2004 16:37:14 -0500
Message-ID: <005101c40dfa$57e72e10$0704a8c0@development.perceptron.com>


Try to add space before SET (if in_tablename doesn't end with the space):

v_update := 'UPDATE '|| in_tablename ||

            ' SET lft = DECODE( (SIGN((lft/:1)-1) + SIGN((lft/:2)-1)), 0,
lft-1, 2, lft-2, lft), '||

and so on...

Igor Neyman, OCP DBA
ineyman_at_perceptron.com

-----Original Message-----

From: oracle-l-bounce_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org] On Behalf Of Deanna Schneider Sent: Friday, March 19, 2004 4:28 PM
To: oracle-l_at_freelists.org
Subject: Dynamic SQL question

Hello,
I'm trying to write a procedure that includes dynamic sql (8.17). If I don't
use the dynamic sql, the query runs fine. If I do, it fails with a numeric
or value error (ORA-06512).

Can anyone see what I'm missing?
This works:
UPDATE resourcegroup

    SET lft = DECODE( (SIGN((lft/drop_left)-1) + SIGN((lft/drop_right)-1)),
0, lft-1, 2, lft-2, lft),

        rgt = DECODE( (SIGN((rgt/drop_left)-1) + SIGN((rgt/drop_right)-1)),
0, rgt-1, 2, rgt-2, lft)
WHERE lft > drop_left;

This fails:
v_update := 'UPDATE '|| in_tablename ||

            'SET lft = DECODE( (SIGN((lft/:1)-1) + SIGN((lft/:2)-1)), 0, lft-1, 2, lft-2, lft), '||

            'rgt = DECODE( (SIGN((rgt/:3)-1) + SIGN((rgt/:4)-1)), 0, rgt-1,
2, rgt-2, lft) ' ||

            'WHERE lft > :5';

EXECUTE IMMEDIATE v_update USING drop_left, drop_right, drop_left, drop_right, drop_left;

I'm just using the linewrap concantenation for use of readability for testing. It fails when it's all on one line as well.

Thanks.
-Deanna



Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--

Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html


Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--

Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
Received on Fri Mar 19 2004 - 15:33:43 CST

Original text of this message

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