Results 1 to 3 of 3
  1. #1
    Join Date
    Oct 2002
    Location
    Toronto, Canada
    Posts
    12

    Unanswered: Stored proc problem - dynamic sql

    I'm trying to create a procedure so that I can build my sql in the stored proc dynamically and am having problems. I've been researching this and to my knowledge, I'm doing it correctly, but not working.... I have boiled it down to a simple problem and invite you to enlighten me as to what I'm doing wrong.

    Running on:
    DB21085I This instance or install (instance name, where applicable:
    "inst1") uses "64" bits and DB2 code release "SQL10055" with level
    identifier "0606010E".
    Informational tokens are "DB2 v10.5.0.5", "s141128", "IP23633", and Fix Pack
    "5".

    Code:
    CREATE PROCEDURE db2mon.test_proc
    (IN where varchar(40),
    OUT P_SQLSTATE_OUT CHARACTER(5)
    )


    DYNAMIC RESULT SETS 1


    DDHLD: BEGIN


    -- Declare variable
    DECLARE stmt_text varchar(4096);



    BEGIN
    DECLARE cursor1 CURSOR WITH RETURN FOR stmt_text;
    SET stmt_text='select * from syscat.tables '||where;
    prepare cursor1 from stmt_text;
    open cursor1;
    END;


    END DDHLD


    @

    I can create the procedure fine, but when I try to run it I get:

    call db2mon.test_proc('where tabname=''TEST''',?)


    The cursor "CURSOR1" is not in a prepared state.. SQLCODE=-514, SQLSTATE=26501, DRIVER=3.66.46

    I've tried many iterations of this in slightly different forms; this is my last one, but they all end the same way...

    Any comments appreciated.

    Thanks,
    P
    Last edited by rpm2203; 08-27-15 at 16:32.
    Paul
    www.dbmsguy.com

  2. #2
    Join Date
    Apr 2006
    Location
    Belgium
    Posts
    2,514
    Provided Answers: 11
    see some examples
    http://www-01.ibm.com/support/knowle...erate-db2.html
    i believe the declare cursor should be after the SET stmt_text='select * from syscat.tables '||where;
    Best Regards, Guy Przytula
    Database Software Consultant
    Good DBAs are not formed in a week or a month. They are created little by little, day by day. Protracted and patient effort is needed to develop good DBAs.
    Spoon feeding : To treat (another) in a way that discourages independent thought or action, as by overindulgence.
    DB2 UDB LUW Certified V7-V8-V9-V9.7-V10.1-V10.5 DB Admin - Advanced DBA -Dprop..
    Information Server Datastage Certified
    http://www.infocura.be

  3. #3
    Join Date
    Jul 2013
    Location
    Moscow, Russia
    Posts
    666
    Provided Answers: 55
    A number of errors.
    Look at the correct code below.
    Note, that:
    - you don't have to declare the STATEMENT variables
    - you can omit the inner BEGIN & END clauses

    Code:
    CREATE or replace PROCEDURE test_proc
    (IN where varchar(40),
    OUT P_SQLSTATE_OUT CHARACTER(5)
    )
    DYNAMIC RESULT SETS 1
    DDHLD: BEGIN
    -- Declare variable
    DECLARE stmt_text varchar(4096);
    --DECLARE s1 STATEMENT;
    
    BEGIN
    DECLARE cursor1 CURSOR WITH RETURN FOR s1;
    SET stmt_text='select * from syscat.tables '||where;
    prepare s1 from stmt_text;
    open cursor1;
    END;
    
    
    END DDHLD
    @
    Last edited by mark.b; 08-28-15 at 06:50.
    Regards,
    Mark.

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •