File: pythondb.html

package info (click to toggle)
sqlrelay 1%3A0.37.1-3.1
  • links: PTS
  • area: main
  • in suites: etch, etch-m68k
  • size: 13,084 kB
  • ctags: 6,691
  • sloc: cpp: 48,136; python: 10,118; ansic: 9,673; java: 9,195; php: 8,839; perl: 8,827; sh: 8,554; ruby: 8,516; tcl: 5,039; makefile: 3,665
file content (757 lines) | stat: -rw-r--r-- 31,175 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
<html>
<head>
<title>firstworks   Programming with SQL Relay using the Python DB API</title>
<link href="../css/styles.css" rel="stylesheet">
</head>
<body>

<span class="heading1">Programming with SQL Relay using the Python DB API</span><br><br>

<ul>
<li><a href="#session">Establishing a Sessions</a></li>
<li><a href="#query">Executing Queries</a></li>
<li><a href="#commit">Commits and Rollbacks</a></li>
<li><a href="#temptables">Temporary Tables</a></li>
<li><a href="#errors">Catching Errors</a></li>
<li><a href="#bindvars">Bind Variables</a></li>
<li><a href="#rebinding">Re-Binding and Re-Executing</a></li>
<li><a href="#fields">Accessing Fields in the Result Set</a></li>
<li><a href="#cursors">Cursors</a></li>
<li><a href="#columns">Getting Column Information</a></li>
<li><a href="#storedprocedures">Stored Procedures</a></li>
</ul>

<a name="session"></a>
<span class="heading2">Establishing a Session</span><br><br>

<p>To use SQL Relay, you have to identify the connection that you intend to 
use.</p>

<blockquote>
<PRE>
<FONT color=#a020f0>from</FONT> SQLRelay <FONT color=#a020f0>import</FONT> PySQLRDB

con=PySQLRDB.connect('<FONT color=#ff00ff>host</FONT>',9000,'','<FONT color=#ff00ff>user</FONT>','<FONT color=#ff00ff>password</FONT>',0,1)
cur=con.cursor()

... execute some queries ...
</PRE>
</blockquote>

<p>After calling the connect(), a session is established when the first 
execute() is run.</p>

<p>For the duration of the session, the client stays connected to a database
connection daemon.  While one client is connected, no other client can connect.
Care should be taken to minimize the length of a session.</p>

<p>If you're using a transactional database, ending a session has a catch.
Database connection daemons can be configured to send either a commit or
rollback at the end of a session if DML queries were executed during the
session with no commit or rollback.  Program accordingly.</p>

<a name="query"></a>
<span class="heading2">Executing Queries</span><br><br>

<p>Call execute() to run a query.</p>

<blockquote>
<PRE>
<FONT color=#a020f0>from</FONT> SQLRelay <FONT color=#a020f0>import</FONT> PySQLRDB

con=PySQLRDB.connect('<FONT color=#ff00ff>host</FONT>',9000,'','<FONT color=#ff00ff>user</FONT>','<FONT color=#ff00ff>password</FONT>',0,1)
cur=con.cursor()

cur.execute('<FONT color=#ff00ff>select * from my_table</FONT>')

... process the result set ...

</PRE>
</blockquote>

<a name="commit"></a>
<span class="heading2">Commits and Rollbacks</span><br><br>

<p>If you need to execute a commit or rollback, you should use the commit()
and rollback() methods rather than sending a "commit" or "rollback" query.  
There are two reasons for this.  First, it's much more efficient to call the 
methods.  Second, if you're writing code that can run on transactional or 
non-transactional databases, some non-transactional databases will throw errors
if they receive a "commit" or "rollback" query, but by calling the commit() 
and rollback() methods you instruct the database connection daemon to call the 
commit and rollback API methods for that database rather than issuing them as 
queries.  If the API's have no commit or rollback methods, the calls do nothing
and the database throws no error.  This is especially important when using SQL 
Relay with ODBC.</p>

<a name="temptables"></a>
<span class="heading2">Temporary Tables</span><br><br>

<p>Some databases support temporary tables.  That is, tables which are
automatically dropped or truncated when an application closes it's connection
to the database or when a transaction is committed or rolled back.</p>

<p>For databases which drop or truncate tables when a transaction is committed
or rolled back, temporary tables work naturally.</p>

