-
Notifications
You must be signed in to change notification settings - Fork 58
/
procedure_spec.rb
2390 lines (2093 loc) · 77.7 KB
/
procedure_spec.rb
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
# encoding: utf-8
require "spec_helper"
describe "Parameter type mapping /" do
shared_examples "Function with string parameters" do |datatype|
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_uppercase
( p_string #{datatype} )
RETURN #{datatype}
IS
BEGIN
RETURN UPPER(p_string);
END test_uppercase;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_uppercase"
plsql.logoff
end
it "should find existing procedure" do
expect(PLSQL::Procedure.find(plsql, :test_uppercase)).not_to be_nil
end
it "should not find nonexisting procedure" do
expect(PLSQL::Procedure.find(plsql, :qwerty123456)).to be_nil
end
it "should execute function and return correct value" do
expect(plsql.test_uppercase("xxx")).to eq("XXX")
end
it "should execute function with named parameters and return correct value" do
expect(plsql.test_uppercase(p_string: "xxx")).to eq("XXX")
end
it "should raise error if wrong number of arguments is passed" do
expect { plsql.test_uppercase("xxx", "yyy") }.to raise_error(ArgumentError)
end
it "should raise error if wrong named argument is passed" do
expect { plsql.test_uppercase(p_string2: "xxx") }.to raise_error(ArgumentError)
end
it "should execute function with schema name specified" do
expect(plsql.hr.test_uppercase("xxx")).to eq("XXX")
end
it "should process nil parameter as NULL" do
expect(plsql.test_uppercase(nil)).to be_nil
end
end
["VARCHAR", "VARCHAR2"].each do |datatype|
describe "Function with #{datatype} parameters" do
it_should_behave_like "Function with string parameters", datatype
end
end
shared_examples "Function with numeric" do |ora_data_type, class_, num1, num2, expected, mandatory|
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_sum
( p_num1 #{ora_data_type}, p_num2 #{ora_data_type} )
RETURN #{ora_data_type}
IS
BEGIN
RETURN p_num1 + p_num2;
END test_sum;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_sum"
plsql.logoff
end
it "should get #{ora_data_type} variable type mapped to #{class_.to_s}" do
expect(plsql.test_sum(num1, num2)).to be_a class_
end
it "should process input parameters and return correct result" do
expect(plsql.test_sum(num1, num2)).to eq(expected)
end
it "should process nil parameter as NULL" do
expect(plsql.test_sum(num1, nil)).to be_nil
end unless mandatory
end
@big_number = ("1234567890" * 3).to_i
[
{ ora_data_type: "INTEGER", class: Integer, num1: @big_number, num2: @big_number, expected: @big_number * 2 },
{ ora_data_type: "NUMBER", class: BigDecimal, num1: 12345.12345, num2: 12345.12345, expected: 24690.2469 },
{ ora_data_type: "PLS_INTEGER", class: Integer, num1: 123456789, num2: 123456789, expected: 246913578 },
{ ora_data_type: "BINARY_INTEGER", class: Integer, num1: 123456789, num2: 123456789, expected: 246913578 },
{ ora_data_type: "SIMPLE_INTEGER", class: Integer, num1: 123456789, num2: 123456789, expected: 246913578, mandatory: true },
{ ora_data_type: "NATURAL", class: Integer, num1: 123456789, num2: 123456789, expected: 246913578 },
{ ora_data_type: "NATURALN", class: Integer, num1: 123456789, num2: 123456789, expected: 246913578, mandatory: true },
{ ora_data_type: "POSITIVE", class: Integer, num1: 123456789, num2: 123456789, expected: 246913578 },
{ ora_data_type: "POSITIVEN", class: Integer, num1: 123456789, num2: 123456789, expected: 246913578, mandatory: true },
{ ora_data_type: "SIGNTYPE", class: Integer, num1: 1, num2: -1, expected: 0 },
].each do |row|
ora_data_type, class_, num1, num2, expected, mandatory = row.values
describe ora_data_type do
include_examples "Function with numeric", ora_data_type, class_, num1, num2, expected, mandatory
end
end
describe "Boolean to NUMBER conversion" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_num ( p_num NUMBER) RETURN NUMBER
IS
BEGIN
RETURN p_num;
END test_num;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_num"
plsql.logoff
end
it "should convert true value to 1 for NUMBER parameter" do
expect(plsql.test_num(true)).to eq(1)
end
it "should convert false value to 0 for NUMBER parameter" do
expect(plsql.test_num(false)).to eq(0)
end
end
describe "Function with date parameters" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_date
( p_date DATE )
RETURN DATE
IS
BEGIN
RETURN p_date + 1;
END test_date;
SQL
end
before(:each) do
plsql.default_timezone = :local
end
after(:all) do
plsql.execute "DROP FUNCTION test_date"
plsql.logoff
end
it "should process Time parameters" do
now = Time.local(2008, 8, 12, 14, 28, 0)
expect(plsql.test_date(now)).to eq(now + 60 * 60 * 24)
end
it "should process UTC Time parameters" do
plsql.default_timezone = :utc
now = Time.utc(2008, 8, 12, 14, 28, 0)
expect(plsql.test_date(now)).to eq(now + 60 * 60 * 24)
end
it "should process DateTime parameters" do
now = DateTime.parse(Time.local(2008, 8, 12, 14, 28, 0).iso8601)
result = plsql.test_date(now)
expect(result.class).to eq(Time)
expect(result).to eq(Time.parse((now + 1).strftime("%c")))
end
it "should process old DateTime parameters" do
now = DateTime.civil(1901, 1, 1, 12, 0, 0, plsql.local_timezone_offset)
result = plsql.test_date(now)
expect(result.class).to eq(Time)
expect(result).to eq(Time.parse((now + 1).strftime("%c")))
end
it "should process Date parameters" do
now = Date.new(2008, 8, 12)
result = plsql.test_date(now)
expect(result.class).to eq(Time)
expect(result).to eq(Time.parse((now + 1).strftime("%c")))
end
it "should process old Date parameters" do
now = Date.new(1901, 1, 1)
result = plsql.test_date(now)
expect(result.class).to eq(Time)
expect(result).to eq(Time.parse((now + 1).strftime("%c")))
end
it "should process nil date parameter as NULL" do
expect(plsql.test_date(nil)).to be_nil
end
end
describe "Function with timestamp parameters" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_timestamp
( p_time TIMESTAMP )
RETURN TIMESTAMP
IS
BEGIN
RETURN p_time + NUMTODSINTERVAL(1, 'DAY');
END test_timestamp;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_timestamp"
plsql.logoff
end
it "should process timestamp parameters" do
# now = Time.now
now = Time.local(2008, 8, 12, 14, 28, 0)
expect(plsql.test_timestamp(now)).to eq(now + 60 * 60 * 24)
end
end
describe "Function or procedure with XMLType parameters" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
@oracle12c_or_higher = !! plsql.connection.select_all(
"select * from product_component_version where product like 'Oracle%' and to_number(substr(version,1,2)) >= 12")
skip "Skip until furtuer investigation for #114" if @oracle12c_or_higher
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_xmltype
( p_xml XMLTYPE )
RETURN XMLTYPE
IS
BEGIN
RETURN p_xml;
END test_xmltype;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE PROCEDURE test_xmltype2
( p_xml XMLTYPE, po_xml OUT XMLTYPE )
IS
BEGIN
po_xml := p_xml;
END test_xmltype2;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_xmltype" unless @oracle12c_or_higher
plsql.execute "DROP PROCEDURE test_xmltype2" unless @oracle12c_or_higher
plsql.logoff
end
it "should process XMLType parameters" do
xml = "<DUMMY>value</DUMMY>"
result = plsql.test_xmltype(xml)
expect(result).to eq("<DUMMY>value</DUMMY>")
end
it "should work when passing a NULL value" do
result = plsql.test_xmltype(nil)
expect(result).to be_nil
end
it "should assign input parameter to putput parameter" do
xml = "<DUMMY>value</DUMMY>"
result = plsql.test_xmltype2(xml)
expect(result[:po_xml]).to eq("<DUMMY>value</DUMMY>")
end
end
describe "Procedure with output parameters" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE PROCEDURE test_copy
( p_from VARCHAR2, p_to OUT VARCHAR2, p_to_double OUT VARCHAR2 )
IS
BEGIN
p_to := p_from;
p_to_double := p_from || p_from;
END test_copy;
SQL
end
after(:all) do
plsql.execute "DROP PROCEDURE test_copy"
plsql.logoff
end
it "should return hash with output parameters" do
expect(plsql.test_copy("abc", nil, nil)).to eq(p_to: "abc", p_to_double: "abcabc")
end
it "should return hash with output parameters when called with named parameters" do
expect(plsql.test_copy(p_from: "abc", p_to: nil, p_to_double: nil)).to eq(p_to: "abc", p_to_double: "abcabc")
end
it "should substitute output parameters with nil if they are not specified" do
expect(plsql.test_copy("abc")).to eq(p_to: "abc", p_to_double: "abcabc")
end
it "should substitute named output parameters with nil if they are not specified" do
expect(plsql.test_copy(p_from: "abc")).to eq(p_to: "abc", p_to_double: "abcabc")
end
end
describe "Package with procedures with same name but different argument lists" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE PACKAGE test_package2 IS
FUNCTION test_procedure ( p_string VARCHAR2 )
RETURN VARCHAR2;
PROCEDURE test_procedure ( p_string VARCHAR2, p_result OUT VARCHAR2 )
;
PROCEDURE test_procedure ( p_number NUMBER, p_result OUT VARCHAR2 )
;
FUNCTION test_procedure2 ( p_string VARCHAR2 )
RETURN VARCHAR2;
FUNCTION test_function ( p_string VARCHAR2, p_string2 VARCHAR2 DEFAULT ' ')
RETURN VARCHAR2;
FUNCTION test_function ( p_number NUMBER, p_number2 NUMBER DEFAULT 1 )
RETURN NUMBER;
END;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE PACKAGE BODY test_package2 IS
FUNCTION test_procedure ( p_string VARCHAR2 )
RETURN VARCHAR2
IS
BEGIN
RETURN UPPER(p_string);
END test_procedure;
PROCEDURE test_procedure ( p_string VARCHAR2, p_result OUT VARCHAR2 )
IS
BEGIN
p_result := UPPER(p_string);
END test_procedure;
PROCEDURE test_procedure ( p_number NUMBER, p_result OUT VARCHAR2 )
IS
BEGIN
p_result := LOWER(TO_CHAR(p_number));
END test_procedure;
FUNCTION test_procedure2 ( p_string VARCHAR2 )
RETURN VARCHAR2
IS
BEGIN
RETURN UPPER(p_string);
END test_procedure2;
FUNCTION test_function ( p_string VARCHAR2, p_string2 VARCHAR2)
RETURN VARCHAR2
IS
BEGIN
RETURN p_string||p_string2;
END;
FUNCTION test_function ( p_number NUMBER, p_number2 NUMBER)
RETURN NUMBER
IS
BEGIN
RETURN p_number + p_number2;
END;
END;
SQL
end
after(:all) do
plsql.execute "DROP PACKAGE test_package2"
plsql.logoff
end
it "should find existing package" do
expect(PLSQL::Package.find(plsql, :test_package2)).not_to be_nil
end
it "should identify overloaded procedure definition" do
@procedure = PLSQL::Procedure.find(plsql, :test_procedure, "TEST_PACKAGE2")
expect(@procedure).not_to be_nil
expect(@procedure).to be_overloaded
end
it "should identify non-overloaded procedure definition" do
@procedure = PLSQL::Procedure.find(plsql, :test_procedure2, "TEST_PACKAGE2")
expect(@procedure).not_to be_nil
expect(@procedure).not_to be_overloaded
end
it "should execute correct procedures based on number of arguments and return correct value" do
expect(plsql.test_package2.test_procedure("xxx")).to eq("XXX")
expect(plsql.test_package2.test_procedure("xxx", nil)).to eq(p_result: "XXX")
end
it "should execute correct procedures based on number of named arguments and return correct value" do
expect(plsql.test_package2.test_procedure(p_string: "xxx")).to eq("XXX")
expect(plsql.test_package2.test_procedure(p_string: "xxx", p_result: nil)).to eq(p_result: "XXX")
end
it "should raise exception if procedure cannot be found based on number of arguments" do
expect { plsql.test_package2.test_procedure() }.to raise_error(/wrong number or types of arguments/i)
end
it "should find procedure based on types of arguments" do
expect(plsql.test_package2.test_procedure(111, nil)).to eq(p_result: "111")
end
it "should find procedure based on names of named arguments" do
expect(plsql.test_package2.test_procedure(p_number: 111, p_result: nil)).to eq(p_result: "111")
end
it "should find matching procedure based on partial list of named arguments" do
expect(plsql.test_package2.test_function(p_string: "xxx")).to eq("xxx ")
expect(plsql.test_package2.test_function(p_number: 1)).to eq(2)
end
end
describe "Function with output parameters" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_copy_function
( p_from VARCHAR2, p_to OUT VARCHAR2, p_to_double OUT VARCHAR2 )
RETURN NUMBER
IS
BEGIN
p_to := p_from;
p_to_double := p_from || p_from;
RETURN LENGTH(p_from);
END test_copy_function;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_copy_function"
plsql.logoff
end
it "should return array with return value and hash of output parameters" do
expect(plsql.test_copy_function("abc", nil, nil)).to eq([3, { p_to: "abc", p_to_double: "abcabc" }])
end
it "should return array with return value and hash of output parameters when called with named parameters" do
expect(plsql.test_copy_function(p_from: "abc", p_to: nil, p_to_double: nil)).to eq(
[3, { p_to: "abc", p_to_double: "abcabc" }]
)
end
it "should substitute output parameters with nil if they are not specified" do
expect(plsql.test_copy_function("abc")).to eq([3, { p_to: "abc", p_to_double: "abcabc" }])
end
end
describe "Function or procedure without parameters" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_no_params
RETURN VARCHAR2
IS
BEGIN
RETURN 'dummy';
END test_no_params;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE PROCEDURE test_proc_no_params
IS
BEGIN
NULL;
END test_proc_no_params;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_no_params"
plsql.execute "DROP PROCEDURE test_proc_no_params"
plsql.logoff
end
it "should find function" do
expect(PLSQL::Procedure.find(plsql, :test_no_params)).not_to be_nil
end
it "should return function value" do
expect(plsql.test_no_params).to eq("dummy")
end
it "should find procedure" do
expect(PLSQL::Procedure.find(plsql, :test_proc_no_params)).not_to be_nil
end
it "should execute procedure" do
expect(plsql.test_proc_no_params).to be_nil
end
end
describe "Function with CLOB parameter and return value" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_clob
( p_clob CLOB )
RETURN CLOB
IS
BEGIN
RETURN p_clob;
END test_clob;
SQL
plsql.execute "CREATE TABLE test_clob_table (clob_col CLOB)"
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_clob_insert
( p_clob CLOB )
RETURN CLOB
IS
CURSOR clob_cur IS
SELECT clob_col
FROM test_clob_table;
v_dummy CLOB;
BEGIN
DELETE FROM test_clob_table;
INSERT INTO test_clob_table (clob_col) VALUES (p_clob);
OPEN clob_cur;
FETCH clob_cur INTO v_dummy;
CLOSE clob_cur;
RETURN v_dummy;
END test_clob_insert;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_clob"
plsql.execute "DROP FUNCTION test_clob_insert"
plsql.execute "DROP TABLE test_clob_table"
plsql.logoff
end
it "should find existing procedure" do
expect(PLSQL::Procedure.find(plsql, :test_clob)).not_to be_nil
end
it "should execute function and return correct value" do
large_text = "ābčdēfghij" * 10_000
expect(plsql.test_clob(large_text)).to eq(large_text)
end
unless defined?(JRUBY_VERSION)
it "should execute function with empty string and return nil (oci8 cannot pass empty CLOB parameter)" do
text = ""
expect(plsql.test_clob(text)).to be_nil
end
it "should execute function which inserts the CLOB parameter into a table with empty string and return nil" do
text = ""
expect(plsql.test_clob_insert(text)).to be_nil
end
else
it "should execute function with empty string and return empty string" do
text = ""
expect(plsql.test_clob(text)).to eq(text)
end
end
it "should execute function with nil and return nil" do
expect(plsql.test_clob(nil)).to be_nil
end
it "should execute function which inserts the CLOB parameter into a table with nil and return nil" do
expect(plsql.test_clob_insert(nil)).to be_nil
end
end
describe "Procedrue with CLOB parameter and return value" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE PROCEDURE test_clob_proc
( p_clob CLOB,
p_return OUT CLOB)
IS
BEGIN
p_return := p_clob;
END test_clob_proc;
SQL
end
after(:all) do
plsql.execute "DROP PROCEDURE test_clob_proc"
plsql.logoff
end
it "should find existing procedure" do
expect(PLSQL::Procedure.find(plsql, :test_clob_proc)).not_to be_nil
end
it "should execute function and return correct value" do
large_text = "ābčdēfghij" * 10_000
expect(plsql.test_clob_proc(large_text)[:p_return]).to eq(large_text)
end
end
describe "Procedrue with BLOB parameter and return value" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE PROCEDURE test_blob_proc
( p_blob BLOB,
p_return OUT BLOB)
IS
BEGIN
p_return := p_blob;
END test_blob_proc;
SQL
end
after(:all) do
plsql.execute "DROP PROCEDURE test_blob_proc"
plsql.logoff
end
it "should find existing procedure" do
expect(PLSQL::Procedure.find(plsql, :test_blob_proc)).not_to be_nil
end
it "should execute function and return correct value" do
large_binary = '\000\001\002\003\004\005\006\007\010\011' * 10_000
expect(plsql.test_blob_proc(large_binary)[:p_return]).to eq(large_binary)
end
end
describe "Function with record parameter" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute "DROP TABLE test_employees" rescue nil
plsql.execute <<-SQL
CREATE TABLE test_employees (
employee_id NUMBER(15),
first_name VARCHAR2(50),
last_name VARCHAR(50),
hire_date DATE
)
SQL
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_full_name (p_employee test_employees%ROWTYPE)
RETURN VARCHAR2
IS
BEGIN
RETURN p_employee.first_name || ' ' || p_employee.last_name;
END test_full_name;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE PACKAGE test_record IS
TYPE t_employee IS RECORD(
employee_id NUMBER(15),
first_name VARCHAR2(50),
last_name VARCHAR(50),
hire_date DATE
);
TYPE t_candidate IS RECORD(
candidate_id NUMBER(5),
is_approved BOOLEAN
);
TYPE table_of_records IS TABLE OF test_record.t_employee;
FUNCTION test_full_name(p_employee t_employee)
RETURN VARCHAR2;
FUNCTION test_empty_records
RETURN table_of_records;
FUNCTION is_approved(p_candidate t_candidate)
RETURN BOOLEAN;
FUNCTION f_set_candidate_status(p_candidate t_candidate, p_status boolean)
RETURN t_candidate;
PROCEDURE p_set_candidate_status(p_candidate t_candidate, p_status boolean, p_result OUT t_candidate);
END;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE PACKAGE BODY test_record IS
FUNCTION test_full_name (p_employee t_employee)
RETURN VARCHAR2
IS
BEGIN
RETURN p_employee.first_name || ' ' || p_employee.last_name;
END;
FUNCTION test_empty_records
RETURN table_of_records
IS
CURSOR employees_cur
IS
SELECT
null employee_id,
null first_name,
null last_name,
null hire_date
FROM dual
WHERE 1 = 2;
employees_tab table_of_records;
BEGIN
OPEN employees_cur;
FETCH employees_cur BULK COLLECT INTO employees_tab;
CLOSE employees_cur;
RETURN employees_tab;
END;
FUNCTION is_approved(p_candidate t_candidate)
RETURN BOOLEAN
IS
BEGIN
RETURN p_candidate.is_approved;
END;
FUNCTION f_set_candidate_status(p_candidate t_candidate, p_status boolean)
RETURN t_candidate
IS
result t_candidate := p_candidate;
BEGIN
result.is_approved := p_status;
return result;
END;
PROCEDURE p_set_candidate_status(p_candidate t_candidate, p_status boolean, p_result OUT t_candidate)
IS
BEGIN
p_result := p_candidate;
p_result.is_approved := p_status;
END;
END;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_employee_record (p_employee test_employees%ROWTYPE)
RETURN test_employees%ROWTYPE
IS
BEGIN
RETURN p_employee;
END test_employee_record;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_employee_record2 (p_employee test_employees%ROWTYPE, x_employee IN OUT test_employees%ROWTYPE)
RETURN test_employees%ROWTYPE
IS
BEGIN
x_employee.employee_id := p_employee.employee_id;
x_employee.first_name := p_employee.first_name;
x_employee.last_name := p_employee.last_name;
x_employee.hire_date := p_employee.hire_date;
RETURN p_employee;
END test_employee_record2;
SQL
@p_employee = {
employee_id: 1,
first_name: "First",
last_name: "Last",
hire_date: Time.local(2000, 01, 31)
}
@p_employee2 = {
"employee_id" => 1,
"FIRST_NAME" => "Second",
"last_name" => "Last",
"hire_date" => Time.local(2000, 01, 31)
}
end
after(:all) do
plsql.execute "DROP FUNCTION test_full_name"
plsql.execute "DROP PACKAGE test_record"
plsql.execute "DROP FUNCTION test_employee_record"
plsql.execute "DROP FUNCTION test_employee_record2"
plsql.execute "DROP TABLE test_employees"
plsql.logoff
end
it "should find existing function" do
expect(PLSQL::Procedure.find(plsql, :test_full_name)).not_to be_nil
end
it "should execute function with named parameter and return correct value" do
expect(plsql.test_full_name(p_employee: @p_employee)).to eq("First Last")
end
it "should execute function with sequential parameter and return correct value" do
expect(plsql.test_full_name(@p_employee)).to eq("First Last")
end
it "should execute function with Hash parameter using strings as keys" do
expect(plsql.test_full_name(@p_employee2)).to eq("Second Last")
end
it "should raise error if wrong field name is passed for record parameter" do
expect do
expect(plsql.test_full_name(@p_employee.merge xxx: "xxx")).to eq("Second Last")
end.to raise_error(ArgumentError)
end
it "should return empty table of records" do
expect(plsql.test_record.test_empty_records()).to eq([])
end
it "should return record return value" do
expect(plsql.test_employee_record(@p_employee)).to eq(@p_employee)
end
it "should return record return value and output record parameter value" do
expect(plsql.test_employee_record2(@p_employee, @p_employee2)).to eq([@p_employee, { x_employee: @p_employee }])
end
it "should execute package function with parameter with record type defined in package" do
expect(plsql.test_record.test_full_name(@p_employee)).to eq("First Last")
end
context "functions with record parameters having boolean attributes" do
def new_candidate(status)
{ candidate_id: 1, is_approved: status }
end
[true, false, nil].each do |status|
it "should execute function with record having boolean attribute (#{status})" do
expect(plsql.test_record.is_approved(new_candidate(status))).to eq status
end
it "procedure should return record with boolean attribute as output parameter (#{status})" do
expect(plsql.test_record.p_set_candidate_status(new_candidate(nil), status)[:p_result]).to eq new_candidate(status)
end
it "function should return record with boolean attribute (#{status})" do
expect(plsql.test_record.f_set_candidate_status(new_candidate(nil), status)).to eq new_candidate(status)
end
end
end
end
describe "Function with boolean parameters" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_boolean
( p_boolean BOOLEAN )
RETURN BOOLEAN
IS
BEGIN
RETURN p_boolean;
END test_boolean;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE PROCEDURE test_boolean2
( p_boolean BOOLEAN, x_boolean OUT BOOLEAN )
IS
BEGIN
x_boolean := p_boolean;
END test_boolean2;
SQL
end
after(:all) do
plsql.execute "DROP FUNCTION test_boolean"
plsql.execute "DROP PROCEDURE test_boolean2"
plsql.logoff
end
it "should accept true value and return true value" do
expect(plsql.test_boolean(true)).to eq(true)
end
it "should accept false value and return false value" do
expect(plsql.test_boolean(false)).to eq(false)
end
it "should accept nil value and return nil value" do
expect(plsql.test_boolean(nil)).to be_nil
end
it "should accept true value and assign true value to output parameter" do
expect(plsql.test_boolean2(true, nil)).to eq(x_boolean: true)
end
it "should accept false value and assign false value to output parameter" do
expect(plsql.test_boolean2(false, nil)).to eq(x_boolean: false)
end
it "should accept nil value and assign nil value to output parameter" do
expect(plsql.test_boolean2(nil, nil)).to eq(x_boolean: nil)
end
end
describe "Function with object type parameter" do
before(:all) do
plsql.connect! CONNECTION_PARAMS
plsql.execute "DROP TYPE t_employee" rescue nil
plsql.execute "DROP TYPE t_phones" rescue nil
plsql.execute <<-SQL
CREATE OR REPLACE TYPE t_address AS OBJECT (
street VARCHAR2(50),
city VARCHAR2(50),
country VARCHAR2(50)
)
SQL
plsql.execute <<-SQL
CREATE OR REPLACE TYPE t_phone AS OBJECT (
type VARCHAR2(10),
phone_number VARCHAR2(50)
)
SQL
plsql.execute <<-SQL
CREATE OR REPLACE TYPE t_phones AS TABLE OF T_PHONE
SQL
plsql.execute <<-SQL
CREATE OR REPLACE TYPE t_employee AS OBJECT (
employee_id NUMBER(15),
first_name VARCHAR2(50),
last_name VARCHAR(50),
hire_date DATE,
address t_address,
phones t_phones
)
SQL
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_full_name (p_employee t_employee)
RETURN VARCHAR2
IS
BEGIN
RETURN p_employee.first_name || ' ' || p_employee.last_name;
END;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_employee_object (p_employee t_employee)
RETURN t_employee
IS
BEGIN
RETURN p_employee;
END;
SQL
plsql.execute <<-SQL
CREATE OR REPLACE FUNCTION test_employee_object2 (p_employee t_employee, x_employee OUT t_employee)
RETURN t_employee
IS
BEGIN
x_employee := p_employee;
RETURN p_employee;
END;
SQL
@p_employee = {
employee_id: 1,
first_name: "First",
last_name: "Last",
hire_date: Time.local(2000, 01, 31),
address: { street: "Main street 1", city: "Riga", country: "Latvia" },
phones: [{ type: "mobile", phone_number: "123456" }, { type: "home", phone_number: "654321" }]
}
end
after(:all) do
plsql.execute "DROP FUNCTION test_full_name"
plsql.execute "DROP FUNCTION test_employee_object"
plsql.execute "DROP FUNCTION test_employee_object2"
plsql.execute "DROP TYPE t_employee"
plsql.execute "DROP TYPE t_address"
plsql.execute "DROP TYPE t_phones"
plsql.execute "DROP TYPE t_phone"
plsql.logoff
end
it "should find existing function" do
expect(PLSQL::Procedure.find(plsql, :test_full_name)).not_to be_nil
end
it "should execute function with named parameter and return correct value" do
expect(plsql.test_full_name(p_employee: @p_employee)).to eq("First Last")
end