diff --git a/README.md b/README.md index 94fe7994..0dcdffff 100644 --- a/README.md +++ b/README.md @@ -8,7 +8,7 @@ DESCRIPTION ruby-plsql gem provides simple Ruby API for calling Oracle PL/SQL procedures. It could be used both for accessing Oracle PL/SQL API procedures in legacy applications as well as it could be used to create PL/SQL unit tests using Ruby testing libraries. -NUMBER, BINARY_INTEGER, PLS_INTEGER, VARCHAR2, NVARCHAR2, CHAR, NCHAR, DATE, TIMESTAMP, CLOB, BLOB, BOOLEAN, PL/SQL RECORD, TABLE, VARRAY, OBJECT and CURSOR types are supported for input and output parameters and return values of PL/SQL procedures and functions. +NUMBER, BINARY_INTEGER, PLS_INTEGER, NATURAL, NATURALN, POSITIVE, POSITIVEN, SIGNTYPE, SIMPLE_INTEGER, VARCHAR, VARCHAR2, NVARCHAR2, CHAR, NCHAR, DATE, TIMESTAMP, CLOB, BLOB, BOOLEAN, PL/SQL RECORD, TABLE, VARRAY, OBJECT and CURSOR types are supported for input and output parameters and return values of PL/SQL procedures and functions. ruby-plsql supports Ruby 1.8.7, 1.9.3, 2.1.3 and JRuby 1.6.7, 1.7.16 implementations. diff --git a/lib/plsql/jdbc_connection.rb b/lib/plsql/jdbc_connection.rb index 4c8cbddd..1b930d98 100644 --- a/lib/plsql/jdbc_connection.rb +++ b/lib/plsql/jdbc_connection.rb @@ -342,7 +342,7 @@ def result_set_to_ruby_data_type(column_type, column_type_name) def plsql_to_ruby_data_type(metadata) data_type, data_length = metadata[:data_type], metadata[:data_length] case data_type - when "VARCHAR2", "CHAR", "NVARCHAR2", "NCHAR" + when "VARCHAR", "VARCHAR2", "CHAR", "NVARCHAR2", "NCHAR" [String, data_length || 32767] when "CLOB", "NCLOB" [Java::OracleSql::CLOB, nil] @@ -350,7 +350,7 @@ def plsql_to_ruby_data_type(metadata) [Java::OracleSql::BLOB, nil] when "NUMBER" [BigDecimal, nil] - when "PLS_INTEGER", "BINARY_INTEGER" + when "NATURAL", "NATURALN", "POSITIVE", "POSITIVEN", "SIGNTYPE", "SIMPLE_INTEGER", "PLS_INTEGER", "BINARY_INTEGER" [Fixnum, nil] when "DATE" [DateTime, nil] diff --git a/lib/plsql/oci_connection.rb b/lib/plsql/oci_connection.rb index 99e9ec64..374023d9 100644 --- a/lib/plsql/oci_connection.rb +++ b/lib/plsql/oci_connection.rb @@ -147,13 +147,13 @@ def cursor_from_query(sql, bindvars=[], options={}) def plsql_to_ruby_data_type(metadata) data_type, data_length = metadata[:data_type], metadata[:data_length] case data_type - when "VARCHAR2", "CHAR", "NVARCHAR2", "NCHAR" + when "VARCHAR", "VARCHAR2", "CHAR", "NVARCHAR2", "NCHAR" [String, data_length || 32767] when "CLOB", "NCLOB" [OCI8::CLOB, nil] when "BLOB" [OCI8::BLOB, nil] - when "NUMBER", "PLS_INTEGER", "BINARY_INTEGER" + when "NUMBER", "NATURAL", "NATURALN", "POSITIVE", "POSITIVEN", "SIGNTYPE", "SIMPLE_INTEGER", "PLS_INTEGER", "BINARY_INTEGER" [OraNumber, nil] when "DATE" [DateTime, nil] diff --git a/lib/plsql/procedure.rb b/lib/plsql/procedure.rb index f5984e14..4ad3ff17 100644 --- a/lib/plsql/procedure.rb +++ b/lib/plsql/procedure.rb @@ -64,7 +64,7 @@ def self.type_to_sql(metadata) #:nodoc: when 'NUMBER' precision, scale = metadata[:data_precision], metadata[:data_scale] "NUMBER#{precision ? "(#{precision}#{scale ? ",#{scale}": ""})" : ""}" - when 'VARCHAR2', 'CHAR' + when 'VARCHAR', 'VARCHAR2', 'CHAR' length = case metadata[:char_used] when 'C' then "#{metadata[:char_length]} CHAR" when 'B' then "#{metadata[:data_length]} BYTE" diff --git a/lib/plsql/procedure_call.rb b/lib/plsql/procedure_call.rb index 6c6806f1..74c95c9e 100644 --- a/lib/plsql/procedure_call.rb +++ b/lib/plsql/procedure_call.rb @@ -109,9 +109,9 @@ def get_overload_from_arguments_list(args) end MATCHING_TYPES = { - :integer => ['NUMBER', 'PLS_INTEGER', 'BINARY_INTEGER'], + :integer => ['NUMBER', 'NATURAL', 'NATURALN', 'POSITIVE', 'POSITIVEN', 'SIGNTYPE', 'SIMPLE_INTEGER', 'PLS_INTEGER', 'BINARY_INTEGER'], :decimal => ['NUMBER', 'BINARY_FLOAT', 'BINARY_DOUBLE'], - :string => ['VARCHAR2', 'NVARCHAR2', 'CHAR', 'NCHAR', 'CLOB', 'BLOB'], + :string => ['VARCHAR', 'VARCHAR2', 'NVARCHAR2', 'CHAR', 'NCHAR', 'CLOB', 'BLOB'], :date => ['DATE'], :time => ['DATE', 'TIMESTAMP', 'TIMESTAMP WITH TIME ZONE', 'TIMESTAMP WITH LOCAL TIME ZONE'], :boolean => ['PL/SQL BOOLEAN'], diff --git a/lib/plsql/variable.rb b/lib/plsql/variable.rb index 6c573a8d..d5243dab 100644 --- a/lib/plsql/variable.rb +++ b/lib/plsql/variable.rb @@ -47,10 +47,10 @@ def value=(new_value) def metadata(type_string) case type_string - when /^(VARCHAR2|CHAR|NVARCHAR2|NCHAR)(\((\d+)[\s\w]*\))?$/ + when /^(VARCHAR|VARCHAR2|CHAR|NVARCHAR2|NCHAR)(\((\d+)[\s\w]*\))?$/ {:data_type => $1, :data_length => $3.to_i, :in_out => 'IN/OUT'} when /^(CLOB|NCLOB|BLOB)$/, - /^(NUMBER)(\(.*\))?$/, /^(PLS_INTEGER|BINARY_INTEGER)$/, + /^(NUMBER)(\(.*\))?$/, /^(NATURAL|NATURALN|POSITIVE|POSITIVEN|SIGNTYPE|SIMPLE_INTEGER|PLS_INTEGER|BINARY_INTEGER)$/, /^(DATE|TIMESTAMP|TIMESTAMP WITH TIME ZONE|TIMESTAMP WITH LOCAL TIME ZONE)$/ {:data_type => $1, :in_out => 'IN/OUT'} when /^INTEGER$/ diff --git a/spec/plsql/connection_spec.rb b/spec/plsql/connection_spec.rb index ed78b697..dc74007a 100644 --- a/spec/plsql/connection_spec.rb +++ b/spec/plsql/connection_spec.rb @@ -51,6 +51,11 @@ # Ruby 1.8 and 1.9 unless defined?(JRuby) describe "OCI data type conversions" do + it "should translate PL/SQL VARCHAR to Ruby String" do + expect(@conn.plsql_to_ruby_data_type(:data_type => "VARCHAR", :data_length => 100)).to eq [String, 100] + expect(@conn.plsql_to_ruby_data_type(:data_type => "VARCHAR", :data_length => nil)).to eq [String, 32767] + end + it "should translate PL/SQL VARCHAR2 to Ruby String" do expect(@conn.plsql_to_ruby_data_type(:data_type => "VARCHAR2", :data_length => 100)).to eq [String, 100] expect(@conn.plsql_to_ruby_data_type(:data_type => "VARCHAR2", :data_length => nil)).to eq [String, 32767] @@ -122,6 +127,10 @@ else describe "JDBC data type conversions" do + it "should translate PL/SQL VARCHAR to Ruby String" do + expect(@conn.plsql_to_ruby_data_type(:data_type => "VARCHAR", :data_length => 100)).to eq [String, 100] + expect(@conn.plsql_to_ruby_data_type(:data_type => "VARCHAR", :data_length => nil)).to eq [String, 32767] + end it "should translate PL/SQL VARCHAR2 to Ruby String" do expect(@conn.plsql_to_ruby_data_type(:data_type => "VARCHAR2", :data_length => 100)).to eq [String, 100] expect(@conn.plsql_to_ruby_data_type(:data_type => "VARCHAR2", :data_length => nil)).to eq [String, 32767] diff --git a/spec/plsql/procedure_spec.rb b/spec/plsql/procedure_spec.rb index 5dc4fb0f..4bdee21a 100644 --- a/spec/plsql/procedure_spec.rb +++ b/spec/plsql/procedure_spec.rb @@ -3,13 +3,14 @@ require 'spec_helper' describe "Parameter type mapping /" do - describe "Function with string parameters" 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 VARCHAR2 ) - RETURN VARCHAR2 + ( p_string #{datatype} ) + RETURN #{datatype} IS BEGIN RETURN UPPER(p_string); @@ -56,83 +57,85 @@ end - describe "Function with numeric parameters" do + ['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 NUMBER, p_num2 NUMBER ) - RETURN NUMBER + ( 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 - plsql.execute <<-SQL - CREATE OR REPLACE FUNCTION test_number_1 - ( p_num NUMBER ) - RETURN VARCHAR2 - IS - BEGIN - IF p_num = 1 THEN - RETURN 'Y'; - ELSIF p_num = 0 THEN - RETURN 'N'; - ELSIF p_num IS NULL THEN - RETURN NULL; - ELSE - RETURN 'UNKNOWN'; - END IF; - END test_number_1; - SQL - plsql.execute <<-SQL - CREATE OR REPLACE PROCEDURE test_integers - ( p_pls_int PLS_INTEGER, p_bin_int BINARY_INTEGER, x_pls_int OUT PLS_INTEGER, x_bin_int OUT BINARY_INTEGER ) - IS - BEGIN - x_pls_int := p_pls_int; - x_bin_int := p_bin_int; - END; - SQL end after(:all) do plsql.execute "DROP FUNCTION test_sum" - plsql.execute "DROP FUNCTION test_number_1" - plsql.execute "DROP PROCEDURE test_integers" plsql.logoff end - it "should process integer parameters" do - expect(plsql.test_sum(123,456)).to eq(579) + 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 big integer parameters" do - expect(plsql.test_sum(123123123123,456456456456)).to eq(579579579579) + it "should process input parameters and return correct result" do + expect(plsql.test_sum(num1, num2)).to eq(expected) end - it "should process float parameters and return BigDecimal" do - expect(plsql.test_sum(123.123,456.456)).to eq(BigDecimal("579.579")) - end + it "should process nil parameter as NULL" do + expect(plsql.test_sum(num1, nil)).to be_nil + end unless mandatory + + end - it "should process BigDecimal parameters and return BigDecimal" do - expect(plsql.test_sum(:p_num1 => BigDecimal("123.123"), :p_num2 => BigDecimal("456.456"))).to eq(BigDecimal("579.579")) + @big_number = ('1234567890' * 3).to_i + [ + {:ora_data_type => 'INTEGER', :class => Bignum, :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 => Fixnum, :num1 => 123456789, :num2 => 123456789, :expected => 246913578 }, + {:ora_data_type => 'BINARY_INTEGER',:class => Fixnum, :num1 => 123456789, :num2 => 123456789, :expected => 246913578 }, + {:ora_data_type => 'SIMPLE_INTEGER',:class => Fixnum, :num1 => 123456789, :num2 => 123456789, :expected => 246913578, :mandatory => true }, + {:ora_data_type => 'NATURAL', :class => Fixnum, :num1 => 123456789, :num2 => 123456789, :expected => 246913578 }, + {:ora_data_type => 'NATURALN', :class => Fixnum, :num1 => 123456789, :num2 => 123456789, :expected => 246913578, :mandatory => true }, + {:ora_data_type => 'POSITIVE', :class => Fixnum, :num1 => 123456789, :num2 => 123456789, :expected => 246913578 }, + {:ora_data_type => 'POSITIVEN', :class => Fixnum, :num1 => 123456789, :num2 => 123456789, :expected => 246913578, :mandatory => true }, + {:ora_data_type => 'SIGNTYPE', :class => Fixnum, :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 - it "should process nil parameter as NULL" do - expect(plsql.test_sum(123,nil)).to be_nil + 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_number_1(true)).to eq('Y') + expect(plsql.test_num(true)).to eq(1) end it "should convert false value to 0 for NUMBER parameter" do - expect(plsql.test_number_1(false)).to eq('N') - end - - it "should process binary integer parameters" do - expect(plsql.test_integers(123, 456)).to eq({:x_pls_int => 123, :x_bin_int => 456}) + expect(plsql.test_num(false)).to eq(0) end end @@ -609,7 +612,7 @@ CREATE TABLE test_employees ( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE ) SQL @@ -626,7 +629,7 @@ TYPE t_employee IS RECORD( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE ); @@ -887,7 +890,7 @@ def new_candidate(status) CREATE OR REPLACE TYPE t_employee AS OBJECT ( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE, address t_address, phones t_phones @@ -1047,7 +1050,7 @@ def new_candidate(status) TYPE t_employee IS RECORD( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE ); TYPE t_employees IS TABLE OF t_employee; @@ -1057,7 +1060,7 @@ def new_candidate(status) TYPE t_employee2 IS RECORD( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE, numbers t_numbers ); @@ -1294,7 +1297,7 @@ def new_candidate(status) CREATE TABLE test_employees ( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE ) SQL @@ -1312,7 +1315,7 @@ def new_candidate(status) TYPE t_employee IS RECORD( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE ); TYPE t_employees IS TABLE OF t_employee @@ -1742,7 +1745,7 @@ def new_candidate(status) CREATE TABLE test_employees ( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE ) SQL diff --git a/spec/plsql/sql_statements_spec.rb b/spec/plsql/sql_statements_spec.rb index d19a3e7d..13326676 100644 --- a/spec/plsql/sql_statements_spec.rb +++ b/spec/plsql/sql_statements_spec.rb @@ -21,7 +21,7 @@ CREATE TABLE test_employees ( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE ) SQL diff --git a/spec/plsql/table_spec.rb b/spec/plsql/table_spec.rb index 0ac93641..549a4cb2 100644 --- a/spec/plsql/table_spec.rb +++ b/spec/plsql/table_spec.rb @@ -8,7 +8,7 @@ CREATE TABLE test_employees ( employee_id NUMBER(15) NOT NULL, first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE, created_at TIMESTAMP, status VARCHAR2(1) DEFAULT 'N' @@ -35,7 +35,7 @@ CREATE TABLE test_employees2 ( employee_id NUMBER(15) NOT NULL, first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE DEFAULT SYSDATE, address t_address, phones t_phones diff --git a/spec/plsql/type_spec.rb b/spec/plsql/type_spec.rb index 2b481369..efa08a86 100644 --- a/spec/plsql/type_spec.rb +++ b/spec/plsql/type_spec.rb @@ -80,7 +80,7 @@ CREATE OR REPLACE TYPE t_employee AS OBJECT ( employee_id NUMBER(15), first_name VARCHAR2(50), - last_name VARCHAR2(50), + last_name VARCHAR(50), hire_date DATE, address t_address, phones t_phones diff --git a/spec/plsql/variable_spec.rb b/spec/plsql/variable_spec.rb index 26abf733..ae576041 100644 --- a/spec/plsql/variable_spec.rb +++ b/spec/plsql/variable_spec.rb @@ -16,6 +16,7 @@ varchar2_default3 varchar2(50) NOT NULL := 'default'; varchar2_3_char VARCHAR2(3 CHAR); varchar2_3_byte VARCHAR2(3 BYTE); + varchar_variable VARCHAR(50); char_variable char(10) ; nvarchar2_variable NVARCHAR2(50); nchar_variable NCHAR(10); @@ -33,6 +34,11 @@ plsql.logoff end + it "should set and get VARCHAR variable" do + plsql.test_package.varchar_variable = 'abc' + expect(plsql.test_package.varchar_variable).to eq('abc') + end + it "should set and get VARCHAR2 variable" do plsql.test_package.varchar2_variable = 'abc' expect(plsql.test_package.varchar2_variable).to eq('abc') @@ -95,25 +101,15 @@ end - describe "Numeric" do + shared_examples "Numeric" do |ora_data_type, default, class_, given, expected| + before(:all) do plsql.connect! CONNECTION_PARAMS plsql.execute <<-SQL CREATE OR REPLACE PACKAGE test_package IS - integer_variable INTEGER; - integer10_variable NUMBER(10); - integer10_default NUMBER(10) := 1; - number_variable NUMBER; - number_with_scale NUMBER(15,2); - pls_int_variable PLS_INTEGER; - bin_int_variable BINARY_INTEGER; + numeric_var #{ora_data_type}#{default ? ':= ' + default.to_s : nil}; END; SQL - plsql.execute <<-SQL - CREATE OR REPLACE PACKAGE BODY test_package IS - END; - SQL - end after(:all) do @@ -121,45 +117,41 @@ plsql.logoff end - it "should set and get INTEGER variable" do - plsql.test_package.integer_variable = 1 - expect(plsql.test_package.integer_variable).to be_a Fixnum - expect(plsql.test_package.integer_variable).to eq(1) - end + it "should get #{ora_data_type} variable default value" do + expect(plsql.test_package.numeric_var).to eq(default) + end if default - it "should set and get integer variable with precision" do - plsql.test_package.integer10_variable = 1 - expect(plsql.test_package.integer10_variable).to be_a Fixnum - expect(plsql.test_package.integer10_variable).to eq(1) + it "should get #{ora_data_type} variable type mapped to #{class_.to_s}" do + plsql.test_package.numeric_var = given + expect(plsql.test_package.numeric_var).to be_a class_ end - it "should get integer variable default value" do - expect(plsql.test_package.integer10_default).to eq(1) + it "should set and get #{ora_data_type} variable" do + plsql.test_package.numeric_var = given + expect(plsql.test_package.numeric_var).to eq(expected) end - it "should set and get PLS_INTEGER variable" do - plsql.test_package.pls_int_variable = 1 - expect(plsql.test_package.pls_int_variable).to be_a Fixnum - expect(plsql.test_package.pls_int_variable).to eq(1) - end - - it "should set and get BINARY_INTEGER variable" do - plsql.test_package.bin_int_variable = 1 - expect(plsql.test_package.bin_int_variable).to be_a Fixnum - expect(plsql.test_package.bin_int_variable).to eq(1) - end - - it "should set and get NUMBER variable" do - plsql.test_package.number_variable = 123.456 - expect(plsql.test_package.number_variable).to be_a BigDecimal - expect(plsql.test_package.number_variable).to eq(123.456) - end + end - it "should set and get NUMBER variable with scale" do - plsql.test_package.number_with_scale = 123.456 - expect(plsql.test_package.number_with_scale).to eq(123.46) # rounding to two decimal digits + [ + {:ora_data_type => 'INTEGER', :default => nil, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'NUMBER(10)', :default => nil, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'NUMBER(10)', :default => 5, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'NUMBER', :default => nil, :class => BigDecimal, :given => 123.456, :expected => 123.456}, + {:ora_data_type => 'NUMBER(15,2)', :default => nil, :class => BigDecimal, :given => 123.456, :expected => 123.46}, + {:ora_data_type => 'PLS_INTEGER', :default => nil, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'BINARY_INTEGER', :default => nil, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'SIMPLE_INTEGER', :default => 10, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'NATURAL', :default => nil, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'NATURALN', :default => 0, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'POSITIVE', :default => nil, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'POSITIVEN', :default => 5, :class => Fixnum, :given => 1, :expected => 1}, + {:ora_data_type => 'SIGNTYPE', :default => -1, :class => Fixnum, :given => 1, :expected => 1}, + ].each do |row| + ora_data_type, default, class_, given, expected = row.values + describe ora_data_type+(default ? ' with default' : '') do + include_examples "Numeric", ora_data_type, default, class_, given, expected end - end describe "Date and Time" do