<p>However, for databases which drop or truncate tables when an application
closes it's connection to the database, there is an issue.  Since SQL Relay
maintains persistent database connections, when an application disconnects from
SQL Relay, the connection between SQL Relay and the database remains, so
the database does not know to drop or truncate the table.  To remedy this
situation, SQL Relay parses each query to see if it created a temporary table,
keeps a list of temporary tables and drops (or truncates them) when the
application disconnects from SQL Relay.  Since each database has slightly
different syntax for creating a temporary table, SQL Relay parses each query
according to the rules for that database.</p>

<p>In effect, temporary tables should work when an application connects to
SQL Relay in the same manner that they would work if the application connected
directly to the database.</p>

<a name="errors"></a>
<span class="heading2">Catching Errors</span><br><br>

<p>If your call to execute() raises an exception, the query failed.
You can find out why by catching the exception.</p>

<blockquote>
<PRE>
<FONT color=#a020f0>from</FONT> SQLRelay <FONT color=#a020f0>import</FONT> PySQLRDB

con=PySQLRDB.connect('<FONT color=#ff00ff>host</FONT>',9000,'','<FONT color=#ff00ff>user</FONT>','<FONT color=#ff00ff>password</FONT>',0,1)
cur=con.cursor()

<B><FONT color=#a52a2a>try</FONT></B>:
	cur.execute('<FONT color=#ff00ff>select * from my_nonexistant_table</FONT>')
<B><FONT color=#a52a2a>except</FONT></B> PySQLRDB.DatabaseError, e:
	print e

</PRE>
</blockquote>

<a name="bindvars"></a>
<span class="heading2">Bind Variables</span><br><br>

<p>Programs rarely execute fixed queries.  More often than not, some part
of the query is dynamically generated.  The Python DB API provides a means
for using bind variables in those queries.</p>

<p>For a detailed discussion of binds, see 
<a href="binds.html">this document</a>.</p>

<blockquote>
<PRE>
<FONT color=#a020f0>from</FONT> SQLRelay <FONT color=#a020f0>import</FONT> PySQLRDB

con=PySQLRDB.connect('<FONT color=#ff00ff>host</FONT>',9000,'','<FONT color=#ff00ff>user</FONT>','<FONT color=#ff00ff>password</FONT>',0,1)
cur=con.cursor()

cur.execute('<FONT color=#ff00ff>select * from my_table where column1&gt;:val1 and column2=:val2 and column3&lt;:val3</FONT>',{'<FONT color=#ff00ff>val1</FONT>':1,'<FONT color=#ff00ff>val2</FONT>':'<FONT color=#ff00ff>hello</FONT>','<FONT color=#ff00ff>val3</FONT>':50.546})

... process the result set ...

</PRE>
</blockquote>

<p>When passing a floating point number in as a bind or substitution variable,
you have to supply precision and scale for the number.  See
<a href="precisionscale.html">this page</a> for a discussion of precision and
scale.</p>

<a name="rebinding"></a>
<span class="heading2">Re-Binding and Re-Execution</span><br><br>

<p>A feature of the prepare/bind/execute paradigm is the ability to prepare, 
bind and execute a query once, then re-bind and re-execute the query 
over and over without re-preparing it.  If your backend database natively 
supports this paradigm, you can reap a substantial performance improvement.</p>

<p>The Python DB API supports this paradigm via the executemany method.  If you
pass in a list of parameter dictionaries, the query will be re-executed for
each dictionary of bind variable/values.</p>

<blockquote>
<PRE>
<FONT color=#a020f0>from</FONT> SQLRelay <FONT color=#a020f0>import</FONT> PySQLRDB

con=PySQLRDB.connect('<FONT color=#f800f8>host</FONT>',9000,'','<FONT color=#f800f8>user</FONT>','<FONT color=#f800f8>password</FONT>',0,1)
cur=con.cursor()

cur.executemany('<FONT color=#ff00ff>insert into my_table values (:val1,:val2,:val3)</FONT>',
		[{'<FONT color=#ff00ff>val1</FONT>':1,'<FONT color=#ff00ff>val2</FONT>':'<FONT color=#ff00ff>hello</FONT>','<FONT color=#ff00ff>val3</FONT>':1.11},
		{'<FONT color=#ff00ff>val1</FONT>':2,'<FONT color=#ff00ff>val2</FONT>':'<FONT color=#ff00ff>hi</FONT>','<FONT color=#ff00ff>val3</FONT>':2.22},
		{'<FONT color=#ff00ff>val1</FONT>':3,'<FONT color=#ff00ff>val2</FONT>':'<FONT color=#ff00ff>bye</FONT>','<FONT color=#ff00ff>val3</FONT>':3,33}])

