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 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242
|
<html>
<head>
<title>firstworks Programming with SQL Relay using the Perl DBI API</title>
<link href="../css/styles.css" rel="stylesheet">
</head>
<body>
<span class="heading1">Programming with SQL Relay using the Perl DBI 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>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
... <FONT color=#008888>execute</FONT> <FONT color=#008888>some</FONT> <FONT color=#008888>queries</FONT> ...
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</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 prepare() and execute() to run a query.</p>
<blockquote>
<PRE>
<FONT color=#a020f0>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from user_tables</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>();
... <FONT color=#008888>process</FONT> <FONT color=#008888>the</FONT> <FONT color=#008888>result</FONT> <FONT color=#008888>set</FONT> ...
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</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>
<p>You can also turn Autocommit on or off by setting the AutoCommit attribute
of the database handle.</p>
<p>The following command turns Autocommit on.</p>
<blockquote>
<PRE>
<FONT color=#008a8e>$dbh</FONT>->{AutoCommit} = <FONT color=#ff00ff>1</FONT>;
</PRE>
</blockquote>
<p>The following command turns Autocommit off.</p>
<blockquote>
<PRE>
<FONT color=#008a8e>$dbh</FONT>->{AutoCommit} = <FONT color=#ff00ff>0</FONT>;
</PRE>
</blockquote>
<p>When Autocommit is on, the database performs a commit after each successful
DML or DDL query. When Autocommit is off, the database commits when the client
instructs it to, or (by default) when a client disconnects. For databases that
don't support Autocommit, setting the AutoCommit attribute has no effect.</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 calls to connect(), prepare() or execute() fail, you can catch the
error in DBI->errstr.
<blockquote>
<PRE>
<FONT color=#a020f0>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>)
<B><FONT color=#a02828>or</FONT></B> <B><FONT color=#a02828>die</FONT></B> <FONT color=#008888>DBI</FONT>-><FONT color=#008888>errstr</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from user_tables</FONT><FONT color=#f800f8>"</FONT>)
<B><FONT color=#a02828>or</FONT></B> <B><FONT color=#a02828>die</FONT></B> <FONT color=#008888>DBI</FONT>-><FONT color=#008888>errstr</FONT>;
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>()
<B><FONT color=#a02828>or</FONT></B> <B><FONT color=#a02828>die</FONT></B> <FONT color=#008888>DBI</FONT>-><FONT color=#008888>errstr</FONT>;
... <FONT color=#008888>process</FONT> <FONT color=#008888>the</FONT> <FONT color=#008888>result</FONT> <FONT color=#008888>set</FONT> ...
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</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 Perl DBI API provides 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>
<p>Here is an example using the bind_param() function. The first parameter of
the bind_param() function corresponds to the name or position of the bind
variable.</p>
<blockquote>
<PRE>
<FONT color=#a020f0>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from my_table where col1=:1 and col2=:2 and col3=:3</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>bind_param</FONT>(<FONT color=#f800f8>1</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>hello</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>bind_param</FONT>(<FONT color=#f800f8>2</FONT>,<FONT color=#f800f8>1</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>bind_param</FONT>(<FONT color=#f800f8>3</FONT>,<FONT color=#f800f8>5</FONT>.<FONT color=#f800f8>5</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>();
... <FONT color=#008888>process</FONT> <FONT color=#008888>the</FONT> <FONT color=#008888>result</FONT> <FONT color=#008888>set</FONT> ...
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</PRE>
</blockquote>
<p>With Oracle version 8i or greater, you can also bind CLOB's and BLOB's using the DBD::SQLRelay::SQL_CLOB and DBD::SQLRelay::SQL_BLOB extensions. When
binding a BLOB, you need to pass a hash containing type and length values.</p>
<blockquote>
<pre>
<font color="#a020f0">#!/usr/bin/env perl</font>
<font color="#a52a2a"><b>use </b></font>DBI;
<font color="#a52a2a"><b>my</b></font> <font color="#008b8b">$dbh</font>=DBI-><font color="#a52a2a"><b>connect</b></font>(<font color="#ff00ff">"</font><font color="#ff00ff">DBI:SQLRelay:host=testhost;port=9000;socket=</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">testuser</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">testpassword</font><font color="#ff00ff">"</font>);
<font color="#a52a2a"><b>my</b></font> <font color="#008b8b">$sth</font>=<font color="#008b8b">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">insert into mytable values (:clobval,:blobval)</font><font color="#ff00ff">"</font>);
<font color="#008b8b">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">:clobval</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">test clob</font><font color="#ff00ff">"</font>,DBD::SQLRelay::SQL_CLOB);
<font color="#008b8b">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">:blobval</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">test blob</font><font color="#ff00ff">"</font>,{<font color="#ff00ff">type</font>=>DBD::SQLRelay::SQL_CLOB,<font color="#a52a2a"><b>length</b></font>=><font color="#ff00ff">9</font>});
<font color="#008b8b">$sth</font>->execute();
... process the result set ...
<font color="#008b8b">$dbh</font>->disconnect;
</pre>
</blockquote>
<p>bind_param() is used for input binds. bind_inout_param() is used for output
binds. Here is an example using the bind_inout_param() function to retrieve a
value from a query. The first parameter of a bind_inout_param() call is the
name or position of the bind variable, the second parameter is the local
variable to return the result in and the third variable is the size of the
buffer to reserve for the value.</p>
<blockquote>
<pre>
<font color="#a520f7">#!/usr/bin/env perl</font>
<font color="#a52829"><b>use </b></font>DBI;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$dbh</font>=DBI-><font color="#a52829"><b>connect</b></font>(<font color="#ff00ff">"</font><font color="#ff00ff">DBI:SQLRelay:host=testhost;port=9000;socket=</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">testuser</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">testpassword</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">begin; :1='hello'; :2=1; :3=5.5; end;</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$hello</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$integer</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$float</font>;
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">1</font>,<font color="#008a8c">\$hello</font>,<font color="#ff00ff">10</font>);
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">2</font>,<font color="#008a8c">\$integer</font>,<font color="#ff00ff">10</font>);
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">3</font>,<font color="#008a8c">\$float</font>,<font color="#ff00ff">10</font>);
<font color="#008a8c">$sth</font>->execute();
<font color="#a52829"><b>print</b></font>(<font color="#ff00ff">"</font><font color="#008a8c">$hello</font><font color="#ff00ff"> </font><font color="#008a8c">$integer</font><font color="#ff00ff"> </font><font color="#008a8c">$float</font><font color="#6b59ce">\n</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$dbh</font>->disconnect;
</pre>
</blockquote>
<p>Here is an example using the execute() function directly. The additional
parameters correspond to bind variable positions. Note that the first
parameter must be "undef".</p>
<blockquote>
<PRE>
<FONT color=#a020f0>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from my_table where col1=:0 and col2=:1 and col3=:2</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>(<B><FONT color=#a02828>undef</FONT></B>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>hello</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>1</FONT>,<FONT color=#f800f8>5</FONT>.<FONT color=#f800f8>5</FONT>);
... <FONT color=#008888>process</FONT> <FONT color=#008888>the</FONT> <FONT color=#008888>result</FONT> <FONT color=#008888>set</FONT> ...
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</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>
<blockquote>
<PRE>
<FONT color=#a020f0>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from my_table where col1=:0 and col2=:1 and col3=:2</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>(<B><FONT color=#a02828>undef</FONT></B>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>hello</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>1</FONT>,<FONT color=#f800f8>1</FONT>.<FONT color=#f800f8>1</FONT>);
... <FONT color=#008888>process</FONT> <FONT color=#008888>result</FONT> <FONT color=#008888>set</FONT> ...
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>(<B><FONT color=#a02828>undef</FONT></B>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>hi</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>2</FONT>,<FONT color=#f800f8>2</FONT>.<FONT color=#f800f8>2</FONT>);
... <FONT color=#008888>process</FONT> <FONT color=#008888>result</FONT> <FONT color=#008888>set</FONT> ...
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>(<B><FONT color=#a02828>undef</FONT></B>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>goodbye</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>3</FONT>,<FONT color=#f800f8>3</FONT>.<FONT color=#f800f8>3</FONT>);
... <FONT color=#008888>process</FONT> <FONT color=#008888>result</FONT> <FONT color=#008888>set</FONT> ...
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</PRE>
</blockquote>
<a name="fields"></a>
<span class="heading2">Accessing Fields in the Result Set</span><br><br>
<p>The fetchrow_array(), bind_columns() and fetch() functions are useful for
processing result sets. fetchrow_array() returns an array of values.
bind_columns() associates variables with columns which are set when fetch() is
called.</p>
<p>Here's an example using fetchrow_array().</p>
<blockquote>
<PRE>
<FONT color=#a020f0>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from user_tables</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>();
<B><FONT color=#a02828>while</FONT></B> (<FONT color=#008888>@data</FONT>=<FONT color=#008888>$sth</FONT>-><FONT color=#008888>fetchrow_array</FONT>()) {
<B><FONT color=#a02828>foreach</FONT></B> <FONT color=#008888>$col</FONT> (<FONT color=#008888>@data</FONT>) {
<B><FONT color=#a02828>print</FONT></B> <FONT color=#f800f8>"</FONT><FONT color=#6858c8>\"</FONT><FONT color=#008888>$col</FONT><FONT color=#6858c8>\"</FONT><FONT color=#f800f8>,</FONT><FONT color=#f800f8>"</FONT>;
}
<B><FONT color=#a02828>print</FONT></B> <FONT color=#f800f8>"</FONT><FONT color=#6858c8>\n</FONT><FONT color=#f800f8>"</FONT>;
}
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</PRE>
</blockquote>
<p>Here's an example using bind_columns() and fetch(). Note that the first
bind_columns() parameter must be "undef".</p>
<blockquote>
<PRE>
<FONT color=#a020f0>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from my_table</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>();
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>bind_columns</FONT>(<B><FONT color=#a02828>undef</FONT></B>,<FONT color=#008888>\$col1</FONT>,<FONT color=#008888>\$col2</FONT>,<FONT color=#008888>\$col3</FONT>,<FONT color=#008888>\$col4</FONT>);
<B><FONT color=#a02828>while</FONT></B> (<FONT color=#008888>$sth</FONT>-><FONT color=#008888>fetch</FONT>()) {
<B><FONT color=#a02828>print</FONT></B> <FONT color=#f800f8>"</FONT><FONT color=#008888>$col</FONT><FONT color=#f800f8>, </FONT><FONT color=#008888>$col2</FONT><FONT color=#f800f8>, </FONT><FONT color=#008888>$col3</FONT><FONT color=#f800f8>, </FONT><FONT color=#008888>$col4</FONT><FONT color=#6858c8>\n</FONT><FONT color=#f800f8>"</FONT>;
}
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</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>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth1</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from my_first_table</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth1</FONT>-><FONT color=#008888>execute</FONT>();
<FONT color=#008888>$sth1</FONT>-><FONT color=#008888>bind_columns</FONT>(<B><FONT color=#a02828>undef</FONT></B>,<FONT color=#008888>\$col1</FONT>,<FONT color=#008888>\$col2</FONT>,<FONT color=#008888>\$col3</FONT>);
<B><FONT color=#a02828>while</FONT></B> (<FONT color=#008888>$sth1</FONT>-><FONT color=#008888>fetch</FONT>()) {
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth2</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>insert into my_second_table values (:0, :1, :2, sysdate)</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth2</FONT>-><FONT color=#008888>execute</FONT>(<B><FONT color=#a02828>undef</FONT></B>,<FONT color=#008888>$col1</FONT>,<FONT color=#008888>$col2</FONT>,<FONT color=#008888>$col3</FONT>);
}
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</PRE>
</blockquote>
<a name="columns"></a>
<span class="heading2">Getting Column Information</span><br><br>
<p>After executing a query, the column count is stored in the NUMBER_OF_FIELDS
statement property and column names are stored in the NAME statement property.
They are accessible as follows:</p>
<blockquote>
<PRE>
<FONT color=#a020f0>#!/usr/bin/env perl</FONT>
<FONT color=#008888>use</FONT> <FONT color=#008888>DBI</FONT>;
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$dbh</FONT>=<FONT color=#008888>DBI</FONT>-><B><FONT color=#a02828>connect</FONT></B>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>DBI:SQLRelay:host=testhost;port=9000;socket=</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testuser</FONT><FONT color=#f800f8>"</FONT>,<FONT color=#f800f8>"</FONT><FONT color=#f800f8>testpassword</FONT><FONT color=#f800f8>"</FONT>);
<B><FONT color=#a02828>my</FONT></B> <FONT color=#008888>$sth</FONT>=<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>prepare</FONT>(<FONT color=#f800f8>"</FONT><FONT color=#f800f8>select * from my_table</FONT><FONT color=#f800f8>"</FONT>);
<FONT color=#008888>$sth</FONT>-><FONT color=#008888>execute</FONT>();
<B><FONT color=#a02828>for</FONT></B> (<FONT color=#008888>$i</FONT>=<FONT color=#f800f8>1</FONT>; <FONT color=#008888>$i</FONT><=<FONT color=#008888>$sth</FONT>->{<FONT color=#008888>NUM_OF_FIELDS</FONT>}; <FONT color=#008888>$i</FONT>++) {
<B><FONT color=#a02828>print</FONT></B> <FONT color=#f800f8>"</FONT><FONT color=#f800f8>Column </FONT><FONT color=#008888>$i</FONT><FONT color=#f800f8>: </FONT><FONT color=#008888>$sth</FONT><FONT color=#f800f8>->{NAME}->[i-1]</FONT><FONT color=#6858c8>\n</FONT><FONT color=#f800f8>"</FONT>;
}
<FONT color=#008888>$dbh</FONT>-><FONT color=#008888>disconnect</FONT>;
</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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>-><font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">begin testproc(:in1,:in2,:in3); end;</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
</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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>-><font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">exec testproc</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
</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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">execute procedure testproc ?, ?, ?</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
</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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">call testproc(?,?,?)</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
</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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">select testproc(:in1,:in2,:in3)</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
</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>In Oracle, stored procedures can return values through output parameters or
as return values of the procedure itself.</p>
<p>Here is an example where the procedure itself returns a value. Note that
Oracle calls these functions.</p>
<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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">select testproc(:in1,:in2,:in3) from dual</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$result</font>;
<font color="#008a8c">$sth</font>->bind_columns(<font color="#a52829"><b>undef</b></font>,<font color="#008a8c">\$result</font>);
<font color="#008a8c">$sth</font>->fetch();
</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>
<p>Here is an example where the value is returned through an output
parameter.</p>
<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>, out1 <font color="#a52829"><b>out</b></font> <font color="#298a52"><b>number</b></font>) <font color="#6b59ce">as</font>
<font color="#6b59ce">begin</font>
out1:=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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">begin testproc(:in1,:in2,:in3,:out1); end;</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$result</font>;
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">out1</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$result</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->execute();
</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>In Sybase and Microsoft SQL Server, stored procedures return values
through output parameters rather than as return values of the procedure
itself.</p>
<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>), @out1 int output <font color="#6b59ce">as</font>
<font color="#a52829"><b>select</b></font> @out1=convert(<font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>),@in1)
</pre>
</blockquote>
<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>
<blockquote>
<pre>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dth</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">exec testproc</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$result</font>;
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">out1</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$result</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->execute();
</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>)) 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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dth</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">select * from testproc(?,?,?)</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$result</font>;
<font color="#008a8c">$sth</font>->bind_columns(<font color="#a52829"><b>undef</b></font>,<font color="#008a8c">\$result</font>);
<font color="#008a8c">$sth</font>->fetch();
</pre>
</blockquote>
<p>Alternatively, you can run a query like the following and receive the result
using an output bind variable. Note that in Interbase/Firebird, input and
output bind variable indices are distict from one another. The index of the
output bind variable is 1 rather than 4, even though there were 3 input bind
variables.</p>
<blockquote>
<pre>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">execute procedure testproc ?, ?, ?</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$result</font>;
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$result</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->execute();
</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.</p>
<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>), <font color="#a52829"><b>out</b></font> out1 int) language sql
<font color="#6b59ce">begin</font>
<font color="#a52829"><b>set</b></font> out1 = 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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">call testproc(?,?,?,?)</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$result</font>;
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">4</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$result</font>,<font color="#ff00ff">25</font>);
<font color="#008a8c">$sth</font>->execute();
</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> 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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">select * from testfunc(:in1,:in2,:in3)</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">4</font>,<font color="#ff00ff">2</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$result</font>;
<font color="#008a8c">$sth</font>->bind_columns(<font color="#a52829"><b>undef</b></font>,<font color="#008a8c">\$result</font>);
<font color="#008a8c">$sth</font>->fetch();
</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.</p>
<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>, out1 <font color="#a52829"><b>out</b></font> <font color="#298a52"><b>number</b></font>, out2 <font color="#a52829"><b>out</b></font> <font color="#298a52"><b>number</b></font>, out3 <font color="#a52829"><b>out</b></font> <font color="#298a52"><b>varchar2</b></font>) <font color="#6b59ce">is</font>
<font color="#6b59ce">begin</font>
out1:=in1;
out2:=in2;
out3:=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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">begin testproc(:in1,:in2,:in3,:out1,:out2,:out3); end;</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out1</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out2</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out3</font>;
<font color="#008a8c">$sth</font>->bind_input_param(<font color="#ff00ff">"</font><font color="#ff00ff">out1</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out1</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->bind_input_param(<font color="#ff00ff">"</font><font color="#ff00ff">out2</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out2</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->bind_input_param(<font color="#ff00ff">"</font><font color="#ff00ff">out3</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out3</font>,<font color="#ff00ff">20</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>), @out1 int output, @out2 int output, @out3 int output <font color="#6b59ce">as</font>
<font color="#a52829"><b>select</b></font> @out1=convert(<font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>),@in1),
@out2=convert(<font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>),@in2),
@out2=convert(<font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>),@in2)
</pre>
</blockquote>
<p>To execute the stored procedure from an SQL Relay program, use code like the
following.</p>
<blockquote>
<pre>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dth</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">exec testproc</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out1</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out2</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out3</font>;
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">out1</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out1</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">out2</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out2</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">out3</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out3</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->execute();
</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>)) 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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dth</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">select * from testproc(?,?,?)</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out1</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out2</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out3</font>;
<font color="#008a8c">$sth</font>->bind_columns(<font color="#a52829"><b>undef</b></font>,<font color="#008a8c">\$out1</font>,<font color="#008a8c">\$out1</font>,<font color="#008a8c">\$out3</font>);
<font color="#008a8c">$sth</font>->fetch();
</pre>
</blockquote>
<p>Alternatively, you can run a query like the following and receive the result
using a output bind variables. Note that in Interbase/Firebird, input and
output bind variable indices are distict from one another. The index of the
first output bind variable is 1 rather than 4, even though there were 3 input
bind variables.</p>
<blockquote>
<pre>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">execute procedure testproc ?, ?, ?</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out1</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out2</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out3</font>;
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out1</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out2</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out3</font>,<font color="#ff00ff">20</font>);
<font color="#008a8c">$sth</font>->execute();
</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>), <font color="#a52829"><b>out</b></font> out1 int, <font color="#a52829"><b>out</b></font> out2 double, <font color="#a52829"><b>out</b></font> out3 <font color="#298a52"><b>varchar</b></font>(<font color="#ff00ff">20</font>)) language sql
<font color="#6b59ce">begin</font>
<font color="#a52829"><b>set</b></font> out1 = in1;
<font color="#a52829"><b>set</b></font> out2 = in2;
<font color="#a52829"><b>set</b></font> out3 = 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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">call testproc(?,?,?,?,?,?)</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">2</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out1</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out2</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out3</font>;
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">4</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out1</font>,<font color="#ff00ff">25</font>);
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">5</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out2</font>,<font color="#ff00ff">25</font>);
<font color="#008a8c">$sth</font>->bind_inout_param(<font color="#ff00ff">"</font><font color="#ff00ff">6</font><font color="#ff00ff">"</font>,<font color="#008a8c">\$out3</font>,<font color="#ff00ff">25</font>);
<font color="#008a8c">$sth</font>->execute();
</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> 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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">select * from testfunc(:in1,:in2,:in3) as (col1 int, col2 float, col3 char(20))</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in1</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in2</font><font color="#ff00ff">"</font>,<font color="#ff00ff">1.1</font>,<font color="#ff00ff">4</font>,<font color="#ff00ff">2</font>);
<font color="#008a8c">$sth</font>->bind_param(<font color="#ff00ff">"</font><font color="#ff00ff">in3</font><font color="#ff00ff">"</font>,<font color="#ff00ff">"</font><font color="#ff00ff">hello</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out1</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out2</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$out3</font>;
<font color="#008a8c">$sth</font>->bind_columns(<font color="#a52829"><b>undef</b></font>,<font color="#008a8c">\$out1</font>,<font color="#008a8c">\$out2</font>,<font color="#008a8c">\$out3</font>);
<font color="#008a8c">$sth</font>->fetch();
</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 driver for Perl DBI does
not currently support output bind cursors.</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>
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$sth</font>=<font color="#008a8c">$dbh</font>->prepare(<font color="#ff00ff">"</font><font color="#ff00ff">select * from testfunc() as (testint int, testfloat float, testchar char(40))</font><font color="#ff00ff">"</font>);
<font color="#008a8c">$sth</font>->execute();
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$col1</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$col2</font>;
<font color="#a52829"><b>my</b></font> <font color="#008a8c">$col3</font>;
<font color="#008a8c">$sth</font>->bind_columns(<font color="#a52829"><b>undef</b></font>,<font color="#008a8c">\$col1</font>,<font color="#008a8c">\$col2</font>,<font color="#008a8c">\$col3</font>);
<font color="#a52829"><b>while</b></font> (<font color="#008a8c">$sth</font>->fetch()) {
<font color="#a52829"><b>print</b></font> <font color="#ff00ff">"</font><font color="#008a8c">$col</font><font color="#ff00ff">, </font><font color="#008a8c">$col2</font><font color="#ff00ff">, </font><font color="#008a8c">$col3</font><font color="#ff00ff">, </font><font color="#008a8c">$col4</font><font color="#6b59ce">\n</font><font color="#ff00ff">"</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">function</font> testfunc
</pre>
</blockquote>
</body>
</html>
|