-
| I'm trying to run a PL/SQL procedure that takes array values as input. Since I have to call this procedure many times for my data, I tried to use the  However, I get an error message from oracledb as soon as I try to use more than one dataset in the bind arguments. It doesn't make a difference if I use positional or named binds, and using  SQL code:   begin
      CM_DATA.ADD_ITEM(
          p_public_id    => :public_id,
          p_type_id      => :type_id,
          p_field_names  => :field_names,
          p_field_values => :field_values
      );
  end;The  Bind parameters (example with only 2 datasets): [
  {
    'public_id': <oracledb.Var of type DB_TYPE_NUMBER with value None>, 
    'type_id': 24, 
    'field_names': ['SERVER_ID', 'DOOCS_LOCATION', 'DOOCS_PROPERTY'], 
    'field_values': ['195181', 'AMC1', 'ACTIVATE']
  }, {
    'public_id': <oracledb.Var of type DB_TYPE_NUMBER with value None>, 
    'type_id': 24, 
    'field_names': ['SERVER_ID', 'DOOCS_LOCATION', 'DOOCS_PROPERTY'], 
    'field_values': ['195181', 'AMC1', 'ALIAS']
  }
]The  Relevant code: # These are the input values to my Python function (add_bulk_items)
type_id = 24
public_ids = [None, None]
bulk_data = [{'SERVER_ID': 195181, 'DOOCS_LOCATION': 'AMC1', 'DOOCS_PROPERTY': 'ACTIVATE'},
             {'SERVER_ID': 195181, 'DOOCS_LOCATION': 'AMC1', 'DOOCS_PROPERTY': 'ALIAS'}]
with connection.cursor() as cursor:
    bind_args, return_vars = [], []
    for data, public_id in zip(bulk_data, public_ids):
        # convert input dict to separate name/value lists
        field_names, field_values = [], []
        for k, v in data.items():
            field_names.append(k.upper())
            if v is None:
                field_values.append(None)
            else:
                field_values.append(str(v))
        public_id_var = cursor.var(int)  # needed for IN/OUT parameter
        public_id_var.setvalue(0, public_id)
        bind_args.append(dict(public_id=public_id_var, type_id=type_id, field_names=field_names, field_values=field_values))
    cursor.setinputsizes(public_id=None, type_id=None, field_names=100, field_values=100)
    cursor.executemany(sql, bind_args, batcherrors=False)The error I'm getting: The exception is raised here: https://github.com/oracle/python-oracledb/blob/v2.5.0/src/oracledb/impl/thin/messages.pyx#L1142 Again, running this with only 1 item in the bind list works fine, and so does calling  Versions used: 
 | 
Beta Was this translation helpful? Give feedback.
Replies: 3 comments 6 replies
-
| Before you get too deep into this, review the caveat in the Batch Execution of PL/SQL doc: 
 | 
Beta Was this translation helpful? Give feedback.
-
| This may have some useful clues: with oracledb.connect(user=un, password=pw, dsn=cs) as connection:
    with connection.cursor() as cursor:
        stmts = [
        """create or replace type my_varchar_list as varray(100) of varchar2(100)""",
        """create or replace procedure myproc(p in number, names in my_varchar_list, count out number) as
           begin
             count := p + names.count;
           end;""",
        ]
        for s in stmts:
            cursor.execute(s)
            if cursor.warning and cursor.warning.full_code == "DPY-7000":
                print(cursor.warning)
                print(s)
    type_obj = connection.gettype("MY_VARCHAR_LIST")
    # Single execute()
    with connection.cursor() as cursor:
        n = 100
        obj = type_obj.newobject()
        obj.extend(['Alex', 'Bobbie', 'Charlie'])
        with connection.cursor() as cursor:
            count = cursor.var(oracledb.DB_TYPE_NUMBER)
            cursor.callproc("myproc", [n, obj, count])
            # prints "OUT bind value is 103"
            print(f"OUT bind value is {count.getvalue()}")
    # Using executemany()
    with connection.cursor() as cursor:
        obj1 = type_obj.newobject()
        obj1.extend(['Alex', 'Bobbie'])
        obj2 = type_obj.newobject()
        obj2.extend(['Charlie', 'Dave', 'Eric'])
        obj3 = type_obj.newobject()
        obj3.extend(['Fred', 'Georgia', 'Helen', 'Ian'])
        data = [
            {"p": 100, "names": obj1},
            {"p": 200, "names": obj2},
            {"p": 300, "names": obj3},
        ]
        count = cursor.var(oracledb.DB_TYPE_NUMBER, arraysize=len(data))
        cursor.setinputsizes(p=None, names=type_obj, count=count)
        cursor.executemany("begin myproc(:p, :names, :count); end;", data)
        # prints "OUT bind value is [102, 203, 304]"
        print(f"OUT bind value is {count.values}")Output is:  | 
Beta Was this translation helpful? Give feedback.
-
| Alright, thanks to the code example from @cjbj I was able to get it working. The main issue apparently was the definition of return variables - instead of passing individual cursor variables with the bind list, they must be (additionally) passed with  I can provide an updated code example later. | 
Beta Was this translation helpful? Give feedback.
The doc just got pushed to GH. See https://python-oracledb.readthedocs.io/en/latest/user_guide/batch_statement.html#batch-execution-of-pl-sql and https://github.com/oracle/python-oracledb/blob/main/samples/plsql_batch.py