</PRE>
</blockquote>

<a name="fields"></a>
<span class="heading2">Accessing Fields in the Result Set</span><br><br>

<p>The fetchone(), fetchmany() and fetchall() methods are useful for processing
result sets.  fetchone() returns a list of values.  fetchmany() and fetchall()
each return a list of rows where each row is a list of values.</p>

<p>The rowcount member variable gives the number of rows in the result set of
a select query or the number of rows affected by an insert/update/delete query.
</p>

<blockquote>
<PRE>
<FONT color=#a020f0>from</FONT> SQLRelay <FONT color=#a020f0>import</FONT> PySQLRDB

con=PySQLRDB.connect('<FONT color=#ff00ff>host</FONT>',9000,'','<FONT color=#ff00ff>user</FONT>','<FONT color=#ff00ff>password</FONT>',0,1)
cur=con.cursor()

cur.execute('<FONT color=#ff00ff>select * from my_table</FONT>')

print '<FONT color=#ff00ff>rowcount:</FONT>', cur.rowcount

print '<FONT color=#ff00ff>the first row:</FONT>'
print cur.fetchone()
print

print '<FONT color=#ff00ff>the next three rows:</FONT>'
print cur.fetchmany(3)
print

print '<FONT color=#ff00ff>the rest of the rows:</FONT>'
print cur.fetchall()
print
</PRE>
</blockquote>

<a name="cursors"></a>
<span class="heading2">Cursors</span><br><br>

<p>Cursors make it possible to execute queries while processing the result
set of another query.  You can select rows from a table in one query, then 
iterate through it's result set, inserting rows into another table, using only 
1 database connection for both operations.</p>

<p>For example:</p>

<blockquote>
<PRE>
<FONT color=#a020f0>from</FONT> SQLRelay <FONT color=#a020f0>import</FONT> PySQLRDB

con=PySQLRDB.sqlrconnection('<FONT color=#f800f8>host</FONT>',9000,'','<FONT color=#f800f8>user</FONT>','<FONT color=#f800f8>password</FONT>',0,1)
cursor1=con.cursor()
cursor2=con.cursor()

cursor1.execute('<FONT color=#f800f8>select * from my_huge_table</FONT>')

<B><FONT color=#a02828>for</FONT></B> a in cursor1.fetchall():
        cursor2.execute('<FONT color=#f800f8>insert into my_other_table values (:1,:2,:3)</FONT>',{':1',a[0],':2',a[1],':3',a[2]})
</PRE>
</blockquote>

<a name="columns"></a>
<span class="heading2">Getting Column Information</span><br><br>

<p>After executing a query, column information is stored in the desc 
variable.  desc is a list of tuples.  Each tuple corresponds to a column, 
containing it's name, type and length. </p>

<blockquote>
<PRE>
<FONT color=#a020f0>from</FONT> SQLRelay <FONT color=#a020f0>import</FONT> PySQLRDB

con=PySQLRDB.connect('<FONT color=#ff00ff>host</FONT>',9000,'','<FONT color=#ff00ff>user</FONT>','<FONT color=#ff00ff>password</FONT>',0,1)
cur=con.cursor()

cur.execute('<FONT color=#ff00ff>select * from my_table</FONT>')

<B><FONT color=#a52a2a>for</FONT></B> name,type,length <B><FONT color=#a52a2a>in</FONT></B> cur.desc:
        print '<FONT color=#ff00ff>Name:          </FONT>', name
        print '<FONT color=#ff00ff>Type:          </FONT>', type
        print '<FONT color=#ff00ff>Length:        </FONT>', length
</PRE>
</blockquote>

<a name="storedprocedures"></a>
<span class="heading2">Stored Procedures</span><br><br>

