diff --git a/.gitignore b/.gitignore index cf8d5b5d..5ede6ec1 100644 --- a/.gitignore +++ b/.gitignore @@ -9,3 +9,4 @@ log tmp sqlnet.log Gemfile.lock +.idea diff --git a/lib/plsql/package.rb b/lib/plsql/package.rb index 72d91508..7b23fc19 100644 --- a/lib/plsql/package.rb +++ b/lib/plsql/package.rb @@ -1,29 +1,37 @@ module PLSQL - module PackageClassMethods #:nodoc: - def find(schema, package) - if schema.select_first( - "SELECT object_name FROM all_objects - WHERE owner = :owner - AND object_name = :package - AND object_type = 'PACKAGE'", - schema.schema_name, package.to_s.upcase) - new(schema, package) - # search for synonym - elsif (row = schema.select_first( - "SELECT o.owner, o.object_name - FROM all_synonyms s, all_objects o - WHERE s.owner IN (:owner, 'PUBLIC') - AND s.synonym_name = :synonym_name - AND o.owner = s.table_owner - AND o.object_name = s.table_name - AND o.object_type = 'PACKAGE' - ORDER BY DECODE(s.owner, 'PUBLIC', 1, 0)", - schema.schema_name, package.to_s.upcase)) - new(schema, row[1], row[0]) - else - nil - end + def find(schema, package_name) + find_package_in_schema(schema, package_name) || find_package_by_synonym(schema, package_name) + end + + def find_by_db_object(db_object) + find(db_object.schema, db_object.name) + end + + def find_package_in_schema(schema, package_name) + row = schema.select_first(<<-SQL, schema.schema_name, package_name.to_s.upcase) + SELECT object_name + FROM all_objects + WHERE owner = :owner + AND object_name = :package + AND object_type = 'PACKAGE' + SQL + new(schema, package_name) if row + end + + def find_package_by_synonym(schema, package_name) + row = schema.select_first(<<-SQL, schema.schema_name, package_name.to_s.upcase) + SELECT o.owner, o.object_name + FROM all_synonyms s, + all_objects o + WHERE s.owner IN (:owner, 'PUBLIC') + AND s.synonym_name = :synonym_name + AND o.owner = s.table_owner + AND o.object_name = s.table_name + AND o.object_type = 'PACKAGE' + ORDER BY DECODE(s.owner, 'PUBLIC', 1, 0) + SQL + new(schema, row[1], row[0]) if row end end @@ -37,29 +45,33 @@ def initialize(schema, package, override_schema_name = nil) @package_objects = {} end + def [](object_name) + object_name = object_name.to_s + @package_objects[object_name] ||= [Procedure, Variable, PipelinedFunction].inject(nil) do |res, object_type| + res || object_type.find(@schema, object_name, @package, @override_schema_name) + end + end + private def method_missing(method, *args, &block) - if assignment = (method.to_s[-1,1] == '=') - method = method.to_s.chop.to_sym - end - object = (@package_objects[method] ||= - Procedure.find(@schema, method, @package, @override_schema_name) || - Variable.find(@schema, method, @package, @override_schema_name)) - case object - when Procedure - raise ArgumentError, "Cannot assign value to package procedure '#{method.to_s.upcase}'" if assignment + method = method.to_s + method.chop! if (assignment = method[/=$/]) + + case (object = self[method]) + when Procedure, PipelinedFunction + raise ArgumentError, "Cannot assign value to package procedure '#{method.upcase}'" if assignment object.exec(*args, &block) when Variable if assignment - raise ArgumentError, "Just one value can be assigned to package variable '#{method.to_s.upcase}'" unless args.size == 1 && block == nil + raise ArgumentError, "Just one value can be assigned to package variable '#{method.upcase}'" unless args.size == 1 && block.nil? object.value = args[0] else - raise ArgumentError, "Cannot pass arguments when getting package variable '#{method.to_s.upcase}' value" unless args.size == 0 && block == nil + raise ArgumentError, "Cannot pass arguments when getting package variable '#{method.upcase}' value" unless args.size == 0 && block.nil? object.value end else - raise ArgumentError, "No PL/SQL procedure or variable '#{method.to_s.upcase}' found" + raise ArgumentError, "No PL/SQL procedure or variable '#{method.upcase}' found" end end diff --git a/lib/plsql/pipelined_function.rb b/lib/plsql/pipelined_function.rb new file mode 100644 index 00000000..aac0da4f --- /dev/null +++ b/lib/plsql/pipelined_function.rb @@ -0,0 +1,77 @@ +module PLSQL + # Work with table functions + # See http://www.oracle-base.com/articles/misc/pipelined-table-functions.php for examples + # or http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:19481671347143 + module PipelinedFunctionClassMethods + def find(schema, function_name, package_name = nil, override_schema_name = nil) + if package_name + find_function_in_package(schema, package_name, function_name, override_schema_name) + else + find_function_in_schema(schema, function_name) || find_function_by_synonym(schema, function_name) + end + end + + def find_function_in_schema(schema, function_name) + row = schema.select_first(<<-SQL, schema.schema_name, function_name.to_s.upcase) + SELECT object_id + FROM all_procedures + WHERE owner = :owner + AND object_name = :object_name + AND object_type = 'FUNCTION' + AND pipelined = 'YES' + SQL + new(schema, function_name, nil, nil, row[0]) if row + end + + def find_function_by_synonym(schema, function_name) + row = schema.select_first(<<-SQL, schema.schema_name, function_name.to_s.upcase) + SELECT p.owner, p.object_name, p.object_id + FROM all_synonyms s, + all_procedures p + WHERE s.owner IN (:owner, 'PUBLIC') + AND s.synonym_name = :synonym_name + AND p.owner = s.table_owner + AND p.object_name = s.table_name + AND p.object_type = 'FUNCTION' + AND p.pipelined = 'YES' + ORDER BY DECODE(s.owner, 'PUBLIC', 1, 0) + SQL + new(schema, row[1], nil, row[0], row[2]) if row + end + + def find_function_in_package(schema, package_name, function_name, override_schema_name = nil) + schema_name = override_schema_name || schema.schema_name + row = schema.select_first(<<-SQL, schema_name, package_name, function_name.to_s.upcase) + SELECT o.object_id + FROM all_procedures p, + all_objects o + WHERE p.owner = :owner + AND p.object_name = :object_name + AND p.procedure_name = :procedure_name + AND p.pipelined = 'YES' + AND o.owner = p.owner + AND o.object_name = p.object_name + AND o.object_type = 'PACKAGE' + SQL + new(schema, function_name, package_name, override_schema_name, row[0]) if row + end + end + + # TODO: create subprogram class and replace superclass for PipelinedFunction and Procedure + class PipelinedFunction < Procedure + extend PipelinedFunctionClassMethods + + def initialize(*) + super + @return = @return[0] + end + + def exec(*args, &block) + # use custom call syntax + call = PipelinedFunctionCall.new(self, args) + call.exec(&block) + end + + private :ensure_tmp_tables_created + end +end \ No newline at end of file diff --git a/lib/plsql/pipelined_function_call.rb b/lib/plsql/pipelined_function_call.rb new file mode 100644 index 00000000..c4a05fd7 --- /dev/null +++ b/lib/plsql/pipelined_function_call.rb @@ -0,0 +1,76 @@ +module PLSQL + class PipelinedFunctionCall < SubprogramCall + def exec(&block) + @cursor = @schema.connection.parse(@sql) + + @binds[:values].each do |arg, value| + @cursor.bind_param(":#{arg}", value, @binds[:metadata][arg]) + end + + @cursor.exec + + if block_given? + fetch_all_rows.each(&block) + nil + else + fetch_all_rows + end + ensure + @cursor.close if @cursor + end + + private + + def construct_sql(arguments) + prepare_sql_construction + @sql = <<-SQL + SELECT * + FROM TABLE(#{full_subprogram_name}(#{add_arguments(arguments)})) + SQL + end + + def fetch_all_rows + result = [] + cols = @cursor.raw_cursor.get_col_names.map { |name| name =~ /[a-z]/ ? name : name.downcase } + + while (row = @cursor.fetch) + tmp_hash = {} + cols.each_with_index do |col, i| + tmp_hash[col] = + case row[i] + when OCI8::LOB + row[i].read + when OraDate + row[i].to_time + when OraNumber + row[i].to_s.to_d + else + row[i] + end + end + + result << tmp_hash + end + + result + end + + def add_arguments(arguments) + if (@schema.connection.database_version <=> [11, 0, 0, 0]) > 0 + super + else + if arguments.first.is_a?(Hash) + # in 10g you cannot use named arguments in SQL for pipelined functions + arguments = make_sequential_arguments(arguments.first) + add_sequential_arguments(arguments) + else + super + end + end + end + + def make_sequential_arguments(arguments) + record_fields_sorted_by_position(arguments_metadata).map {|name| arguments[name] } + end + end +end \ No newline at end of file diff --git a/lib/plsql/procedure.rb b/lib/plsql/procedure.rb index cc5b7846..2522d4c5 100644 --- a/lib/plsql/procedure.rb +++ b/lib/plsql/procedure.rb @@ -1,45 +1,58 @@ module PLSQL module ProcedureClassMethods #:nodoc: - def find(schema, procedure, package = nil, override_schema_name = nil) - if package.nil? - if (row = schema.select_first( - "SELECT object_id FROM all_objects - WHERE owner = :owner - AND object_name = :object_name - AND object_type IN ('PROCEDURE','FUNCTION')", - schema.schema_name, procedure.to_s.upcase)) - new(schema, procedure, nil, nil, row[0]) - # search for synonym - elsif (row = schema.select_first( - "SELECT o.owner, o.object_name, o.object_id - FROM all_synonyms s, all_objects o - WHERE s.owner IN (:owner, 'PUBLIC') - AND s.synonym_name = :synonym_name - AND o.owner = s.table_owner - AND o.object_name = s.table_name - AND o.object_type IN ('PROCEDURE','FUNCTION') - ORDER BY DECODE(s.owner, 'PUBLIC', 1, 0)", - schema.schema_name, procedure.to_s.upcase)) - new(schema, row[1], nil, row[0], row[2]) - else - nil - end - elsif package && (row = schema.select_first( - # older Oracle versions do not have object_id column in all_procedures - "SELECT o.object_id FROM all_procedures p, all_objects o - WHERE p.owner = :owner - AND p.object_name = :object_name - AND p.procedure_name = :procedure_name - AND o.owner = p.owner - AND o.object_name = p.object_name - AND o.object_type = 'PACKAGE'", - override_schema_name || schema.schema_name, package, procedure.to_s.upcase)) - new(schema, procedure, package, override_schema_name, row[0]) + def find(schema, procedure_name, package_name = nil, override_schema_name = nil) + if package_name + find_procedure_in_package(schema, package_name, procedure_name, override_schema_name) else - nil + find_procedure_in_schema(schema, procedure_name) || find_procedure_by_synonym(schema, procedure_name) end end + + def find_procedure_in_schema(schema, procedure_name) + row = schema.select_first(<<-SQL, schema.schema_name, procedure_name.to_s.upcase) + SELECT object_id + FROM all_procedures + WHERE owner = :owner + AND object_name = :object_name + AND object_type IN ('PROCEDURE', 'FUNCTION') + AND pipelined = 'NO' + SQL + new(schema, procedure_name, nil, nil, row[0]) if row + end + + def find_procedure_by_synonym(schema, procedure_name) + row = schema.select_first(<<-SQL, schema.schema_name, procedure_name.to_s.upcase) + SELECT p.owner, p.object_name, p.object_id + FROM all_synonyms s, + all_procedures p + WHERE s.owner IN (:owner, 'PUBLIC') + AND s.synonym_name = :synonym_name + AND p.owner = s.table_owner + AND p.object_name = s.table_name + AND p.object_type IN ('PROCEDURE','FUNCTION') + AND p.pipelined = 'NO' + ORDER BY DECODE(s.owner, 'PUBLIC', 1, 0) + SQL + new(schema, row[1], nil, row[0], row[2]) if row + end + + def find_procedure_in_package(schema, package_name, procedure_name, override_schema_name = nil) + schema_name = override_schema_name || schema.schema_name + row = schema.select_first(<<-SQL, schema_name, package_name, procedure_name.to_s.upcase) + SELECT o.object_id + FROM all_procedures p, + all_objects o + WHERE p.owner = :owner + AND p.object_name = :object_name + AND p.procedure_name = :procedure_name + AND p.pipelined = 'NO' + AND o.owner = p.owner + AND o.object_name = p.object_name + AND o.object_type = 'PACKAGE' + SQL + new(schema, procedure_name, package_name, override_schema_name, row[0]) if row + end end module ProcedureCommon #:nodoc: @@ -253,5 +266,4 @@ def exec(*args, &block) end end - end \ No newline at end of file diff --git a/lib/plsql/procedure_call.rb b/lib/plsql/procedure_call.rb index c00214f6..1c94ffbc 100644 --- a/lib/plsql/procedure_call.rb +++ b/lib/plsql/procedure_call.rb @@ -1,27 +1,22 @@ module PLSQL - class ProcedureCall #:nodoc: + class ProcedureCall < SubprogramCall #:nodoc: + attr_reader :output_stream def initialize(procedure, args = [], options = {}) - @procedure = procedure - @schema = @procedure.schema - @dbms_output_stream = @schema.dbms_output_stream - @skip_self = options[:skip_self] - @self = options[:self] - @overload = get_overload_from_arguments_list(args) - @procedure.ensure_tmp_tables_created(@overload) if @procedure.respond_to?(:ensure_tmp_tables_created) - construct_sql(args) + @output_stream = procedure.schema.dbms_output_stream + super end def exec # puts "DEBUG: sql = #{@sql.gsub("\n","
\n")}" @cursor = @schema.connection.parse(@sql) - @bind_values.each do |arg, value| - @cursor.bind_param(":#{arg}", value, @bind_metadata[arg]) + @binds[:values].each do |arg, value| + @cursor.bind_param(":#{arg}", value, @binds[:metadata][arg]) end - @return_vars.each do |var| - @cursor.bind_param(":#{var}", nil, @return_vars_metadata[var]) + @return[:variables].each do |var| + @cursor.bind_param(":#{var}", nil, @return[:metadata][var]) end @cursor.exec @@ -40,548 +35,90 @@ def exec private - def get_overload_from_arguments_list(args) - # if not overloaded then overload index 0 is used - return 0 unless @procedure.overloaded? - # If named arguments are used then - # there should be just one Hash argument with symbol keys - if args.size == 1 && args[0].is_a?(Hash) && args[0].keys.all?{|k| k.is_a?(Symbol)} - args_keys = args[0].keys - # implicit SELF argument for object instance procedures - args_keys << :self if @self && !args_keys.include?(:self) - number_of_args = args_keys.size - matching_overloads = [] # overloads with exact or smaller number of matching named arguments - overload_argument_list.keys.each do |ov| - # assume that missing arguments have default value - missing_arguments_count = overload_argument_list[ov].size - number_of_args - if missing_arguments_count >= 0 && - args_keys.all?{|k| overload_argument_list[ov].include?(k)} - matching_overloads << [ov, missing_arguments_count] - end - end - # pick first matching overload with smallest missing arguments count - # (hoping that missing arguments will be defaulted - cannot find default value from all_arguments) - overload = matching_overloads.sort_by{|ov, score| score}[0][0] - # otherwise try matching by sequential arguments count and types - else - number_of_args = args.size - matching_types = [] - # if implicit SELF argument for object instance procedures should be passed - # then it should be added as first argument to find matches - if @self - number_of_args += 1 - matching_types << ['OBJECT'] - end - args.each do |arg| - matching_types << matching_oracle_types_for_ruby_value(arg) - end - exact_overloads = [] # overloads with exact number of matching arguments - smaller_overloads = [] # overloads with smaller number of matching arguments - # overload = overload_argument_list.keys.detect do |ov| - # overload_argument_list[ov].size == number_of_args - # end - overload_argument_list.keys.each do |ov| - score = 0 # lower score is better match - ov_arg_list_size = overload_argument_list[ov].size - if (number_of_args <= ov_arg_list_size && - (0..(number_of_args-1)).all? do |i| - ov_arg = overload_argument_list[ov][i] - matching_types[i] == :all || # either value matches any type - (ind = matching_types[i].index(overload_arguments[ov][ov_arg][:data_type])) && - (score += ind) # or add index of matched type - end) - if number_of_args == ov_arg_list_size - exact_overloads << [ov, score] - else - smaller_overloads << [ov, score] - end - end - end - # pick either first exact matching overload of first matching with smaller argument count - # (hoping that missing arguments will be defaulted - cannot find default value from all_arguments) - overload = if !exact_overloads.empty? - exact_overloads.sort_by{|ov, score| score}[0][0] - elsif !smaller_overloads.empty? - smaller_overloads.sort_by{|ov, score| score}[0][0] - end - end - raise ArgumentError, "Wrong number or types of arguments passed to overloaded PL/SQL procedure" unless overload - overload - end - - MATCHING_TYPES = { - :integer => ['NUMBER', 'PLS_INTEGER', 'BINARY_INTEGER'], - :decimal => ['NUMBER', 'BINARY_FLOAT', 'BINARY_DOUBLE'], - :string => ['VARCHAR2', 'NVARCHAR2', 'CHAR', 'NCHAR', 'CLOB', 'BLOB'], - :date => ['DATE'], - :time => ['DATE', 'TIMESTAMP', 'TIMESTAMP WITH TIME ZONE', 'TIMESTAMP WITH LOCAL TIME ZONE'], - :boolean => ['PL/SQL BOOLEAN'], - :hash => ['PL/SQL RECORD', 'OBJECT', 'PL/SQL TABLE'], - :array => ['TABLE', 'VARRAY'], - :cursor => ['REF CURSOR'] - } - def matching_oracle_types_for_ruby_value(value) - case value - when NilClass - :all - when Fixnum, Bignum - MATCHING_TYPES[:integer] - when BigDecimal, Float - MATCHING_TYPES[:decimal] - when String - MATCHING_TYPES[:string] - when Date - MATCHING_TYPES[:date] - when Time - MATCHING_TYPES[:time] - when TrueClass, FalseClass - MATCHING_TYPES[:boolean] - when Hash - MATCHING_TYPES[:hash] - when Array - MATCHING_TYPES[:array] - when CursorCommon - MATCHING_TYPES[:cursor] - end - end + def construct_sql(arguments) + prepare_sql_construction + call_sql = "" + call_sql << add_return if return_metadata - def construct_sql(args) - @declare_sql = "" - @assignment_sql = "" - @call_sql = "" - @return_sql = "" - @return_vars = [] - @return_vars_metadata = {} - - @call_sql << add_return if return_metadata # construct procedure call if procedure name is available # otherwise will get surrounding call_sql from @procedure (used for table statements) - if procedure_name - @call_sql << "#{schema_name}." if schema_name - @call_sql << "#{package_name}." if package_name - @call_sql << "#{procedure_name}(" - end - - @bind_values = {} - @bind_metadata = {} - - # Named arguments - # there should be just one Hash argument with symbol keys - if args.size == 1 && args[0].is_a?(Hash) && args[0].keys.all?{|k| k.is_a?(Symbol)} && - # do not use named arguments if procedure has just one PL/SQL record PL/SQL table or object type argument - - # in that case passed Hash should be used as value for this PL/SQL record argument - # (which will be processed in sequential arguments bracnh) - !(argument_list.size == 1 && - ['PL/SQL RECORD','PL/SQL TABLE','OBJECT'].include?(arguments[(only_argument=argument_list[0])][:data_type]) && - args[0].keys != [only_argument]) - # Add missing output arguments with nil value - arguments.each do |arg, metadata| - if !args[0].has_key?(arg) && metadata[:in_out] == 'OUT' - args[0][arg] = nil - end - end - # Add SELF argument if provided - args[0][:self] = @self if @self - # Add passed parameters to procedure call with parameter names - @call_sql << args[0].map do |arg, value| - "#{arg} => " << add_argument(arg, value) - end.join(', ') - - # Sequential arguments + if subprogram_name + call_sql << "#{full_subprogram_name}(#{add_arguments(arguments)});\n" else - # add SELF as first argument if provided - args.unshift(@self) if @self - argument_count = argument_list.size - raise ArgumentError, "Too many arguments passed to PL/SQL procedure" if args.size > argument_count - # Add missing output arguments with nil value - if args.size < argument_count && - (args.size...argument_count).all?{|i| arguments[argument_list[i]][:in_out] == 'OUT'} - args += [nil] * (argument_count - args.size) - end - # Add passed parameters to procedure call in sequence - @call_sql << (0...args.size).map do |i| - arg = argument_list[i] - value = args[i] - add_argument(arg, value) - end.join(', ') + call_sql << add_arguments(arguments) + call_sql = @subprogram.call_sql(call_sql) end - # finish procedure call construction if procedure name is available - # otherwise will get surrounding call_sql from @procedure (used for table statements) - if procedure_name - @call_sql << ");\n" - else - @call_sql = @procedure.call_sql(@call_sql) - end add_out_variables dbms_output_enable_sql, dbms_output_get_sql = dbms_output_sql - @sql = @declare_sql.empty? ? "" : "DECLARE\n" << @declare_sql - @sql << "BEGIN\n" << @assignment_sql << dbms_output_enable_sql << @call_sql << dbms_output_get_sql << @return_sql << "END;\n" - end - - def add_argument(argument, value, argument_metadata=nil) - argument_metadata ||= arguments[argument] - raise ArgumentError, "Wrong argument #{argument.inspect} passed to PL/SQL procedure" unless argument_metadata - case argument_metadata[:data_type] - when 'PL/SQL RECORD' - add_record_declaration(argument, argument_metadata) - record_assignment_sql, record_bind_values, record_bind_metadata = - record_assignment_sql_values_metadata(argument, argument_metadata, value) - @assignment_sql << record_assignment_sql - @bind_values.merge!(record_bind_values) - @bind_metadata.merge!(record_bind_metadata) - "l_#{argument}" - when 'PL/SQL BOOLEAN' - @declare_sql << "l_#{argument} BOOLEAN;\n" - @assignment_sql << "l_#{argument} := (:#{argument} = 1);\n" - @bind_values[argument] = value.nil? ? nil : (value ? 1 : 0) - @bind_metadata[argument] = argument_metadata.merge(:data_type => "NUMBER", :data_precision => 1) - "l_#{argument}" - else - # TABLE or PL/SQL TABLE type defined inside package - if argument_metadata[:tmp_table_name] - add_table_declaration_and_assignment(argument, argument_metadata) - insert_values_into_tmp_table(argument, argument_metadata, value) - "l_#{argument}" - else - @bind_values[argument] = value - @bind_metadata[argument] = argument_metadata - ":#{argument}" - end - end - end - - def add_table_declaration_and_assignment(argument, argument_metadata) - is_index_by_table = argument_metadata[:data_type] == 'PL/SQL TABLE' - @declare_sql << "l_#{argument} #{argument_metadata[:sql_type_name]}#{is_index_by_table ? nil : " := #{argument_metadata[:sql_type_name]}()"};\n" - @assignment_sql << "FOR r_#{argument} IN c_#{argument} LOOP\n" - @assignment_sql << "l_#{argument}.EXTEND;\n" unless is_index_by_table - case argument_metadata[:element][:data_type] - when 'PL/SQL RECORD' - fields = record_fields_sorted_by_position(argument_metadata[:element][:fields]) - fields_string = is_index_by_table ? "*" : fields.join(', ') - @declare_sql << "CURSOR c_#{argument} IS SELECT #{fields_string} FROM #{argument_metadata[:tmp_table_name]} ORDER BY i__;\n" - if is_index_by_table - fields.each do |field| - @assignment_sql << "l_#{argument}(r_#{argument}.i__).#{field} := r_#{argument}.#{field};\n" - end - else - @assignment_sql << "l_#{argument}(l_#{argument}.COUNT) := r_#{argument};\n" - end - else - @declare_sql << "CURSOR c_#{argument} IS SELECT * FROM #{argument_metadata[:tmp_table_name]} ORDER BY i__;\n" - @assignment_sql << "l_#{argument}(r_#{argument}.i__) := r_#{argument}.element;\n" - end - @assignment_sql << "END LOOP;\n" - @assignment_sql << "DELETE FROM #{argument_metadata[:tmp_table_name]};\n" - end - - def insert_values_into_tmp_table(argument, argument_metadata, values) - return unless values && !values.empty? - is_index_by_table = argument_metadata[:data_type] == 'PL/SQL TABLE' - if is_index_by_table - raise ArgumentError, "Hash value should be passed for #{argument.inspect} argument" unless values.is_a?(Hash) - else - raise ArgumentError, "Array value should be passed for #{argument.inspect} argument" unless values.is_a?(Array) - end - tmp_table = @schema.root_schema.send(argument_metadata[:tmp_table_name]) - # insert values without autocommit - old_autocommit = @schema.connection.autocommit? - @schema.connection.autocommit = false if old_autocommit - tmp_table.delete - case argument_metadata[:element][:data_type] - when 'PL/SQL RECORD' - values_with_index = [] - if is_index_by_table - values.each{|i,v| values_with_index << v.merge(:i__ => i)} - else - values.each_with_index{|v,i| values_with_index << v.merge(:i__ => i+1)} - end - tmp_table.insert values_with_index - else - values_with_index = [] - if is_index_by_table - values.each{|i,v| values_with_index << [v, i]} - else - values.each_with_index{|v,i| values_with_index << [v, i+1]} - end - tmp_table.insert_values [:element, :i__], *values_with_index - end - @schema.connection.autocommit = true if old_autocommit - end - - def add_record_declaration(argument, argument_metadata) - @declare_sql << if argument_metadata[:type_subname] - "l_#{argument} #{argument_metadata[:sql_type_name]};\n" - else - fields_metadata = argument_metadata[:fields] - sql = "TYPE t_#{argument} IS RECORD (\n" - sql << record_fields_sorted_by_position(fields_metadata).map do |field| - metadata = fields_metadata[field] - "#{field} #{type_to_sql(metadata)}" - end.join(",\n") - sql << ");\n" - sql << "l_#{argument} t_#{argument};\n" - end - end - - def record_fields_sorted_by_position(fields_metadata) - fields_metadata.keys.sort_by{|k| fields_metadata[k][:position]} - end - - def record_assignment_sql_values_metadata(argument, argument_metadata, record_value) - sql = "" - bind_values = {} - bind_metadata = {} - (record_value||{}).each do |key, value| - field = key.is_a?(Symbol) ? key : key.to_s.downcase.to_sym - metadata = argument_metadata[:fields][field] - raise ArgumentError, "Wrong field name #{key.inspect} passed to PL/SQL record argument #{argument.inspect}" unless metadata - bind_variable = :"#{argument}_f#{metadata[:position]}" - sql << "l_#{argument}.#{field} := :#{bind_variable};\n" - bind_values[bind_variable] = value - bind_metadata[bind_variable] = metadata - end - [sql, bind_values, bind_metadata] - end - - def add_return - add_return_variable(:return, return_metadata, true) - end - - def add_out_variables - out_list.each do |argument| - add_return_variable(argument, arguments[argument]) - end - end - - def add_return_variable(argument, argument_metadata, is_return_value=false) - case argument_metadata[:data_type] - when 'PL/SQL RECORD' - add_record_declaration(argument, argument_metadata) if is_return_value - argument_metadata[:fields].each do |field, metadata| - # should use different output bind variable as JDBC does not support - # if output bind variable appears in several places - bind_variable = :"#{argument}_o#{metadata[:position]}" - @return_vars << bind_variable - @return_vars_metadata[bind_variable] = metadata - @return_sql << ":#{bind_variable} := l_#{argument}.#{field};\n" - end - "l_#{argument} := " if is_return_value - when 'PL/SQL BOOLEAN' - @declare_sql << "l_#{argument} BOOLEAN;\n" if is_return_value - @declare_sql << "o_#{argument} NUMBER(1);\n" - # should use different output bind variable as JDBC does not support - # if output bind variable appears in several places - bind_variable = :"o_#{argument}" - @return_vars << bind_variable - @return_vars_metadata[bind_variable] = argument_metadata.merge(:data_type => "NUMBER", :data_precision => 1) - @return_sql << "IF l_#{argument} IS NULL THEN\no_#{argument} := NULL;\n" << - "ELSIF l_#{argument} THEN\no_#{argument} := 1;\nELSE\no_#{argument} := 0;\nEND IF;\n" << - ":#{bind_variable} := o_#{argument};\n" - "l_#{argument} := " if is_return_value - else - if argument_metadata[:tmp_table_name] - add_return_table(argument, argument_metadata, is_return_value) - elsif is_return_value - @return_vars << argument - @return_vars_metadata[argument] = argument_metadata - ":#{argument} := " - end - end - end - - def add_return_table(argument, argument_metadata, is_return_value=false) - is_index_by_table = argument_metadata[:data_type] == 'PL/SQL TABLE' - declare_i__ - @declare_sql << "l_return #{return_metadata[:sql_type_name]};\n" if is_return_value - @return_vars << argument - @return_vars_metadata[argument] = argument_metadata.merge(:data_type => "REF CURSOR") - @return_sql << if is_index_by_table - "i__ := l_#{argument}.FIRST;\nLOOP\nEXIT WHEN i__ IS NULL;\n" - else - "IF l_#{argument}.COUNT > 0 THEN\nFOR i__ IN l_#{argument}.FIRST..l_#{argument}.LAST LOOP\n" - end - case argument_metadata[:element][:data_type] - when 'PL/SQL RECORD' - field_names = record_fields_sorted_by_position(argument_metadata[:element][:fields]) - values_string = field_names.map{|f| "l_#{argument}(i__).#{f}"}.join(', ') - @return_sql << "INSERT INTO #{argument_metadata[:tmp_table_name]} VALUES (#{values_string}, i__);\n" - return_fields_string = is_index_by_table ? '*' : field_names.join(', ') - else - @return_sql << "INSERT INTO #{argument_metadata[:tmp_table_name]} VALUES (l_#{argument}(i__), i__);\n" - return_fields_string = '*' - end - @return_sql << "i__ := l_#{argument}.NEXT(i__);\n" if is_index_by_table - @return_sql << "END LOOP;\n" - @return_sql << "END IF;\n" unless is_index_by_table - @return_sql << "OPEN :#{argument} FOR SELECT #{return_fields_string} FROM #{argument_metadata[:tmp_table_name]} ORDER BY i__;\n" - @return_sql << "DELETE FROM #{argument_metadata[:tmp_table_name]};\n" - "l_#{argument} := " if is_return_value - end - - # declare once temp variable i__ that is used as itertor - def declare_i__ - unless @declared_i__ - @declare_sql << "i__ PLS_INTEGER;\n" - @declared_i__ = true - end - end - - def type_to_sql(metadata) - ProcedureCommon.type_to_sql(metadata) + @sql = <<-SQL + DECLARE + #{@declare_sql} + BEGIN + #{@assignment_sql} + #{dbms_output_enable_sql} + #{call_sql} + #{dbms_output_get_sql} + #{@return[:sql]} + END; + SQL end def get_return_value + # create output hash if there are any out variables + output = out_list.inject({}) {|res, k| res[k] = out_variable_value(k); res} if out_list.size > 0 # if function with output parameters if return_metadata && out_list.size > 0 - result = [function_return_value, {}] - out_list.each do |k| - result[1][k] = out_variable_value(k) - end - result + [function_return_value, output] # if function without output parameters elsif return_metadata function_return_value # if procedure with output parameters elsif out_list.size > 0 - result = {} - out_list.each do |k| - result[k] = out_variable_value(k) - end - result - # if procedure without output parameters - else - nil + output end - end - - def function_return_value - return_variable_value(:return, return_metadata) - end - - def out_variable_value(argument) - return_variable_value(argument, arguments[argument]) - end - - def return_variable_value(argument, argument_metadata) - case argument_metadata[:data_type] - when 'PL/SQL RECORD' - return_value = {} - argument_metadata[:fields].each do |field, metadata| - return_value[field] = @cursor[":#{argument}_o#{metadata[:position]}"] - end - return_value - when 'PL/SQL BOOLEAN' - numeric_value = @cursor[":o_#{argument}"] - numeric_value.nil? ? nil : numeric_value == 1 - else - if argument_metadata[:tmp_table_name] - is_index_by_table = argument_metadata[:data_type] == 'PL/SQL TABLE' - case argument_metadata[:element][:data_type] - when 'PL/SQL RECORD' - if is_index_by_table - Hash[*@cursor[":#{argument}"].fetch_hash_all.map{|row| [row.delete(:i__), row]}.flatten] - else - @cursor[":#{argument}"].fetch_hash_all - end - else - if is_index_by_table - Hash[*@cursor[":#{argument}"].fetch_all.map{|row| [row[1], row[0]]}.flatten] - else - @cursor[":#{argument}"].fetch_all.map{|row| row[0]} - end - end - else - @cursor[":#{argument}"] - end - end - end - - def overload_argument_list - @overload_argument_list ||= - @skip_self ? @procedure.argument_list_without_self : @procedure.argument_list - end - - def overload_arguments - @overload_arguments ||= - @skip_self ? @procedure.arguments_without_self : @procedure.arguments - end - - def argument_list - @argument_list ||= overload_argument_list[@overload] - end - - def arguments - @arguments ||= overload_arguments[@overload] - end - - def return_metadata - @return_metadata ||= @procedure.return[@overload] - end - - def out_list - @out_list ||= - @skip_self ? @procedure.out_list_without_self[@overload] : @procedure.out_list[@overload] - end - - def schema_name - @schema_name ||= @procedure.schema_name - end - - def package_name - @package_name ||= @procedure.package - end - - def procedure_name - @procedure_name ||= @procedure.procedure + # nil if procedure without output parameters end def dbms_output_sql - if @dbms_output_stream - dbms_output_enable_sql = "DBMS_OUTPUT.ENABLE(#{@schema.dbms_output_buffer_size});\n" - # if database version is at least 10.2 then use DBMS_OUTPUT.GET_LINES with SYS.DBMSOUTPUT_LINESARRAY - if (@schema.connection.database_version <=> [10, 2, 0, 0]) >= 0 - @declare_sql << "l_dbms_output_numlines INTEGER := #{Schema::DBMS_OUTPUT_MAX_LINES};\n" - dbms_output_get_sql = "DBMS_OUTPUT.GET_LINES(:dbms_output_lines, l_dbms_output_numlines);\n" - @bind_values[:dbms_output_lines] = nil - @bind_metadata[:dbms_output_lines] = {:data_type => 'TABLE', :data_length => nil, - :sql_type_name => "SYS.DBMSOUTPUT_LINESARRAY", :in_out => 'OUT'} - # if database version is less than 10.2 then use individual DBMS_OUTPUT.GET_LINE calls - else - dbms_output_get_sql = "" - end - [dbms_output_enable_sql, dbms_output_get_sql] + return ["", ""] unless output_stream + + dbms_output_enable_sql = "DBMS_OUTPUT.ENABLE(#{@schema.dbms_output_buffer_size});\n" + # if database version is at least 10.2 then use DBMS_OUTPUT.GET_LINES with SYS.DBMSOUTPUT_LINESARRAY + if (@schema.connection.database_version <=> [10, 2, 0, 0]) >= 0 + add_variable_declaration('dbms_output_numlines', 'integer', :value => Schema::DBMS_OUTPUT_MAX_LINES) + dbms_output_get_sql = "DBMS_OUTPUT.GET_LINES(:dbms_output_lines, l_dbms_output_numlines);\n" + bind_value(:dbms_output_lines, nil, + :data_type => 'TABLE', :data_length => nil, + :sql_type_name => "SYS.DBMSOUTPUT_LINESARRAY", :in_out => 'OUT') + # if database version is less than 10.2 then use individual DBMS_OUTPUT.GET_LINE calls else - ["", ""] + dbms_output_get_sql = "" end + [dbms_output_enable_sql, dbms_output_get_sql] end def dbms_output_log - if @dbms_output_stream - # if database version is at least 10.2 then :dbms_output_lines output bind variable has dbms_output lines - if @bind_metadata[:dbms_output_lines] - @cursor[':dbms_output_lines'].each do |line| - @dbms_output_stream.puts "DBMS_OUTPUT: #{line}" if line - end - # if database version is less than 10.2 then use individual DBMS_OUTPUT.GET_LINE calls - else - cursor = @schema.connection.parse("BEGIN sys.dbms_output.get_line(:line, :status); END;") - while true do - cursor.bind_param(':line', nil, :data_type => 'VARCHAR2', :in_out => 'OUT') - cursor.bind_param(':status', nil, :data_type => 'NUMBER', :in_out => 'OUT') - cursor.exec - break unless cursor[':status'] == 0 - @dbms_output_stream.puts "DBMS_OUTPUT: #{cursor[':line']}" - end - cursor.close + return unless output_stream + + # if database version is at least 10.2 then :dbms_output_lines output bind variable has dbms_output lines + if @binds[:metadata][:dbms_output_lines] + @cursor[':dbms_output_lines'].each {|line| output_stream.puts("DBMS_OUTPUT: #{line}") if line} + # if database version is less than 10.2 then use individual DBMS_OUTPUT.GET_LINE calls + else + cursor = @schema.connection.parse("BEGIN sys.dbms_output.get_line(:line, :status); END;") + while true do + cursor.bind_param(':line', nil, :data_type => 'VARCHAR2', :in_out => 'OUT') + cursor.bind_param(':status', nil, :data_type => 'NUMBER', :in_out => 'OUT') + cursor.exec + break unless cursor[':status'] == 0 + output_stream.puts "DBMS_OUTPUT: #{cursor[':line']}" end - @dbms_output_stream.flush + cursor.close end + output_stream.flush end - end - end \ No newline at end of file diff --git a/lib/plsql/schema.rb b/lib/plsql/schema.rb index fbf73453..bc119b6e 100644 --- a/lib/plsql/schema.rb +++ b/lib/plsql/schema.rb @@ -193,24 +193,48 @@ def method_missing(method, *args, &block) def find_database_object(name, override_schema_name = nil) object_schema_name = override_schema_name || schema_name object_name = name.to_s.upcase - if row = select_first( - "SELECT o.object_type, o.object_id, o.status, - (CASE WHEN o.object_type = 'PACKAGE' - THEN (SELECT ob.status FROM all_objects ob - WHERE ob.owner = o.owner AND ob.object_name = o.object_name AND ob.object_type = 'PACKAGE BODY') - ELSE NULL END) body_status - FROM all_objects o - WHERE owner = :owner AND object_name = :object_name - AND object_type IN ('PROCEDURE','FUNCTION','PACKAGE','TABLE','VIEW','SEQUENCE','TYPE','SYNONYM')", - object_schema_name, object_name) - object_type, object_id, status, body_status = row + if (row = select_first(<<-SQL, object_schema_name, object_name)) + SELECT o.object_type, + o.object_id, + o.status, + (CASE + WHEN o.object_type = 'PACKAGE' THEN + (SELECT ob.status + FROM all_objects ob + WHERE ob.owner = o.owner + AND ob.object_name = o.object_name + AND ob.object_type = 'PACKAGE BODY') + ELSE NULL + END) body_status, + (CASE + WHEN o.object_type = 'FUNCTION' THEN + (SELECT p.pipelined + FROM all_procedures p + WHERE p.owner = o.owner + AND p.object_name = o.object_name + AND p.object_type = 'FUNCTION') + ELSE NULL + END) pipelined + FROM all_objects o + WHERE owner = :owner + AND object_name = :object_name + AND object_type IN ('PROCEDURE','FUNCTION','PACKAGE','TABLE','VIEW','SEQUENCE','TYPE','SYNONYM') + SQL + + object_type, object_id, status, body_status, pipelined = row raise ArgumentError, "Database object '#{object_schema_name}.#{object_name}' is not in valid status\n#{ _errors(object_schema_name, object_name, object_type)}" if status == 'INVALID' raise ArgumentError, "Package '#{object_schema_name}.#{object_name}' body is not in valid status\n#{ _errors(object_schema_name, object_name, 'PACKAGE BODY')}" if body_status == 'INVALID' case object_type - when 'PROCEDURE', 'FUNCTION' + when 'PROCEDURE' Procedure.new(self, name, nil, override_schema_name, object_id) + when 'FUNCTION' + if pipelined == 'NO' + Procedure.new(self, name, nil, override_schema_name, object_id) + else + PipelinedFunction.new(self, name, nil, override_schema_name, object_id) + end when 'PACKAGE' Package.new(self, name, override_schema_name) when 'TABLE' diff --git a/lib/plsql/subprogram_call.rb b/lib/plsql/subprogram_call.rb new file mode 100644 index 00000000..62a33981 --- /dev/null +++ b/lib/plsql/subprogram_call.rb @@ -0,0 +1,541 @@ +module PLSQL + # Call of any function or procedure + # TODO: need to be refactored + class SubprogramCall + def initialize(subprogram, args = [], options = {}) + @subprogram = subprogram + @schema = @subprogram.schema + @skip_self = options[:skip_self] + @self = options[:self] + @overload = get_overload_from_arguments_list(args) + @subprogram.ensure_tmp_tables_created(@overload) if @subprogram.respond_to?(:ensure_tmp_tables_created) + construct_sql(args) + end + + private + + def prepare_sql_construction + @declare_sql = "" + @assignment_sql = "" + @binds = {:values => {}, :metadata => {}} + @return = {:sql => '', :variables => [], :metadata => {}} + end + + def get_overload_from_arguments_list(args) + # if not overloaded then overload index 0 is used + return 0 unless @subprogram.overloaded? + # If named arguments are used then + # there should be just one Hash argument with symbol keys + if args.size == 1 && args[0].is_a?(Hash) && args[0].keys.all?{|k| k.is_a?(Symbol)} + args_keys = args[0].keys + # implicit SELF argument for object instance procedures + args_keys << :self if @self && !args_keys.include?(:self) + number_of_args = args_keys.size + matching_overloads = [] # overloads with exact or smaller number of matching named arguments + overload_argument_list.keys.each do |ov| + # assume that missing arguments have default value + missing_arguments_count = overload_argument_list[ov].size - number_of_args + if missing_arguments_count >= 0 && + args_keys.all?{|k| overload_argument_list[ov].include?(k)} + matching_overloads << [ov, missing_arguments_count] + end + end + # pick first matching overload with smallest missing arguments count + # (hoping that missing arguments will be defaulted - cannot find default value from all_arguments) + overload = matching_overloads.sort_by{|ov, score| score}[0][0] + # otherwise try matching by sequential arguments count and types + else + number_of_args = args.size + matching_types = [] + # if implicit SELF argument for object instance procedures should be passed + # then it should be added as first argument to find matches + if @self + number_of_args += 1 + matching_types << ['OBJECT'] + end + args.each do |arg| + matching_types << matching_oracle_types_for_ruby_value(arg) + end + exact_overloads = [] # overloads with exact number of matching arguments + smaller_overloads = [] # overloads with smaller number of matching arguments + # overload = overload_argument_list.keys.detect do |ov| + # overload_argument_list[ov].size == number_of_args + # end + overload_argument_list.keys.each do |ov| + score = 0 # lower score is better match + ov_arg_list_size = overload_argument_list[ov].size + if (number_of_args <= ov_arg_list_size && + (0..(number_of_args-1)).all? do |i| + ov_arg = overload_argument_list[ov][i] + matching_types[i] == :all || # either value matches any type + (ind = matching_types[i].index(overload_arguments[ov][ov_arg][:data_type])) && + (score += ind) # or add index of matched type + end) + if number_of_args == ov_arg_list_size + exact_overloads << [ov, score] + else + smaller_overloads << [ov, score] + end + end + end + # pick either first exact matching overload of first matching with smaller argument count + # (hoping that missing arguments will be defaulted - cannot find default value from all_arguments) + overload = if !exact_overloads.empty? + exact_overloads.sort_by{|ov, score| score}[0][0] + elsif !smaller_overloads.empty? + smaller_overloads.sort_by{|ov, score| score}[0][0] + end + end + raise ArgumentError, "Wrong number or types of arguments passed to overloaded PL/SQL procedure" unless overload + overload + end + + MATCHING_TYPES = { + :integer => ['NUMBER', 'PLS_INTEGER', 'BINARY_INTEGER'], + :decimal => ['NUMBER', 'BINARY_FLOAT', 'BINARY_DOUBLE'], + :string => ['VARCHAR2', 'NVARCHAR2', 'CHAR', 'NCHAR', 'CLOB', 'BLOB'], + :date => ['DATE'], + :time => ['DATE', 'TIMESTAMP', 'TIMESTAMP WITH TIME ZONE', 'TIMESTAMP WITH LOCAL TIME ZONE'], + :boolean => ['PL/SQL BOOLEAN'], + :hash => ['PL/SQL RECORD', 'OBJECT', 'PL/SQL TABLE'], + :array => ['TABLE', 'VARRAY'], + :cursor => ['REF CURSOR'] + } + + def matching_oracle_types_for_ruby_value(value) + case value + when NilClass + :all + when Fixnum, Bignum + MATCHING_TYPES[:integer] + when BigDecimal, Float + MATCHING_TYPES[:decimal] + when String + MATCHING_TYPES[:string] + when Date + MATCHING_TYPES[:date] + when Time + MATCHING_TYPES[:time] + when TrueClass, FalseClass + MATCHING_TYPES[:boolean] + when Hash + MATCHING_TYPES[:hash] + when Array + MATCHING_TYPES[:array] + when CursorCommon + MATCHING_TYPES[:cursor] + end + end + + def add_arguments(arguments) + # Named arguments + # there should be just one Hash argument with symbol keys + if use_named_arguments?(arguments) + add_named_arguments(arguments.first) + # Sequential arguments + else + add_sequential_arguments(arguments) + end + end + + def use_named_arguments?(arguments) + return false unless arguments.size == 1 + arguments = arguments.first + return false unless arguments.is_a?(Hash) && arguments.keys.all?{|k| k.is_a?(Symbol)} + # do not use named arguments if procedure has just one PL/SQL record PL/SQL table or object type argument - + # in that case passed Hash should be used as value for this PL/SQL record argument + # (which will be processed in sequential arguments branch) + + # ensure that first argument is not record/table/object + return true if argument_list.size != 1 + only_argument = argument_list.first + data_type = arguments_metadata[only_argument][:data_type] + !['PL/SQL RECORD','PL/SQL TABLE','OBJECT'].include?(data_type) || arguments.keys == [only_argument] + end + + def add_named_arguments(arguments) + # Add missing output arguments with nil value + arguments_metadata.each do |arg, metadata| + arguments[arg] = nil if !arguments.has_key?(arg) && metadata[:in_out] == 'OUT' + end + + # Add SELF argument if provided + arguments[:self] = @self if @self + # Add passed parameters to procedure call with parameter names + arguments.map {|arg, value| "#{arg} => " << add_argument(arg, value)}.join(', ') + end + + def add_sequential_arguments(arguments) + # add SELF as first argument if provided + arguments.unshift(@self) if @self + argument_count = argument_list.size + raise ArgumentError, "Too many arguments passed to PL/SQL procedure" if arguments.size > argument_count + # Add missing output arguments with nil value + if arguments.size < argument_count && + (arguments.size...argument_count).all?{|i| arguments_metadata[argument_list[i]][:in_out] == 'OUT'} + arguments += [nil] * (argument_count - arguments.size) + end + # Add passed parameters to procedure call in sequence + arguments.map.each_with_index {|arg, idx| add_argument(argument_list[idx], arg)}.join(', ') + end + + def add_argument(argument, value, argument_metadata=nil) + argument_metadata ||= arguments_metadata[argument] + raise ArgumentError, "Wrong argument #{argument.inspect} passed to PL/SQL procedure" unless argument_metadata + case argument_metadata[:data_type] + when 'PL/SQL RECORD' + add_record_declaration(argument, argument_metadata) + record_assignment_sql, record_bind_values, record_bind_metadata = + record_assignment_sql_values_metadata(argument, argument_metadata, value) + @assignment_sql << record_assignment_sql + bind_values(record_bind_values, record_bind_metadata) + "l_#{argument}" + when 'PL/SQL BOOLEAN' + add_variable_declaration(argument, 'boolean') + @assignment_sql << "l_#{argument} := (:#{argument} = 1);\n" + value = value.nil? ? nil : (value ? 1 : 0) + metadata = argument_metadata.merge(:data_type => "NUMBER", :data_precision => 1) + bind_value(argument, value, metadata) + "l_#{argument}" + else + # TABLE or PL/SQL TABLE type defined inside package + if argument_metadata[:tmp_table_name] + add_table_declaration_and_assignment(argument, argument_metadata) + insert_values_into_tmp_table(argument, argument_metadata, value) + "l_#{argument}" + else + bind_value(argument, value, argument_metadata) + ":#{argument}" + end + end + end + + ## Next methods adds declaration in DECLARE block + + def add_variable_declaration(name, type, options = {}) + variable_name = options[:output_variable] ? 'o_' : 'l_' + variable_name << name.to_s << ' ' << type.to_s.upcase + variable_name << ' := '<< options[:value].to_s if options[:value] + variable_name << ";\n" + @declare_sql << variable_name + end + + def add_type_declaration(name, fields_metadata) + fields = record_fields_sorted_by_position(fields_metadata).map do |field| + metadata = fields_metadata[field] + "#{field} #{type_to_sql(metadata)}" + end.join(",\n") + + @declare_sql << "TYPE t_#{name} IS RECORD (\n#{fields});\n" + end + + def add_record_declaration(name, argument_metadata) + if argument_metadata[:type_subname] + add_variable_declaration(name, argument_metadata[:sql_type_name]) + else + add_type_declaration(name, argument_metadata[:fields]) + add_variable_declaration(name, "t_#{name}") + end + end + + def add_cursor_declaration(name, fields, table, order = 'i__') + # make an array + fields = [*fields] + @declare_sql << "CURSOR c_#{name} IS SELECT #{fields.join(', ')} FROM #{table} ORDER BY #{order};\n" + end + + def add_table_declaration_and_assignment(argument, argument_metadata) + is_index_by_table = argument_metadata[:data_type] == 'PL/SQL TABLE' + type = argument_metadata[:sql_type_name] + add_variable_declaration(argument, type, :value => !is_index_by_table && (type + '()')) + + @assignment_sql << "FOR r_#{argument} IN c_#{argument} LOOP\n" + @assignment_sql << "l_#{argument}.EXTEND;\n" unless is_index_by_table + + table_name = argument_metadata[:tmp_table_name] + + if argument_metadata[:element][:data_type] == 'PL/SQL RECORD' + fields = record_fields_sorted_by_position(argument_metadata[:element][:fields]) + add_cursor_declaration(argument, is_index_by_table ? "*" : fields, table_name) + if is_index_by_table + fields.each do |field| + @assignment_sql << "l_#{argument}(r_#{argument}.i__).#{field} := r_#{argument}.#{field};\n" + end + else + @assignment_sql << "l_#{argument}(l_#{argument}.COUNT) := r_#{argument};\n" + end + else + add_cursor_declaration(argument, "*", table_name) + @assignment_sql << "l_#{argument}(r_#{argument}.i__) := r_#{argument}.element;\n" + end + + @assignment_sql << "END LOOP;\n" + @assignment_sql << "DELETE FROM #{table_name};\n" + end + + ## + + def record_fields_sorted_by_position(fields_metadata) + fields_metadata.keys.sort_by{|k| fields_metadata[k][:position]} + end + + def type_to_sql(metadata) + ProcedureCommon.type_to_sql(metadata) + end + + def overload_argument_list + @overload_argument_list ||= + @skip_self ? @subprogram.argument_list_without_self : @subprogram.argument_list + end + + def overload_arguments + @overload_arguments ||= + @skip_self ? @subprogram.arguments_without_self : @subprogram.arguments + end + + def argument_list + @argument_list ||= overload_argument_list[@overload] + end + + def arguments_metadata + @arguments ||= overload_arguments[@overload] + end + + def return_metadata + @return_metadata ||= @subprogram.return[@overload] + end + + def out_list + @out_list ||= + @skip_self ? @subprogram.out_list_without_self[@overload] : @subprogram.out_list[@overload] + end + + def schema_name + @subprogram.schema_name + end + + def package_name + @subprogram.package + end + + def subprogram_name + @subprogram.procedure + end + + def full_subprogram_name + [schema_name, package_name, subprogram_name].compact.join('.') + end + + def function_return_value + return_variable_value(:return, return_metadata) + end + + def out_variable_value(argument) + return_variable_value(argument, arguments_metadata[argument]) + end + + # declare once temp variable l_i__ that is used as iterator + def declare_iterator + unless @declared_i__ + add_variable_declaration(iterator.sub(/^l_/, ''), 'pls_integer') + @declared_i__ = true + end + end + + def iterator + 'l_i__' + end + + def return_variable_value(argument, argument_metadata) + case argument_metadata[:data_type] + when 'PL/SQL RECORD' + return_value = {} + argument_metadata[:fields].each do |field, metadata| + return_value[field] = @cursor[":#{argument}_o#{metadata[:position]}"] + end + return_value + when 'PL/SQL BOOLEAN' + numeric_value = @cursor[":o_#{argument}"] + numeric_value.nil? ? nil : numeric_value == 1 + else + if argument_metadata[:tmp_table_name] + is_index_by_table = argument_metadata[:data_type] == 'PL/SQL TABLE' + case argument_metadata[:element][:data_type] + when 'PL/SQL RECORD' + if is_index_by_table + Hash[*@cursor[":#{argument}"].fetch_hash_all.map{|row| [row.delete(:i__), row]}.flatten] + else + @cursor[":#{argument}"].fetch_hash_all + end + else + if is_index_by_table + Hash[*@cursor[":#{argument}"].fetch_all.map{|row| [row[1], row[0]]}.flatten] + else + @cursor[":#{argument}"].fetch_all.map{|row| row[0]} + end + end + else + @cursor[":#{argument}"] + end + end + end + + def record_assignment_sql_values_metadata(argument, argument_metadata, record_value) + sql = "" + bind_values = {} + bind_metadata = {} + (record_value||{}).each do |key, value| + field = key.is_a?(Symbol) ? key : key.to_s.downcase.to_sym + metadata = argument_metadata[:fields][field] + raise ArgumentError, "Wrong field name #{key.inspect} passed to PL/SQL record argument #{argument.inspect}" unless metadata + bind_variable = :"#{argument}_f#{metadata[:position]}" + sql << "l_#{argument}.#{field} := :#{bind_variable};\n" + bind_values[bind_variable] = value + bind_metadata[bind_variable] = metadata + end + [sql, bind_values, bind_metadata] + end + + def add_return + add_return_variable(:return, return_metadata, true) + end + + def add_out_variables + out_list.each do |argument| + add_return_variable(argument, arguments_metadata[argument]) + end + end + + def add_return_variable(argument, argument_metadata, is_return_value = false) + case argument_metadata[:data_type] + when 'PL/SQL RECORD' + add_record_declaration(argument, argument_metadata) if is_return_value + argument_metadata[:fields].each do |field, metadata| + # should use different output bind variable as JDBC does not support + # if output bind variable appears in several places + bind_variable = :"#{argument}_o#{metadata[:position]}" + bind_return_variable(bind_variable, metadata, ":#{bind_variable} := l_#{argument}.#{field};") + end + "l_#{argument} := " if is_return_value + when 'PL/SQL BOOLEAN' + add_variable_declaration(argument, 'boolean') if is_return_value + add_variable_declaration(argument, 'number(1)', :output_variable => true) + + # should use different output bind variable as JDBC does not support + # if output bind variable appears in several places + bind_variable = :"o_#{argument}" + bind_return_variable(bind_variable, argument_metadata.merge(:data_type => "NUMBER", :data_precision => 1), <<-SQL) + IF l_#{argument} IS NULL THEN + #{bind_variable} := NULL; + ELSIF l_#{argument} THEN + #{bind_variable} := 1; + ELSE + #{bind_variable} := 0; + END IF; + :#{bind_variable} := #{bind_variable}; + SQL + "l_#{argument} := " if is_return_value + else + if argument_metadata[:tmp_table_name] + add_return_table(argument, argument_metadata, is_return_value) + elsif is_return_value + bind_return_variable(argument, argument_metadata) + ":#{argument} := " + end + end + end + + def bind_return_variable(name, metadata, sql = nil) + @return[:sql] << sql << "\n" if sql + @return[:variables] << name + @return[:metadata][name] = metadata + end + + def bind_value(name, value, metadata) + bind_values({name => value}, {name => metadata}) + end + + def bind_values(values, metadata) + @binds[:values].merge!(values) + @binds[:metadata].merge!(metadata) + end + + def add_return_table(argument, argument_metadata, is_return_value = false) + is_index_by_table = argument_metadata[:data_type] == 'PL/SQL TABLE' + table_name = argument_metadata[:tmp_table_name] + declare_iterator + add_variable_declaration('return', return_metadata[:sql_type_name]) if is_return_value + + if argument_metadata[:element][:data_type] == 'PL/SQL RECORD' + field_names = record_fields_sorted_by_position(argument_metadata[:element][:fields]) + values_string = field_names.map{|f| "l_#{argument}(#{iterator}).#{f}"}.join(', ') + return_fields_string = is_index_by_table ? '*' : field_names.join(', ') + else + values_string = "l_#{argument}(#{iterator})" + return_fields_string = '*' + end + + if is_index_by_table + return_sql = <<-SQL + #{iterator} := l_#{argument}.FIRST; + LOOP + EXIT WHEN #{iterator} IS NULL; + INSERT INTO #{table_name} VALUES (#{values_string}, #{iterator}); + #{iterator} := l_#{argument}.NEXT(#{iterator}); + END LOOP; + SQL + else + return_sql = <<-SQL + IF l_#{argument}.COUNT > 0 THEN + FOR #{iterator} IN l_#{argument}.FIRST..l_#{argument}.LAST + LOOP + INSERT INTO #{table_name} VALUES (#{values_string}, #{iterator}); + END LOOP; + END IF; + SQL + end + + return_sql << <<-SQL + OPEN :#{argument} FOR SELECT #{return_fields_string} FROM #{table_name} ORDER BY i__; + DELETE FROM #{table_name}; + SQL + + bind_return_variable(argument, argument_metadata.merge(:data_type => "REF CURSOR"), return_sql) + "l_#{argument} := " if is_return_value + end + + def insert_values_into_tmp_table(argument, argument_metadata, values) + return unless values && !values.empty? + is_index_by_table = argument_metadata[:data_type] == 'PL/SQL TABLE' + if is_index_by_table + raise ArgumentError, "Hash value should be passed for #{argument.inspect} argument" unless values.is_a?(Hash) + else + raise ArgumentError, "Array value should be passed for #{argument.inspect} argument" unless values.is_a?(Array) + end + tmp_table = @schema.root_schema.send(argument_metadata[:tmp_table_name]) + # insert values without autocommit + old_autocommit = @schema.connection.autocommit? + @schema.connection.autocommit = false if old_autocommit + tmp_table.delete + case argument_metadata[:element][:data_type] + when 'PL/SQL RECORD' + values_with_index = [] + if is_index_by_table + values.each{|i,v| values_with_index << v.merge(:i__ => i)} + else + values.each_with_index{|v,i| values_with_index << v.merge(:i__ => i+1)} + end + tmp_table.insert values_with_index + else + values_with_index = [] + if is_index_by_table + values.each{|i,v| values_with_index << [v, i]} + else + values.each_with_index{|v,i| values_with_index << [v, i+1]} + end + tmp_table.insert_values [:element, :i__], *values_with_index + end + @schema.connection.autocommit = true if old_autocommit + end + end +end \ No newline at end of file diff --git a/lib/ruby_plsql.rb b/lib/ruby_plsql.rb index b098c394..f04b749f 100644 --- a/lib/ruby_plsql.rb +++ b/lib/ruby_plsql.rb @@ -2,12 +2,17 @@ require "date" require "bigdecimal" -%w(connection sql_statements schema procedure procedure_call package variable table view sequence type version helpers).each do |file| +%w(connection sql_statements schema + procedure subprogram_call procedure_call + pipelined_function pipelined_function_call + package variable + table view sequence type + version helpers).each do |file| require "plsql/#{file}" end -unless defined?(JRUBY_VERSION) - require "plsql/oci_connection" -else +if defined?(JRUBY_VERSION) require "plsql/jdbc_connection" +else + require "plsql/oci_connection" end diff --git a/spec/plsql/package_spec.rb b/spec/plsql/package_spec.rb index d982bfa9..ba7f0614 100644 --- a/spec/plsql/package_spec.rb +++ b/spec/plsql/package_spec.rb @@ -3,15 +3,40 @@ describe "Package" do before(:all) do plsql.connection = get_connection + # Not use ROWTYPE definition due to Oracle bug (see http://arjudba.blogspot.com/2011/12/ora-00600-internal-error-code-arguments.html) plsql.execute <<-SQL CREATE OR REPLACE PACKAGE test_package IS + TYPE object_record IS RECORD( + owner ALL_OBJECTS.OWNER%TYPE, + object_name ALL_OBJECTS.OBJECT_NAME%TYPE, + object_id ALL_OBJECTS.OBJECT_ID%TYPE, + object_type ALL_OBJECTS.OBJECT_TYPE%TYPE); + TYPE objects_list IS TABLE OF object_record; + + FUNCTION find_objects_by_name ( p_name ALL_OBJECTS.OBJECT_NAME%TYPE ) + RETURN objects_list PIPELINED; + test_variable NUMBER; FUNCTION test_procedure ( p_string VARCHAR2 ) RETURN VARCHAR2; - END; + END test_package; SQL plsql.execute <<-SQL CREATE OR REPLACE PACKAGE BODY test_package IS + FUNCTION find_objects_by_name ( p_name ALL_OBJECTS.OBJECT_NAME%TYPE ) + RETURN objects_list PIPELINED + IS + BEGIN + FOR l_object IN ( + SELECT OWNER, OBJECT_NAME, OBJECT_ID, OBJECT_TYPE + FROM ALL_OBJECTS + WHERE OBJECT_NAME = UPPER(p_name) + AND ROWNUM < 11) + LOOP + PIPE ROW(l_object); + END LOOP; + END find_objects_by_name; + FUNCTION test_procedure ( p_string VARCHAR2 ) RETURN VARCHAR2 IS @@ -20,7 +45,6 @@ END test_procedure; END; SQL - end after(:all) do @@ -43,6 +67,16 @@ plsql.test_package.class.should == PLSQL::Package end + it "should search objects via []" do + PLSQL::Package.find(plsql, :test_package)['test_procedure'].should be_a PLSQL::Procedure + PLSQL::Package.find(plsql, :test_package)['test_variable'].should be_a PLSQL::Variable + end + + it "should tell ordinary function from pipelined" do + PLSQL::Package.find(plsql, :test_package)['test_procedure'].should be_a PLSQL::Procedure + PLSQL::Package.find(plsql, :test_package)['find_objects_by_name'].should be_a PLSQL::PipelinedFunction + end + it "should execute package function and return correct value" do plsql.test_package.test_procedure('xxx').should == 'XXX' end diff --git a/spec/plsql/pipelined_function_spec.rb b/spec/plsql/pipelined_function_spec.rb new file mode 100644 index 00000000..63ad0ae6 --- /dev/null +++ b/spec/plsql/pipelined_function_spec.rb @@ -0,0 +1,94 @@ +require 'spec_helper' + +describe "PipelinedFunction" do + before(:all) do + plsql.connection = get_connection + # Not use ROWTYPE definition due to Oracle bug (see http://arjudba.blogspot.com/2011/12/ora-00600-internal-error-code-arguments.html) + plsql.execute(<<-SQL) + CREATE OR REPLACE PACKAGE test_package IS + TYPE object_record IS RECORD( + owner ALL_OBJECTS.OWNER%TYPE, + object_name ALL_OBJECTS.OBJECT_NAME%TYPE, + object_id ALL_OBJECTS.OBJECT_ID%TYPE, + object_type ALL_OBJECTS.OBJECT_TYPE%TYPE); + TYPE objects_list IS TABLE OF object_record; + + FUNCTION find_objects_by_name ( p_name ALL_OBJECTS.OBJECT_NAME%TYPE ) + RETURN objects_list PIPELINED; + END test_package; + SQL + + plsql.execute(<<-SQL) + CREATE OR REPLACE PACKAGE BODY test_package IS + FUNCTION find_objects_by_name ( p_name ALL_OBJECTS.OBJECT_NAME%TYPE ) + RETURN objects_list PIPELINED + IS + BEGIN + FOR l_object IN ( + SELECT OWNER, OBJECT_NAME, OBJECT_ID, OBJECT_TYPE + FROM ALL_OBJECTS + WHERE OBJECT_NAME LIKE UPPER(p_name) + AND ROWNUM < 11) + LOOP + PIPE ROW(l_object); + END LOOP; + END find_objects_by_name; + END; + SQL + + plsql.execute(<<-SQL) + CREATE OR REPLACE TYPE test_numbers AS TABLE OF NUMBER; + SQL + + plsql.execute(<<-SQL) + CREATE OR REPLACE + FUNCTION test_pipelined_func (p_high NUMBER) + RETURN test_numbers PIPELINED + IS + l_cnt NUMBER := p_high; + BEGIN + LOOP + PIPE ROW(l_cnt); + l_cnt := l_cnt - 1; + EXIT WHEN l_cnt < 0; + END LOOP; + END test_pipelined_func; + SQL + end + + after(:all) do + plsql.execute "DROP PACKAGE test_package" + plsql.execute "DROP FUNCTION test_pipelined_func" + plsql.execute "DROP TYPE test_numbers" + plsql.logoff + end + + it "should identify arguments" do + arguments = plsql.test_package['find_objects_by_name'].arguments + arguments.should be_an Enumerable + arguments.size.should == 1 + end + + it "should identify returning table type" do + return_type = plsql.test_package['find_objects_by_name'].return + return_type[:data_type].should == 'TABLE' + end + + it "should returns an array of hashes on exec" do + duals = plsql.test_package.find_objects_by_name(:p_name => 'DUAL') + duals.size.should == 2 + duals[0].should be_a Hash + duals[0]['object_name'].should == 'DUAL' + + numbers = PLSQL::PipelinedFunction.find(plsql, :test_pipelined_func).exec(10) + numbers.size.should == 11 + numbers.last['column_value'].should == 0 + end + + it "should iterate over result set if block given" do + sys_objects = [] + plsql.test_package.find_objects_by_name(:p_name => '%#') {|row| sys_objects << row} + sys_objects.size.should == 10 + sys_objects.map{|object| object['object_name'][-1..-1]}.uniq.should == %w(#) + end +end \ No newline at end of file diff --git a/spec/spec_helper.rb b/spec/spec_helper.rb index ac51625c..e08a30a5 100644 --- a/spec/spec_helper.rb +++ b/spec/spec_helper.rb @@ -15,8 +15,15 @@ require 'ruby-plsql' DATABASE_NAME = ENV['DATABASE_NAME'] || 'orcl' -DATABASE_HOST = ENV['DATABASE_HOST'] || 'localhost' -DATABASE_PORT = ENV['DATABASE_PORT'] || 1521 + +if ENV['DATABASE_USE_TNS_NAMES'] + DATABASE_HOST = nil + DATABASE_PORT = nil +else + DATABASE_HOST = ENV['DATABASE_HOST'] || 'localhost' + DATABASE_PORT = ENV['DATABASE_PORT'] || 1521 +end + DATABASE_USERS_AND_PASSWORDS = [ [ENV['DATABASE_USER'] || 'hr', ENV['DATABASE_PASSWORD'] || 'hr'], [ENV['DATABASE_USER2'] || 'arunit', ENV['DATABASE_PASSWORD2'] || 'arunit'] @@ -26,15 +33,7 @@ def get_connection(user_number = 0) database_user, database_password = DATABASE_USERS_AND_PASSWORDS[user_number] - unless defined?(JRUBY_VERSION) - begin - OCI8.new(database_user, database_password, DATABASE_NAME) - # if connection fails then sleep 5 seconds and retry - rescue OCIError - sleep 5 - OCI8.new(database_user, database_password, DATABASE_NAME) - end - else + if defined?(JRUBY_VERSION) begin java.sql.DriverManager.getConnection("jdbc:oracle:thin:@#{DATABASE_HOST}:#{DATABASE_PORT}:#{DATABASE_NAME}", database_user, database_password) @@ -44,6 +43,14 @@ def get_connection(user_number = 0) java.sql.DriverManager.getConnection("jdbc:oracle:thin:@#{DATABASE_HOST}:#{DATABASE_PORT}:#{DATABASE_NAME}", database_user, database_password) end + else + begin + OCI8.new(database_user, database_password, DATABASE_NAME) + # if connection fails then sleep 5 seconds and retry + rescue OCIError + sleep 5 + OCI8.new(database_user, database_password, DATABASE_NAME) + end end end