|
| 1 | +# ----------------------------------------------------------------------------- |
| 2 | +# Copyright (c) 2024, Oracle and/or its affiliates. |
| 3 | +# |
| 4 | +# This software is dual-licensed to you under the Universal Permissive License |
| 5 | +# (UPL) 1.0 as shown at https://oss.oracle.com/licenses/upl and Apache License |
| 6 | +# 2.0 as shown at http://www.apache.org/licenses/LICENSE-2.0. You may choose |
| 7 | +# either license. |
| 8 | +# |
| 9 | +# If you elect to accept the software under the Apache License, Version 2.0, |
| 10 | +# the following applies: |
| 11 | +# |
| 12 | +# Licensed under the Apache License, Version 2.0 (the "License"); |
| 13 | +# you may not use this file except in compliance with the License. |
| 14 | +# You may obtain a copy of the License at |
| 15 | +# |
| 16 | +# https://www.apache.org/licenses/LICENSE-2.0 |
| 17 | +# |
| 18 | +# Unless required by applicable law or agreed to in writing, software |
| 19 | +# distributed under the License is distributed on an "AS IS" BASIS, |
| 20 | +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. |
| 21 | +# See the License for the specific language governing permissions and |
| 22 | +# limitations under the License. |
| 23 | +# ----------------------------------------------------------------------------- |
| 24 | + |
| 25 | +# ----------------------------------------------------------------------------- |
| 26 | +# plsql_batch.py |
| 27 | +# |
| 28 | +# Demonstrates using executemany() to make repeated calls to a PL/SQL procedure |
| 29 | +# |
| 30 | +# Note in python-oracledb Thick mode, when cursor.executemany() is used for |
| 31 | +# PL/SQL code that returns OUT binds, it will have the same performance |
| 32 | +# characteristics as repeated calls to cursor.execute(). |
| 33 | +# ----------------------------------------------------------------------------- |
| 34 | + |
| 35 | +import oracledb |
| 36 | +import sample_env |
| 37 | + |
| 38 | +# determine whether to use python-oracledb thin mode or thick mode |
| 39 | +if not sample_env.get_is_thin(): |
| 40 | + oracledb.init_oracle_client(lib_dir=sample_env.get_oracle_client()) |
| 41 | + |
| 42 | +connection = oracledb.connect( |
| 43 | + user=sample_env.get_main_user(), |
| 44 | + password=sample_env.get_main_password(), |
| 45 | + dsn=sample_env.get_connect_string(), |
| 46 | + params=sample_env.get_connect_params(), |
| 47 | +) |
| 48 | + |
| 49 | +# ----------------------------------------------------------------------------- |
| 50 | +# IN and OUT PL/SQL parameter examples |
| 51 | +# Also shows passing in an object |
| 52 | +# ----------------------------------------------------------------------------- |
| 53 | + |
| 54 | +# Setup |
| 55 | + |
| 56 | +with connection.cursor() as cursor: |
| 57 | + stmts = [ |
| 58 | + """create or replace type my_varchar_list as table of varchar2(100)""", |
| 59 | + """create or replace procedure myproc |
| 60 | + (p in number, names in my_varchar_list, count out number) as |
| 61 | + begin |
| 62 | + count := p + names.count; |
| 63 | + end;""", |
| 64 | + ] |
| 65 | + for s in stmts: |
| 66 | + cursor.execute(s) |
| 67 | + if cursor.warning: |
| 68 | + print(cursor.warning) |
| 69 | + print(s) |
| 70 | + |
| 71 | +type_obj = connection.gettype("MY_VARCHAR_LIST") |
| 72 | + |
| 73 | +# Example 1: positional binds |
| 74 | + |
| 75 | +with connection.cursor() as cursor: |
| 76 | + |
| 77 | + obj1 = type_obj.newobject() |
| 78 | + obj1.extend(["Alex", "Bobbie"]) |
| 79 | + obj2 = type_obj.newobject() |
| 80 | + obj2.extend(["Charlie", "Dave", "Eric"]) |
| 81 | + obj3 = type_obj.newobject() |
| 82 | + obj3.extend(["Fred", "Georgia", "Helen", "Ian"]) |
| 83 | + |
| 84 | + data = [ |
| 85 | + (1, obj1), |
| 86 | + (2, obj2), |
| 87 | + (3, obj3), |
| 88 | + ] |
| 89 | + |
| 90 | + count = cursor.var(oracledb.DB_TYPE_NUMBER, arraysize=len(data)) |
| 91 | + cursor.setinputsizes(None, type_obj, count) |
| 92 | + |
| 93 | + cursor.executemany("begin myproc(:1, :2, :3); end;", data) |
| 94 | + print(count.values) # [3, 5, 7] |
| 95 | + |
| 96 | +# Example 2: named binds |
| 97 | + |
| 98 | +with connection.cursor() as cursor: |
| 99 | + |
| 100 | + obj1 = type_obj.newobject() |
| 101 | + obj1.extend(["Alex", "Bobbie"]) |
| 102 | + obj2 = type_obj.newobject() |
| 103 | + obj2.extend(["Charlie", "Dave", "Eric"]) |
| 104 | + obj3 = type_obj.newobject() |
| 105 | + obj3.extend(["Fred", "Georgia", "Helen", "Ian"]) |
| 106 | + |
| 107 | + data = [ |
| 108 | + {"p": 100, "names": obj1}, |
| 109 | + {"p": 200, "names": obj2}, |
| 110 | + {"p": 300, "names": obj3}, |
| 111 | + ] |
| 112 | + |
| 113 | + count = cursor.var(oracledb.DB_TYPE_NUMBER, arraysize=len(data)) |
| 114 | + cursor.setinputsizes(p=None, names=type_obj, count=count) |
| 115 | + |
| 116 | + cursor.executemany("begin myproc(:p, :names, :count); end;", data) |
| 117 | + print(count.values) # [102, 203, 304] |
| 118 | + |
| 119 | +# ----------------------------------------------------------------------------- |
| 120 | +# IN/OUT PL/SQL parameter examples |
| 121 | +# ----------------------------------------------------------------------------- |
| 122 | + |
| 123 | +# Setup |
| 124 | + |
| 125 | +with connection.cursor() as cursor: |
| 126 | + stmt = """create or replace procedure myproc2 |
| 127 | + (p1 in number, p2 in out varchar2) as |
| 128 | + begin |
| 129 | + p2 := p2 || ' ' || p1; |
| 130 | + end;""" |
| 131 | + cursor.execute(stmt) |
| 132 | + if cursor.warning: |
| 133 | + print(cursor.warning) |
| 134 | + print(stmt) |
| 135 | + |
| 136 | +# Example 3: positional binds |
| 137 | + |
| 138 | +with connection.cursor() as cursor: |
| 139 | + data = [(440, "Gregory"), (550, "Haley"), (660, "Ian")] |
| 140 | + outvals = cursor.var( |
| 141 | + oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data) |
| 142 | + ) |
| 143 | + cursor.setinputsizes(None, outvals) |
| 144 | + |
| 145 | + cursor.executemany("begin myproc2(:1, :2); end;", data) |
| 146 | + print(outvals.values) # ['Gregory 440', 'Haley 550', 'Ian 660'] |
| 147 | + |
| 148 | +# Example 4: positional binds, utilizing setvalue() |
| 149 | + |
| 150 | +with connection.cursor() as cursor: |
| 151 | + data = [(777,), (888,), (999,)] |
| 152 | + |
| 153 | + inoutvals = cursor.var( |
| 154 | + oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data) |
| 155 | + ) |
| 156 | + inoutvals.setvalue(0, "Roger") |
| 157 | + inoutvals.setvalue(1, "Sally") |
| 158 | + inoutvals.setvalue(2, "Tom") |
| 159 | + cursor.setinputsizes(None, inoutvals) |
| 160 | + |
| 161 | + cursor.executemany("begin myproc2(:1, :2); end;", data) |
| 162 | + print(inoutvals.values) # ['Roger 777', 'Sally 888', 'Tom 999'] |
| 163 | + |
| 164 | +# Example 5: named binds |
| 165 | + |
| 166 | +with connection.cursor() as cursor: |
| 167 | + data = [ |
| 168 | + {"p1bv": 100, "p2bv": "Alfie"}, |
| 169 | + {"p1bv": 200, "p2bv": "Brian"}, |
| 170 | + {"p1bv": 300, "p2bv": "Cooper"}, |
| 171 | + ] |
| 172 | + outvals = cursor.var( |
| 173 | + oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data) |
| 174 | + ) |
| 175 | + cursor.setinputsizes(p1bv=None, p2bv=outvals) |
| 176 | + |
| 177 | + cursor.executemany("begin myproc2(:p1bv, :p2bv); end;", data) |
| 178 | + print(outvals.values) # ['Alfie 100', 'Brian 200', 'Cooper 300'] |
| 179 | + |
| 180 | +# Example 6: named binds, utilizing setvalue() |
| 181 | + |
| 182 | +with connection.cursor() as cursor: |
| 183 | + inoutvals = cursor.var( |
| 184 | + oracledb.DB_TYPE_VARCHAR, size=100, arraysize=len(data) |
| 185 | + ) |
| 186 | + inoutvals.setvalue(0, "Dean") |
| 187 | + inoutvals.setvalue(1, "Elsa") |
| 188 | + inoutvals.setvalue(2, "Felix") |
| 189 | + data = [{"p1bv": 101}, {"p1bv": 202}, {"p1bv": 303}] |
| 190 | + cursor.setinputsizes(p1bv=None, p2bv=inoutvals) |
| 191 | + |
| 192 | + cursor.executemany("begin myproc2(:p1bv, :p2bv); end;", data) |
| 193 | + print(inoutvals.values) # ['Dean 101', 'Elsa 202', 'Felix 303'] |
0 commit comments