<p>Many databases support stored procedures.  Stored procedures are sets of
queries and procedural code that are executed inside of the database itself.
For example, a stored procedure may select rows from one table, iterate through
the result set and, based on the values in each row, insert, update or delete
rows in other tables.  A client program could do this as well, but a stored
procedure is generally more efficient because queries and result sets don't
have to be sent back and forth between the client and database.  Also, stored
procedures are generally stored in the database in a compiled state, while
queries may have to be re-parsed and re-compiled each time they are sent.</p>

<p>While many databases support stored procedures.  The syntax for creating
and executing stored procedures varies greatly between databases.</p>

<p>SQL Relay supports stored procedures for most databases, but there are
some caveats.  Stored procedures are not currently supported when using FreeTDS
against Sybase or Microsoft SQL Server.  Blob/Clob bind variables are only
supported in Oracle 8i or higher.  Sybase stored procedures must use varchar
output parameters.</p>

<p>Stored procedures typically take input paramters from client programs through
input bind variables and return values back to client programs either through
bind variables or result sets.  Stored procedures can be broken down into
several categories, based on the values that they return.  Some stored
procedures don't return any values, some return a single value, some return
multiple values and some return entire result sets.</p>

<span class="heading3">No Values</span><br>

<p>Some stored procedures don't return any values.  Below are examples,
illustrating how to create, execute and drop this kind of stored procedure for
each database that SQL Relay supports.</p>

<span class="heading4">Oracle</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">procedure</font> testproc(in1 <font color="#a52829"><b>in</b></font> <font color="#298a52"><b>number</b></font>, in2 <font color="#a52829"><b>in</b></font> <font color="#298a52"><b>number</b></font>, in3 <font color="#a52829"><b>in</b></font> <font color="#298a52"><b>varchar2</b></font>) <font color="#6b59ce">is</font>
<font color="#6b59ce">begin</font>
        <font color="#a52829"><b>insert</b></font> <font color="#6b59ce">into</font> mytable <font color="#6b59ce">values</font> (in1,in2,in3);
<font color="#6b59ce">end</font>;
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">begin testproc(:in1,:in2,:in3); end;</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">procedure</font> testproc
</pre>
</blockquote>


<span class="heading4">Sybase and Microsoft SQL Server</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">procedure</font> testproc @in1 int, @in2 <font color="#298a52"><b>float</b></font>, @in3 <font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>) <font color="#6b59ce">as</font>
        <font color="#a52829"><b>insert</b></font> <font color="#6b59ce">into</font> mytable <font color="#6b59ce">values</font> (@in1,@in2,@in3)
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">exec testproc</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">procedure</font> testproc
</pre>
</blockquote>

<span class="heading4">Interbase and Firebird</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">procedure</font> testproc(in1 <font color="#298a52"><b>integer</b></font>, in2 <font color="#298a52"><b>float</b></font>, in3 <font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>)) <font color="#6b59ce">as</font>
<font color="#6b59ce">begin</font>
        <font color="#a52829"><b>insert</b></font> <font color="#6b59ce">into</font> mytable <font color="#6b59ce">values</font> (in1,in2,in3);
        suspend;
<font color="#6b59ce">end</font>;
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">exec procedure testproc ?, ?, ?</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">procedure</font> testproc
</pre>
</blockquote>

<span class="heading4">DB2</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">procedure</font> testproc(<font color="#a52829"><b>in</b></font> in1 int, <font color="#a52829"><b>in</b></font> in2 double, <font color="#a52829"><b>in</b></font> in3 <font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>)) language sql
<font color="#6b59ce">begin</font>
        <font color="#a52829"><b>insert</b></font> <font color="#6b59ce">into</font> mytable <font color="#6b59ce">values</font> (in1,in2,in3);
<font color="#6b59ce">end</font>;
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">call testproc(?,?,?)</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">procedure</font> testproc
</pre>
</blockquote>

<span class="heading4">Postgresql</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">function</font> testproc(int,<font color="#298a52"><b>float</b></font>,<font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>)) returns void <font color="#6b59ce">as</font> '
<font color="#6b59ce">begin</font>
        <font color="#a52829"><b>insert</b></font> <font color="#6b59ce">into</font> mytable <font color="#6b59ce">values</font> ($<font color="#ff00ff">1</font>,$<font color="#ff00ff">2</font>,$<font color="#ff00ff">3</font>);
        <font color="#6b59ce">return</font>;
