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 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307
|
/*-----------------------------------------------------------------------------
* Copyright (c) 2020, 2022, Oracle and/or its affiliates.
*
* This software is dual-licensed to you under the Universal Permissive License
* (UPL) 1.0 as shown at https://oss.oracle.com/licenses/upl and Apache License
* 2.0 as shown at http://www.apache.org/licenses/LICENSE-2.0. You may choose
* either license.*
*
* If you elect to accept the software under the Apache License, Version 2.0,
* the following applies:
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
* You may obtain a copy of the License at
*
* https://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*---------------------------------------------------------------------------*/
/*-----------------------------------------------------------------------------
* create_schema.sql
*
* Performs the actual work of creating and populating the schemas with the
* database objects used by the python-oracledb test suite. It is executed by
* the Python script create_schema.py.
*---------------------------------------------------------------------------*/
alter session set nls_date_format = 'YYYY-MM-DD HH24:MI:SS'
/
alter session set nls_numeric_characters='.,'
/
create user &main_user identified by &main_password
/
create user &proxy_user identified by &proxy_password
/
alter user &proxy_user grant connect through &main_user
/
grant create session to &proxy_user
/
grant
create session,
create table,
create procedure,
create type,
create view,
select any dictionary,
change notification,
unlimited tablespace
to &main_user
/
grant aq_administrator_role to &main_user
/
begin
for r in
( select role
from dba_roles
where role in ('SODA_APP')
) loop
execute immediate 'grant ' || r.role || ' to &main_user';
end loop;
end;
/
-- create types
create type &main_user..udt_SubObject as object (
SubNumberValue number,
SubStringValue varchar2(60)
);
/
create type &main_user..udt_ObjectArray as
varray(10) of &main_user..udt_SubObject;
/
create type &main_user..udt_Object as object (
NumberValue number,
StringValue varchar2(60),
FixedCharValue char(10),
NStringValue nvarchar2(60),
NFixedCharValue nchar(10),
RawValue raw(16),
IntValue integer,
SmallIntValue smallint,
RealValue real,
DoublePrecisionValue double precision,
FloatValue float,
BinaryFloatValue binary_float,
BinaryDoubleValue binary_double,
DateValue date,
TimestampValue timestamp,
TimestampTZValue timestamp with time zone,
TimestampLTZValue timestamp with local time zone,
CLOBValue clob,
NCLOBValue nclob,
BLOBValue blob,
SubObjectValue &main_user..udt_SubObject,
SubObjectArray &main_user..udt_ObjectArray
);
/
create type &main_user..udt_Array as varray(10) of number;
/
create or replace type &main_user..udt_Building as object (
BuildingId number(9),
NumFloors number(3),
Description varchar2(60),
DateBuilt date
);
/
create or replace type &main_user..udt_Book as object (
Title varchar2(100),
Authors varchar2(100),
Price number(5,2)
);
/
-- create tables
create table &main_user..TestNumbers (
IntCol number(9) not null,
LongIntCol number(16) not null,
NumberCol number(9, 2) not null,
FloatCol float not null,
UnconstrainedCol number not null,
NullableCol number(38)
)
/
create table &main_user..TestStrings (
IntCol number(9) not null,
StringCol varchar2(20) not null,
RawCol raw(30) not null,
FixedCharCol char(40) not null,
NullableCol varchar2(50)
)
/
create table &main_user..TestUnicodes (
IntCol number(9) not null,
UnicodeCol nvarchar2(20) not null,
FixedUnicodeCol nchar(40) not null,
NullableCol nvarchar2(50)
)
/
create table &main_user..TestDates (
IntCol number(9) not null,
DateCol date not null,
NullableCol date
)
/
create table &main_user..TestCLOBs (
IntCol number(9) not null,
CLOBCol clob not null,
ExtraNumCol1 number(9),
ExtraCLOBCol1 clob,
ExtraNumCol2 number(9),
ExtraCLOBCol2 clob
)
/
create table &main_user..TestNCLOBs (
IntCol number(9) not null,
NCLOBCol nclob not null,
ExtraNumCol1 number(9),
ExtraNCLOBCol1 nclob,
ExtraNumCol2 number(9),
ExtraNCLOBCol2 nclob
)
/
create table &main_user..TestBLOBs (
IntCol number(9) not null,
BLOBCol blob not null,
ExtraNumCol1 number(9),
ExtraBLOBCol1 blob,
ExtraNumCol2 number(9),
ExtraBLOBCol2 blob
)
/
create table &main_user..TestXML (
IntCol number(9) not null,
XMLCol xmltype not null
)
/
create table &main_user..TestTempXML (
IntCol number(9) not null,
XMLCol xmltype not null
)
/
create table &main_user..TestLongs (
IntCol number(9) not null,
LongCol long
) nocompress
/
create table &main_user..TestLongRaws (
IntCol number(9) not null,
LongRawCol long raw
) nocompress
/
create table &main_user..TestTempTable (
IntCol number(9) not null,
StringCol1 varchar2(400),
StringCol2 varchar2(400),
NumberCol number(25,2),
constraint TestTempTable_pk primary key (IntCol)
)
/
create table &main_user..TestArrayDML (
IntCol number(9) not null,
StringCol varchar2(100),
IntCol2 number(3),
constraint TestArrayDML_pk primary key (IntCol)
)
/
create table &main_user..TestObjects (
IntCol number(9) not null,
ObjectCol &main_user..udt_Object,
ArrayCol &main_user..udt_Array
)
/
create table &main_user..TestTimestamps (
IntCol number(9) not null,
TimestampCol timestamp not null,
NullableCol timestamp
)
/
create table &main_user..TestTimestampLTZs (
IntCol number(9) not null,
TimestampLTZCol timestamp with local time zone not null,
NullableCol timestamp with local time zone
)
/
create table &main_user..TestTimestampTZs (
IntCol number(9) not null,
TimestampTZCol timestamp with time zone not null,
NullableCol timestamp with time zone
)
/
create table &main_user..TestIntervals (
IntCol number(9) not null,
IntervalCol interval day to second not null,
NullableCol interval day to second
)
/
create table &main_user..TestUniversalRowids (
IntCol number(9) not null,
StringCol varchar2(250) not null,
DateCol date not null,
constraint TestUniversalRowids_pk primary key (IntCol, StringCol, DateCol)
) organization index
/
create table &main_user..TestBuildings (
BuildingId number(9) not null,
BuildingObj &main_user..udt_Building not null
)
/
create table &main_user..TestRowids (
IntCol number(9) not null,
RowidCol rowid,
URowidCol urowid
)
/
create table &main_user..PlsqlSessionCallbacks (
RequestedTag varchar2(250),
ActualTag varchar2(250),
FixupTimestamp timestamp
)
/
declare
t_Version number;
begin
select to_number(substr(version, 1, instr(version, '.') - 1))
into t_Version
from product_component_version
where product like 'Oracle Database%';
if t_Version >= 21 then
execute immediate 'create table &main_user..TestJson (' ||
' IntCol number(9) not null,' ||
' JsonCol json not null' ||
')';
end if;
end;
/
-- create queue table and queues for testing advanced queuing
declare
t_Version number;
begin
select to_number(substr(version, 1, instr(version, '.') - 1))
into t_Version
from product_component_version
where product like 'Oracle Database%';
dbms_aqadm.create_queue_table('&main_user..BOOK_QUEUE_TAB',
'&main_user..UDT_BOOK');
dbms_aqadm.create_queue('&main_user..TEST_BOOK_QUEUE',
'&main_user..BOOK_QUEUE_TAB');
dbms_aqadm.start_queue('&main_user..TEST_BOOK_QUEUE');
dbms_aqadm.create_queue_table('&main_user..RAW_QUEUE_TAB', 'RAW');
dbms_aqadm.create_queue('&main_user..TEST_RAW_QUEUE',
'&main_user..RAW_QUEUE_TAB');
dbms_aqadm.start_queue('&main_user..TEST_RAW_QUEUE');
dbms_aqadm.create_queue_table('&main_user..BOOK_QUEUE_MULTI_TAB',
'&main_user..UDT_BOOK', multiple_consumers => TRUE);
dbms_aqadm.create_queue('&main_user..BOOK_QUEUE_MULTI',
'&main_user..BOOK_QUEUE_MULTI_TAB');
dbms_aqadm.start_queue('&main_user..BOOK_QUEUE_MULTI');
dbms_aqadm.add_subscriber('&main_user..BOOK_QUEUE_MULTI',
sys.aq$_agent('Sub1', null, null));
if t_Version >= 21 then
dbms_aqadm.create_queue_table('&main_user..JSON_QUEUE_TAB', 'JSON');
dbms_aqadm.create_queue('&main_user..TEST_JSON_QUEUE',
'&main_user..JSON_QUEUE_TAB');
dbms_aqadm.start_queue('&main_user..TEST_JSON_QUEUE');
end if;
end;
/
-- create transformations
begin
dbms_transform.create_transformation('&main_user', 'transform1',
'&main_user', 'UDT_BOOK', '&main_user', 'UDT_BOOK',
'&main_user..UDT_BOOK(source.user_data.TITLE, ' ||
'source.user_data.AUTHORS, source.user_data.PRICE + 5)');
dbms_transform.create_transformation('&main_user', 'transform2',
'&main_user', 'UDT_BOOK', '&main_user', 'UDT_BOOK',
'&main_user..UDT_BOOK(source.user_data.TITLE, ' ||
'source.user_data.AUTHORS, source.user_data.PRICE + 10)');
end;
/
-- populate tables
begin
for i in 1..10 loop
insert into &main_user..TestNumbers
values (i, power(38, i), i + i * 0.25, i + i * .75, i * i * i + i *.5,
decode(mod(i, 2), 0, null, power(143, i)));
end loop;
end;
/
declare
t_RawValue raw(30);
function ConvertHexDigit(a_Value number) return varchar2 is
begin
if a_Value between 0 and 9 then
return to_char(a_Value);
end if;
return chr(ascii('A') + a_Value - 10);
end;
function ConvertToHex(a_Value varchar2) return varchar2 is
t_HexValue varchar2(60);
t_Digit number;
begin
for i in 1..length(a_Value) loop
t_Digit := ascii(substr(a_Value, i, 1));
t_HexValue := t_HexValue ||
ConvertHexDigit(trunc(t_Digit / 16)) ||
ConvertHexDigit(mod(t_Digit, 16));
end loop;
return t_HexValue;
end;
begin
for i in 1..10 loop
t_RawValue := hextoraw(ConvertToHex('Raw ' || to_char(i)));
insert into &main_user..TestStrings
values (i, 'String ' || to_char(i), t_RawValue,
'Fixed Char ' || to_char(i),
decode(mod(i, 2), 0, null, 'Nullable ' || to_char(i)));
end loop;
end;
/
begin
for i in 1..10 loop
insert into &main_user..TestUnicodes
values (i, 'Unicode ' || unistr('\3042') || ' ' || to_char(i),
'Fixed Unicode ' || to_char(i),
decode(mod(i, 2), 0, null, unistr('Nullable ') || to_char(i)));
end loop;
end;
/
begin
for i in 1..10 loop
insert into &main_user..TestDates
values (i, to_date(20021209, 'YYYYMMDD') + i + i * .1,
decode(mod(i, 2), 0, null,
to_date(20021209, 'YYYYMMDD') + i + i + i * .15));
end loop;
end;
/
begin
for i in 1..100 loop
insert into &main_user..TestXML
values (i, '<?xml version="1.0"?><records>' ||
dbms_random.string('x', 1024) || '</records>');
end loop;
end;
/
begin
for i in 1..10 loop
insert into &main_user..TestTimestamps
values (i, to_timestamp('20021209', 'YYYYMMDD') +
to_dsinterval(to_char(i) || ' 00:00:' || to_char(i * 2) ||
'.' || to_char(i * 50)),
decode(mod(i, 2), 0, to_timestamp(null, 'YYYYMMDD'),
to_timestamp('20021209', 'YYYYMMDD') +
to_dsinterval(to_char(i + 1) || ' 00:00:' ||
to_char(i * 3) || '.' || to_char(i * 125))));
end loop;
end;
/
begin
for i in 1..10 loop
insert into &main_user..TestTimestampLTZs
values (i, to_timestamp_tz('20220602 ' ||
decode(mod(i, 2), 0, '-', '+') ||
ltrim(to_char(i, '00')) || ':' ||
decode(mod(i, 4), 0, '00', '30'), 'YYYYMMDD TZH:TZM') +
to_dsinterval(to_char(i) || ' 00:00:' || to_char(i * 2) ||
'.' || to_char(i * 50)),
decode(mod(i, 2), 0, to_timestamp(null, 'YYYYMMDD'),
to_timestamp_tz('20220602 00:00', 'YYYYMMDD TZH:TZM') +
to_dsinterval(to_char(i + 1) || ' 00:00:' ||
to_char(i * 3) || '.' || to_char(i * 125))));
end loop;
end;
/
begin
for i in 1..10 loop
insert into &main_user..TestTimestampTZs
values (i, to_timestamp_tz('20220603 ' ||
decode(mod(i, 2), 0, '-', '+') ||
ltrim(to_char(i, '00')) || ':' ||
decode(mod(i, 4), 0, '00', '30'), 'YYYYMMDD TZH:TZM') +
to_dsinterval(to_char(i) || ' 00:00:' || to_char(i * 2) ||
'.' || to_char(i * 50)),
decode(mod(i, 2), 0, to_timestamp(null, 'YYYYMMDD'),
to_timestamp_tz('20220603 00:00', 'YYYYMMDD TZH:TZM') +
to_dsinterval(to_char(i + 1) || ' 00:00:' ||
to_char(i * 3) || '.' || to_char(i * 125))));
end loop;
end;
/
begin
for i in 1..10 loop
insert into &main_user..TestIntervals
values (i, to_dsinterval(to_char(i) || ' ' || to_char(i) || ':' ||
to_char(i * 2) || ':' || to_char(i * 3)),
decode(mod(i, 2), 0, to_dsinterval(null),
to_dsinterval(to_char(i + 5) || ' ' || to_char(i + 2) || ':' ||
to_char(i * 2 + 5) || ':' || to_char(i * 3 + 5))));
end loop;
end;
/
insert into &main_user..TestObjects values (1,
&main_user..udt_Object(1, 'First row', 'First', 'N First Row', 'N First',
'52617720446174612031', 2, 5, 12.125, 0.5, 12.5, 25.25, 50.125,
to_date(20070306, 'YYYYMMDD'),
to_timestamp('20080912 16:40:00', 'YYYYMMDD HH24:MI:SS'),
to_timestamp_tz('20091013 17:50:00 00:00',
'YYYYMMDD HH24:MI:SS TZH:TZM'),
to_timestamp_tz('20101114 18:55:00 00:00',
'YYYYMMDD HH24:MI:SS TZH:TZM'),
'Short CLOB value', 'Short NCLOB Value',
utl_raw.cast_to_raw('Short BLOB value'),
&main_user..udt_SubObject(11, 'Sub object 1'),
&main_user..udt_ObjectArray(
&main_user..udt_SubObject(5, 'first element'),
&main_user..udt_SubObject(6, 'second element'))),
&main_user..udt_Array(5, 10, null, 20))
/
insert into &main_user..TestObjects values (2, null,
&main_user..udt_Array(3, null, 9, 12, 15))
/
insert into &main_user..TestObjects values (3,
&main_user..udt_Object(3, 'Third row', 'Third', 'N Third Row', 'N Third',
'52617720446174612033', 4, 10, 6.5, 0.75, 43.25, 86.5, 192.125,
to_date(20070621, 'YYYYMMDD'),
to_timestamp('20071213 07:30:45', 'YYYYMMDD HH24:MI:SS'),
to_timestamp_tz('20170621 23:18:45 00:00',
'YYYYMMDD HH24:MI:SS TZH:TZM'),
to_timestamp_tz('20170721 08:27:13 00:00',
'YYYYMMDD HH24:MI:SS TZH:TZM'),
'Another short CLOB value', 'Another short NCLOB Value',
utl_raw.cast_to_raw('Yet another short BLOB value'),
&main_user..udt_SubObject(13, 'Sub object 3'),
&main_user..udt_ObjectArray(
&main_user..udt_SubObject(10, 'element #1'),
&main_user..udt_SubObject(20, 'element #2'),
&main_user..udt_SubObject(30, 'element #3'),
&main_user..udt_SubObject(40, 'element #4'))), null)
/
commit
/
-- create procedures for testing callproc()
create procedure &main_user..proc_Test (
a_InValue varchar2,
a_InOutValue in out number,
a_OutValue out number
) as
begin
a_InOutValue := a_InOutValue * length(a_InValue);
a_OutValue := length(a_InValue);
end;
/
create procedure &main_user..proc_TestNoArgs as
begin
null;
end;
/
-- create procedure for testing refcursor
create procedure &main_user..myrefcursorproc (
a_RefCursor out sys_refcursor
) as
begin
open a_RefCursor for
select *
from TestTempTable;
end;
/
-- create functions for testing callfunc()
create function &main_user..func_Test (
a_String varchar2,
a_ExtraAmount number
) return number as
begin
return length(a_String) + a_ExtraAmount;
end;
/
create function &main_user..func_TestNoArgs
return number as
begin
return 712;
end;
/
-- create packages
create or replace package &main_user..pkg_TestStringArrays as
type udt_StringList is table of varchar2(100) index by binary_integer;
function TestInArrays (
a_StartingLength number,
a_Array udt_StringList
) return number;
procedure TestInOutArrays (
a_NumElems number,
a_Array in out nocopy udt_StringList
);
procedure TestOutArrays (
a_NumElems number,
a_Array out nocopy udt_StringList
);
procedure TestIndexBy (
a_Array out nocopy udt_StringList
);
end;
/
create or replace package body &main_user..pkg_TestStringArrays as
function TestInArrays (
a_StartingLength number,
a_Array udt_StringList
) return number is
t_Length number;
begin
t_Length := a_StartingLength;
for i in 1..a_Array.count loop
t_Length := t_Length + length(a_Array(i));
end loop;
return t_Length;
end;
procedure TestInOutArrays (
a_NumElems number,
a_Array in out udt_StringList
) is
begin
for i in 1..a_NumElems loop
a_Array(i) := 'Converted element # ' ||
to_char(i) || ' originally had length ' ||
to_char(length(a_Array(i)));
end loop;
end;
procedure TestOutArrays (
a_NumElems number,
a_Array out udt_StringList
) is
begin
for i in 1..a_NumElems loop
a_Array(i) := 'Test out element # ' || to_char(i);
end loop;
end;
procedure TestIndexBy (
a_Array out nocopy udt_StringList
) is
begin
a_Array(-1048576) := 'First element';
a_Array(-576) := 'Second element';
a_Array(284) := 'Third element';
a_Array(8388608) := 'Fourth element';
end;
end;
/
create or replace package &main_user..pkg_TestUnicodeArrays as
type udt_UnicodeList is table of nvarchar2(100) index by binary_integer;
function TestInArrays (
a_StartingLength number,
a_Array udt_UnicodeList
) return number;
procedure TestInOutArrays (
a_NumElems number,
a_Array in out nocopy udt_UnicodeList
);
procedure TestOutArrays (
a_NumElems number,
a_Array out nocopy udt_UnicodeList
);
end;
/
create or replace package body &main_user..pkg_TestUnicodeArrays as
function TestInArrays (
a_StartingLength number,
a_Array udt_UnicodeList
) return number is
t_Length number;
begin
t_Length := a_StartingLength;
for i in 1..a_Array.count loop
t_Length := t_Length + length(a_Array(i));
end loop;
return t_Length;
end;
procedure TestInOutArrays (
a_NumElems number,
a_Array in out udt_UnicodeList
) is
begin
for i in 1..a_NumElems loop
a_Array(i) := unistr('Converted element ' || unistr('\3042') ||
' # ') || to_char(i) || ' originally had length ' ||
to_char(length(a_Array(i)));
end loop;
end;
procedure TestOutArrays (
a_NumElems number,
a_Array out udt_UnicodeList
) is
begin
for i in 1..a_NumElems loop
a_Array(i) := unistr('Test out element ') || unistr('\3042') ||
' # ' || to_char(i);
end loop;
end;
end;
/
create or replace package &main_user..pkg_TestNumberArrays as
type udt_NumberList is table of number index by binary_integer;
function TestInArrays (
a_StartingValue number,
a_Array udt_NumberList
) return number;
procedure TestInOutArrays (
a_NumElems number,
a_Array in out nocopy udt_NumberList
);
procedure TestOutArrays (
a_NumElems number,
a_Array out nocopy udt_NumberList
);
end;
/
create or replace package body &main_user..pkg_TestNumberArrays as
function TestInArrays (
a_StartingValue number,
a_Array udt_NumberList
) return number is
t_Value number;
begin
t_Value := a_StartingValue;
for i in 1..a_Array.count loop
t_Value := t_Value + a_Array(i);
end loop;
return t_Value;
end;
procedure TestInOutArrays (
a_NumElems number,
a_Array in out udt_NumberList
) is
begin
for i in 1..a_NumElems loop
a_Array(i) := a_Array(i) * 10;
end loop;
end;
procedure TestOutArrays (
a_NumElems number,
a_Array out udt_NumberList
) is
begin
for i in 1..a_NumElems loop
a_Array(i) := i * 100;
end loop;
end;
end;
/
create or replace package &main_user..pkg_TestDateArrays as
type udt_DateList is table of date index by binary_integer;
function TestInArrays (
a_StartingValue number,
a_BaseDate date,
a_Array udt_DateList
) return number;
procedure TestInOutArrays (
a_NumElems number,
a_Array in out nocopy udt_DateList
);
procedure TestOutArrays (
a_NumElems number,
a_Array out nocopy udt_DateList
);
end;
/
create or replace package body &main_user..pkg_TestDateArrays as
function TestInArrays (
a_StartingValue number,
a_BaseDate date,
a_Array udt_DateList
) return number is
t_Value number;
begin
t_Value := a_StartingValue;
for i in 1..a_Array.count loop
t_Value := t_Value + a_Array(i) - a_BaseDate;
end loop;
return t_Value;
end;
procedure TestInOutArrays (
a_NumElems number,
a_Array in out udt_DateList
) is
begin
for i in 1..a_NumElems loop
a_Array(i) := a_Array(i) + 7;
end loop;
end;
procedure TestOutArrays (
a_NumElems number,
a_Array out udt_DateList
) is
begin
for i in 1..a_NumElems loop
a_Array(i) := to_date(20021212, 'YYYYMMDD') + i * 1.2;
end loop;
end;
end;
/
create or replace package &main_user..pkg_TestRefCursors as
procedure TestOutCursor (
a_MaxIntValue number,
a_Cursor out sys_refcursor
);
function TestInCursor (
a_Cursor sys_refcursor
) return varchar2;
function TestReturnCursor (
a_MaxIntValue number
) return sys_refcursor;
procedure TestLobCursor (
a_Value varchar2,
a_Cursor out sys_refcursor
);
procedure TestCloseCursor (
a_Cursor sys_refcursor
);
end;
/
create or replace package body &main_user..pkg_TestRefCursors as
procedure TestOutCursor (
a_MaxIntValue number,
a_Cursor out sys_refcursor
) is
begin
open a_Cursor for
select
IntCol,
StringCol
from TestStrings
where IntCol <= a_MaxIntValue
order by IntCol;
end;
function TestInCursor (
a_Cursor sys_refcursor
) return varchar2 is
t_String varchar2(100);
begin
fetch a_Cursor into t_String;
return t_String || ' (Modified)';
end;
function TestReturnCursor (
a_MaxIntValue number
) return sys_refcursor is
t_Cursor sys_refcursor;
begin
open t_Cursor for
select
IntCol,
StringCol
from TestSTrings
where IntCol <= a_MaxIntValue
order by IntCol;
return t_Cursor;
end;
procedure TestLobCursor (
a_Value varchar2,
a_Cursor out sys_refcursor
) is
begin
open a_Cursor for
select to_clob(a_Value)
from dual;
end;
procedure TestCloseCursor (
a_Cursor sys_refcursor
) is
t_Id number;
t_StrVal varchar2(400);
begin
delete from TestTempTable;
fetch a_Cursor into t_Id, t_StrVal;
if not a_Cursor%notfound then
insert into TestTempTable (IntCol, StringCol1)
values (t_Id, t_StrVal);
end if;
close a_Cursor;
commit;
end;
end;
/
create or replace package &main_user..pkg_TestBooleans as
type udt_BooleanList is table of boolean index by binary_integer;
function GetStringRep (
a_Value boolean
) return varchar2;
function IsLessThan10 (
a_Value number
) return boolean;
function TestInArrays (
a_Value udt_BooleanList
) return number;
procedure TestOutArrays (
a_NumElements number,
a_Value out nocopy udt_BooleanList
);
end;
/
create or replace package body &main_user..pkg_TestBooleans as
function GetStringRep (
a_Value boolean
) return varchar2 is
begin
if a_Value is null then
return 'NULL';
elsif a_Value then
return 'TRUE';
end if;
return 'FALSE';
end;
function IsLessThan10 (
a_Value number
) return boolean is
begin
return a_Value < 10;
end;
function TestInArrays (
a_Value udt_BooleanList
) return number is
t_Result pls_integer;
begin
t_Result := 0;
for i in 1..a_Value.count loop
if a_Value(i) then
t_Result := t_Result + 1;
end if;
end loop;
return t_Result;
end;
procedure TestOutArrays (
a_NumElements number,
a_Value out nocopy udt_BooleanList
) is
begin
for i in 1..a_NumElements loop
a_Value(i) := (mod(i, 2) = 1);
end loop;
end;
end;
/
create or replace package &main_user..pkg_TestBindObject as
function GetStringRep (
a_Object udt_Object
) return varchar2;
procedure BindObjectOut (
a_NumberValue number,
a_StringValue varchar2,
a_Object out nocopy udt_Object
);
end;
/
create or replace package body &main_user..pkg_TestBindObject as
function GetStringRep (
a_Object udt_SubObject
) return varchar2 is
begin
if a_Object is null then
return 'null';
end if;
return 'udt_SubObject(' ||
nvl(to_char(a_Object.SubNumberValue), 'null') || ', ' ||
case when a_Object.SubStringValue is null then 'null'
else '''' || a_Object.SubStringValue || '''' end || ')';
end;
function GetStringRep (
a_Array udt_ObjectArray
) return varchar2 is
t_StringRep varchar2(4000);
begin
if a_Array is null then
return 'null';
end if;
t_StringRep := 'udt_ObjectArray(';
for i in 1..a_Array.count loop
if i > 1 then
t_StringRep := t_StringRep || ', ';
end if;
t_StringRep := t_StringRep || GetStringRep(a_Array(i));
end loop;
return t_StringRep || ')';
end;
function GetStringRep (
a_Object udt_Object
) return varchar2 is
begin
if a_Object is null then
return 'null';
end if;
return 'udt_Object(' ||
nvl(to_char(a_Object.NumberValue), 'null') || ', ' ||
case when a_Object.StringValue is null then 'null'
else '''' || a_Object.StringValue || '''' end || ', ' ||
case when a_Object.FixedCharValue is null then 'null'
else '''' || a_Object.FixedCharValue || '''' end || ', ' ||
case when a_Object.DateValue is null then 'null'
else 'to_date(''' ||
to_char(a_Object.DateValue, 'YYYY-MM-DD') ||
''', ''YYYY-MM-DD'')' end || ', ' ||
case when a_Object.TimestampValue is null then 'null'
else 'to_timestamp(''' || to_char(a_Object.TimestampValue,
'YYYY-MM-DD HH24:MI:SS') ||
''', ''YYYY-MM-DD HH24:MI:SS'')' end || ', ' ||
GetStringRep(a_Object.SubObjectValue) || ', ' ||
GetStringRep(a_Object.SubObjectArray) || ')';
end;
procedure BindObjectOut (
a_NumberValue number,
a_StringValue varchar2,
a_Object out nocopy udt_Object
) is
begin
a_Object := udt_Object(a_NumberValue, a_StringValue, null, null, null,
null, null, null, null, null, null, null, null, null, null,
null, null, null, null, null, null, null);
end;
end;
/
create or replace package &main_user..pkg_TestRecords as
type udt_Record is record (
NumberValue number,
StringValue varchar2(30),
DateValue date,
TimestampValue timestamp,
BooleanValue boolean,
PlsIntegerValue pls_integer,
BinaryIntegerValue binary_integer
);
type udt_RecordArray is table of udt_Record index by binary_integer;
function GetStringRep (
a_Value udt_Record
) return varchar2;
procedure TestOut (
a_Value out nocopy udt_Record
);
function TestInArrays (
a_Value udt_RecordArray
) return varchar2;
end;
/
create or replace package body &main_user..pkg_TestRecords as
function GetStringRep (
a_Value udt_Record
) return varchar2 is
begin
return 'udt_Record(' ||
nvl(to_char(a_Value.NumberValue), 'null') || ', ' ||
case when a_Value.StringValue is null then 'null'
else '''' || a_Value.StringValue || '''' end || ', ' ||
case when a_Value.DateValue is null then 'null'
else 'to_date(''' ||
to_char(a_Value.DateValue, 'YYYY-MM-DD') ||
''', ''YYYY-MM-DD'')' end || ', ' ||
case when a_Value.TimestampValue is null then 'null'
else 'to_timestamp(''' || to_char(a_Value.TimestampValue,
'YYYY-MM-DD HH24:MI:SS') ||
''', ''YYYY-MM-DD HH24:MI:SS'')' end || ', ' ||
case when a_Value.BooleanValue is null then 'null'
when a_Value.BooleanValue then 'true'
else 'false' end || ', ' ||
nvl(to_char(a_Value.PlsIntegerValue), 'null') || ', ' ||
nvl(to_char(a_Value.BinaryIntegerValue), 'null') || ')';
end;
procedure TestOut (
a_Value out nocopy udt_Record
) is
begin
a_Value.NumberValue := 25;
a_Value.StringValue := 'String in record';
a_Value.DateValue := to_date(20160216, 'YYYYMMDD');
a_Value.TimestampValue := to_timestamp('20160216 18:23:55',
'YYYYMMDD HH24:MI:SS');
a_Value.BooleanValue := true;
a_Value.PlsIntegerValue := 45;
a_Value.BinaryIntegerValue := 10;
end;
function TestInArrays (
a_Value udt_RecordArray
) return varchar2 is
t_Result varchar2(4000);
begin
for i in 0..a_Value.count - 1 loop
if t_Result is not null then
t_Result := t_Result || '; ';
end if;
t_Result := t_Result || GetStringRep(a_Value(i));
end loop;
return t_Result;
end;
end;
/
create or replace package &main_user..pkg_SessionCallback as
procedure TheCallback (
a_RequestedTag varchar2,
a_ActualTag varchar2
);
end;
/
create or replace package body &main_user..pkg_SessionCallback as
type udt_Properties is table of varchar2(64) index by varchar2(64);
procedure LogCall (
a_RequestedTag varchar2,
a_ActualTag varchar2
) is
pragma autonomous_transaction;
begin
insert into PlsqlSessionCallbacks
values (a_RequestedTag, a_ActualTag, systimestamp);
commit;
end;
procedure ParseProperty (
a_Property varchar2,
a_Name out nocopy varchar2,
a_Value out nocopy varchar2
) is
t_Pos number;
begin
t_Pos := instr(a_Property, '=');
if t_Pos = 0 then
raise_application_error(-20000, 'Tag must contain key=value pairs');
end if;
a_Name := substr(a_Property, 1, t_Pos - 1);
a_Value := substr(a_Property, t_Pos + 1);
end;
procedure SetProperty (
a_Name varchar2,
a_Value varchar2
) is
t_ValidValues udt_Properties;
begin
if a_Name = 'TIME_ZONE' then
t_ValidValues('UTC') := 'UTC';
t_ValidValues('MST') := '-07:00';
elsif a_Name = 'NLS_DATE_FORMAT' then
t_ValidValues('SIMPLE') := 'YYYY-MM-DD HH24:MI';
t_ValidValues('FULL') := 'YYYY-MM-DD HH24:MI:SS';
else
raise_application_error(-20000, 'Unsupported session setting');
end if;
if not t_ValidValues.exists(a_Value) then
raise_application_error(-20000, 'Unsupported session setting');
end if;
execute immediate
'ALTER SESSION SET ' || a_Name || '=''' ||
t_ValidValues(a_Value) || '''';
end;
procedure ParseTag (
a_Tag varchar2,
a_Properties out nocopy udt_Properties
) is
t_PropertyName varchar2(64);
t_PropertyValue varchar2(64);
t_StartPos number;
t_EndPos number;
begin
t_StartPos := 1;
while t_StartPos < length(a_Tag) loop
t_EndPos := instr(a_Tag, ';', t_StartPos);
if t_EndPos = 0 then
t_EndPos := length(a_Tag) + 1;
end if;
ParseProperty(substr(a_Tag, t_StartPos, t_EndPos - t_StartPos),
t_PropertyName, t_PropertyValue);
a_Properties(t_PropertyName) := t_PropertyValue;
t_StartPos := t_EndPos + 1;
end loop;
end;
procedure TheCallback (
a_RequestedTag varchar2,
a_ActualTag varchar2
) is
t_RequestedProps udt_Properties;
t_ActualProps udt_Properties;
t_PropertyName varchar2(64);
begin
LogCall(a_RequestedTag, a_ActualTag);
ParseTag(a_RequestedTag, t_RequestedProps);
ParseTag(a_ActualTag, t_ActualProps);
t_PropertyName := t_RequestedProps.first;
while t_PropertyName is not null loop
if not t_ActualProps.exists(t_PropertyName) or
t_ActualProps(t_PropertyName) !=
t_RequestedProps(t_PropertyName) then
SetProperty(t_PropertyName, t_RequestedProps(t_PropertyName));
end if;
t_PropertyName := t_RequestedProps.next(t_PropertyName);
end loop;
end;
end;
/
|