<font color="#6b59ce">end</font>;' language plpgsql
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">select testproc(:in1,:in2,:in3)</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">procedure</font> testproc
</pre>
</blockquote>




<br><span class="heading3">Single Values</span><br>

<p>Some stored procedures return single values.  Below are examples,
illustrating how to create, execute and drop this kind of stored procedure for
each database that SQL Relay supports.</p>

<span class="heading4">Oracle</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">function</font> testproc(in1 <font color="#a52829"><b>in</b></font> <font color="#298a52"><b>number</b></font>, in2 <font color="#a52829"><b>in</b></font> <font color="#298a52"><b>number</b></font>, in3 <font color="#a52829"><b>in</b></font> <font color="#298a52"><b>varchar2</b></font>) returns <font color="#298a52"><b>number</b></font> <font color="#6b59ce">is</font>
<font color="#6b59ce">begin</font>
        <font color="#6b59ce">return</font> in1;
<font color="#6b59ce">end</font>;
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">select testproc(:in1,:in2,:in3) from dual</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
result=cur.fetchone()[0]
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">function</font> testproc
</pre>
</blockquote>

<span class="heading4">Sybase and Microsoft SQL Server</span><br>

<p>In Sybase and Microsoft SQL Server, stored procedures return values
through output parameters rather than as return values of the procedure
itself.  However, the SQL Relay Python DBdriver does not currently support
output parameters.</p>


<span class="heading4">Interbase and Firebird</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">procedure</font> testproc(in1 <font color="#298a52"><b>integer</b></font>, in2 <font color="#298a52"><b>float</b></font>, in3 <font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>)) returns (out1 <font color="#298a52"><b>integer</b></font>) <font color="#6b59ce">as</font>
<font color="#6b59ce">begin</font>
        out1=in1;
        suspend;
<font color="#6b59ce">end</font>;
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">select * from testproc(?,?,?)</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
result=cur.fetchone()[0]
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">procedure</font> testproc
</pre>
</blockquote>


<span class="heading4">DB2</span><br>

<p>In DB2, stored procedures return values through output parameters rather
than as return values of the procedure itself.  However, the SQL Relay Python
DB driver does not currently support output parameters.</p>

<span class="heading4">Postgresql</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">function</font> testfunc(int,<font color="#298a52"><b>float</b></font>,<font color="#298a52"><b>char</b></font>(<font color="#ff00ff">20</font>)) returns int <font color="#6b59ce">as</font> '
declare
        in1 int;
        in2 <font color="#298a52"><b>float</b></font>;
        in3 <font color="#298a52"><b>char</b></font>(<font color="#ff00ff">20</font>);
<font color="#6b59ce">begin</font>
        in1:=$<font color="#ff00ff">1</font>;
        <font color="#6b59ce">return</font>;
<font color="#6b59ce">end</font>;
' language plpgsql
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">select * from testfunc(:in1,:in2,:in3)</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
result=cur.fetchone()[0]
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">function</font> testfunc(int,<font color="#298a52"><b>float</b></font>,<font color="#298a52"><b>char</b></font>(<font color="#ff00ff">20</font>))
</pre>
</blockquote>



<br><span class="heading3">Multiple Values</span><br>

<p>Some stored procedures return multiple values.  Below are examples,
illustrating how to create, execute and drop this kind of stored procedure for
each database that SQL Relay supports.</p>

<span class="heading4">Oracle</span><br>

<p>In Oracle, stored procedures can return values through output parameters or
as return values of the procedure itself.  If a procedure needs to return
multiple values, it can return one of them as the return value of the procedure
itself, but the rest must be returned through output parameters.  However, the
SQL Relay Python DB driver does not currently support output parameters.</p>

<span class="heading4">Sybase and Microsoft SQL Server</span><br>

<p>In Sybase and Microsoft SQL Server, stored procedures return values
through output parameters rather than as return values of the procedure
itself.  However, the SQL Relay Python DB driver does not currently support
output parameters.</p>

<span class="heading4">Interbase and Firebird</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">procedure</font> testproc(in1 <font color="#298a52"><b>integer</b></font>, in2 <font color="#298a52"><b>float</b></font>, in3 <font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>)) returns (out1 <font color="#298a52"><b>integer</b></font>, out2 <font color="#298a52"><b>float</b></font>, out3 <font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>)) <font color="#6b59ce">as</font>
<font color="#6b59ce">begin</font>
        out1=in1;
        out2=in2;
        out3=in3;
        suspend;
<font color="#6b59ce">end</font>;
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">select * from testfunc(?,?,?)</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
out1=cur.fetchone()[0]
out2=cur.fetchone()[1]
out3=cur.fetchone()[2]
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">procedure</font> testproc
</pre>
</blockquote>


<span class="heading4">DB2</span><br>

<p>In DB2, stored procedures return values through output parameters rather
than as return values of the procedure itself.  However, the SQL Relay Python
DB driver does not currently support output parameters.</p>

<span class="heading4">Postgresql</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">function</font> testfunc(int,<font color="#298a52"><b>float</b></font>,<font color="#298a52"><b>char</b></font>(<font color="#ff00ff">20</font>)) returns record <font color="#6b59ce">as</font> '
declare
        output record;
<font color="#6b59ce">begin</font>
        <font color="#a52829"><b>select</b></font> $<font color="#ff00ff">1</font>,$<font color="#ff00ff">2</font>,$<font color="#ff00ff">3</font> <font color="#6b59ce">into</font> output;
        <font color="#6b59ce">return</font> output;
<font color="#6b59ce">end</font>;
' language plpgsql
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">select * from testfunc(:in1,:in2,:in3) as (col1 int, col2 float, col3 char(20))</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
out1=cur.fetchone()[0]
out2=cur.fetchone()[1]
out3=cur.fetchone()[2]
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">function</font> testfunc(int,<font color="#298a52"><b>float</b></font>,<font color="#298a52"><b>char</b></font>(<font color="#ff00ff">20</font>))
</pre>
</blockquote>



<br><span class="heading3">Result Sets</span><br>

<p>Some stored procedures return entire result sets.  Below are examples,
illustrating how to create, execute and drop this kind of stored procedure for
each database that SQL Relay supports.</p>

<span class="heading4">Oracle</span><br>

<p>Stored procedures in Oracle can return open cursors as return values or
output parameters.  A client-side cursor can be bound to this open cursor and
rows can be fetched from it.  However, the SQL Relay Python DB driver does not
currently support output parameters.</p>

<span class="heading4">Sybase and Microsoft SQL Server</span><br>

<p>Stored procedures in Sybase and Microsoft SQL Server can return a result
set if the last command in the procedure is a select query, however SQL Relay
doesn't currently support stored procedures that return result sets.</p>

<span class="heading4">Interbase and Firebird</span><br>

<p>Stored procedures in Interbase and Firebird can return a result set if a
select query in the procedure selects values into the output parameters and
then issues a suspend command, however SQL Relay doesn't currently support
stored procedures that return result sets.</p>

<span class="heading4">DB2</span><br>

<p>Stored procedures in DB2 can return a result set if the procedure is declared
to return one, however SQL Relay doesn't currently support stored procedures
that return result sets.</p>

<span class="heading4">Postgresql</span><br>

<p>To create the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>create</b></font> <font color="#6b59ce">function</font> testfunc() returns setof record <font color="#6b59ce">as</font> '
        declare output record;
<font color="#6b59ce">begin</font>
        <font color="#6b59ce">for</font> output <font color="#a52829"><b>in</b></font> <font color="#a52829"><b>select</b></font> * <font color="#6b59ce">from</font> mytable <font color="#6b59ce">loop</font>
                <font color="#6b59ce">return</font> next output;
        <font color="#6b59ce">end</font> <font color="#6b59ce">loop</font>;
        <font color="#6b59ce">return</font>;
<font color="#6b59ce">end</font>;
' language plpgsql
</pre>
</blockquote>

<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>

<blockquote>
<pre>
cur.execute('<font color="#ff00ff">select * from testfunc() as (col1 int, col2 float, col3 char(20))</font>',{'<font color="#ff00ff">in1</font>':1,'<font color="#ff00ff">in2</font>':1.1,'<font color="#ff00ff">in3</font>':'<font color="#ff00ff">hello</font>'})
result=cur.fetchall()
</pre>
</blockquote>

<p>To drop the stored procedure, run a query like the following.</p>

<blockquote>
<pre>
<font color="#a52829"><b>drop</b></font> <font color="#6b59ce">function</font> testfunc
</pre>
</blockquote>

</body>
</html>