diff --git a/lib/plsql/procedure.rb b/lib/plsql/procedure.rb index 08ffce6..c9ec875 100644 --- a/lib/plsql/procedure.rb +++ b/lib/plsql/procedure.rb @@ -83,6 +83,14 @@ def self.type_to_sql(metadata) #:nodoc: # get procedure argument metadata from data dictionary def get_argument_metadata #:nodoc: + if (@schema.connection.database_version <=> [18, 0, 0, 0]) >= 0 + get_argument_metadata_from_18c + else + get_argument_metadata_below_18c + end + end + + def get_argument_metadata_below_18c #:nodoc: @arguments = {} @argument_list = {} @out_list = {} @@ -197,6 +205,99 @@ def get_argument_metadata #:nodoc: construct_argument_list_for_overloads end + # get procedure argument metadata from data dictionary + def get_argument_metadata_from_18c #:nodoc: + @arguments = {} + @argument_list = {} + @out_list = {} + @return = {} + @overloaded = false + + # store tmp tables for each overload for table parameters with types defined inside packages + @tmp_table_names = {} + # store if tmp tables are created for specific overload + @tmp_tables_created = {} + + @schema.select_all( + "SELECT subprogram_id, object_name, TO_NUMBER(overload), argument_name, position, + data_type, in_out, data_length, data_precision, data_scale, char_used, + char_length, type_owner, nvl(type_subname, type_name), + decode(type_object_type, 'PACKAGE', type_name, null), type_object_type, defaulted + FROM all_arguments + WHERE object_id = :object_id + AND owner = :owner + AND object_name = :procedure_name + ORDER BY overload, sequence", + @object_id, @schema_name, @procedure + ) do |r| + + subprogram_id, object_name, overload, argument_name, position, + data_type, in_out, data_length, data_precision, data_scale, char_used, + char_length, type_owner, type_name, type_package, type_object_type, defaulted = r + + @overloaded ||= !overload.nil? + # if not overloaded then store arguments at key 0 + overload ||= 0 + @arguments[overload] ||= {} + @return[overload] ||= nil + @tmp_table_names[overload] ||= [] + + sql_type_name = build_sql_type_name(type_owner, type_package, type_name) + + tmp_table_name = nil + # type defined inside package + if type_package + if collection_type?(data_type) + tmp_table_name = "#{Connection::RUBY_TEMP_TABLE_PREFIX}#{@schema.connection.session_id}_#{@object_id}_#{subprogram_id}_#{position}" + end + end + + argument_metadata = { + position: position && position.to_i, + data_type: data_type, + in_out: in_out, + data_length: data_length && data_length.to_i, + data_precision: data_precision && data_precision.to_i, + data_scale: data_scale && data_scale.to_i, + char_used: char_used, + char_length: char_length && char_length.to_i, + type_owner: type_owner, + type_name: type_name, + # TODO: should be renamed to type_package, when support for legacy database versions is dropped + # due to the explicit change declaration of types in oracle plsql_type-catalogs (type_package + type_name), + # the assignment of type + subtype was switched here for 18c and beyond + type_subname: type_package, + sql_type_name: sql_type_name, + defaulted: defaulted, + type_object_type: type_object_type + } + if tmp_table_name + @tmp_table_names[overload] << [(argument_metadata[:tmp_table_name] = tmp_table_name), argument_metadata] + end + + if composite_type?(data_type) + case data_type + when "PL/SQL RECORD", "REF CURSOR" + argument_metadata[:fields] = get_field_definitions(argument_metadata) + when "PL/SQL TABLE", "TABLE", "VARRAY" + argument_metadata[:element] = get_element_definition(argument_metadata) + end + end + + # if function has return value + if argument_name.nil? && in_out == "OUT" + @return[overload] = argument_metadata + else + # sometime there are empty IN arguments in all_arguments view for procedures without arguments (e.g. for DBMS_OUTPUT.DISABLE) + @arguments[overload][argument_name.downcase.to_sym] = argument_metadata if argument_name + end + end + # if procedure is without arguments then create default empty argument list for default overload + @arguments[0] = {} if @arguments.keys.empty? + + construct_argument_list_for_overloads + end + def construct_argument_list_for_overloads #:nodoc: @overloads = @arguments.keys.sort @overloads.each do |overload| @@ -229,6 +330,185 @@ def ensure_tmp_tables_created(overload) #:nodoc: @tmp_tables_created[overload] = true end + def build_sql_type_name(type_owner, type_package, type_name) #:nodoc: + if type_owner == nil || type_owner == "PUBLIC" + type_owner_res = "" + else + type_owner_res = "#{type_owner}." + end + + if type_package == nil + type_name_res = type_name + else + type_name_res = "#{type_package}.#{type_name}" + end + type_name_res && "#{type_owner_res}#{type_name_res}" + end + + def get_field_definitions(argument_metadata) #:nodoc: + fields = {} + case argument_metadata[:type_object_type] + when "PACKAGE" + @schema.select_all( + "SELECT attr_no, attr_name, attr_type_owner, attr_type_name, attr_type_package, length, precision, scale, char_used + FROM ALL_PLSQL_TYPES t, ALL_PLSQL_TYPE_ATTRS ta + WHERE t.OWNER = :owner AND t.type_name = :type_name AND t.package_name = :package_name + AND ta.OWNER = t.owner AND ta.TYPE_NAME = t.TYPE_NAME AND ta.PACKAGE_NAME = t.PACKAGE_NAME + ORDER BY attr_no", + @schema_name, argument_metadata[:type_name], argument_metadata[:type_subname]) do |r| + + attr_no, attr_name, attr_type_owner, attr_type_name, attr_type_package, attr_length, attr_precision, attr_scale, attr_char_used = r + + fields[attr_name.downcase.to_sym] = { + position: attr_no.to_i, + data_type: attr_type_owner == nil ? attr_type_name : get_composite_type(attr_type_owner, attr_type_name, attr_type_package), + in_out: argument_metadata[:in_out], + data_length: attr_length && attr_length.to_i, + data_precision: attr_precision && attr_precision.to_i, + data_scale: attr_scale && attr_scale.to_i, + char_used: attr_char_used == nil ? "0" : attr_char_used, + char_length: attr_char_used && attr_length && attr_length.to_i, + type_owner: attr_type_owner, + type_name: attr_type_owner && attr_type_name, + type_subname: attr_type_package, + sql_type_name: attr_type_owner && build_sql_type_name(attr_type_owner, attr_type_package, attr_type_name), + defaulted: argument_metadata[:defaulted] + } + + if fields[attr_name.downcase.to_sym][:data_type] == "TABLE" && fields[attr_name.downcase.to_sym][:type_subname] != nil + fields[attr_name.downcase.to_sym][:fields] = get_field_definitions(fields[attr_name.downcase.to_sym]) + end + end + when "TABLE", "VIEW" + @schema.select_all( + "SELECT column_id, column_name, data_type, data_length, data_precision, data_scale, char_length, char_used + FROM ALL_TAB_COLS WHERE OWNER = :owner AND TABLE_NAME = :type_name + ORDER BY column_id", + @schema_name, argument_metadata[:type_name]) do |r| + + col_no, col_name, col_type_name, col_length, col_precision, col_scale, col_char_length, col_char_used = r + + fields[col_name.downcase.to_sym] = { + position: col_no.to_i, + data_type: col_type_name, + in_out: argument_metadata[:in_out], + data_length: col_length && col_length.to_i, + data_precision: col_precision && col_precision.to_i, + data_scale: col_scale && col_scale.to_i, + char_used: col_char_used == nil ? "0" : col_char_used, + char_length: col_char_length && col_char_length.to_i, + type_owner: nil, + type_name: nil, + type_subname: nil, + sql_type_name: nil, + defaulted: argument_metadata[:defaulted] + } + end + end + fields + end + + def get_element_definition(argument_metadata) #:nodoc: + element_metadata = {} + if collection_type?(argument_metadata[:data_type]) + case argument_metadata[:type_object_type] + when "PACKAGE" + r = @schema.select_first( + "SELECT elem_type_owner, elem_type_name, elem_type_package, length, precision, scale, char_used, index_by + FROM ALL_PLSQL_COLL_TYPES t + WHERE t.OWNER = :owner AND t.TYPE_NAME = :type_name AND t.PACKAGE_NAME = :package_name", + @schema_name, argument_metadata[:type_name], argument_metadata[:type_subname]) + + elem_type_owner, elem_type_name, elem_type_package, elem_length, elem_precision, elem_scale, elem_char_used, index_by = r + + if index_by == "VARCHAR2" + raise ArgumentError, "Index-by Varchar-Table (associative array) #{argument_metadata[:type_name]} is not supported" + end + + element_metadata = { + position: 1, + data_type: if elem_type_owner == nil + elem_type_name + else + elem_type_package != nil ? "PL/SQL RECORD" : "OBJECT" + end, + in_out: argument_metadata[:in_out], + data_length: elem_length && elem_length.to_i, + data_precision: elem_precision && elem_precision.to_i, + data_scale: elem_scale && elem_scale.to_i, + char_used: elem_char_used, + char_length: elem_char_used && elem_length && elem_length.to_i, + type_owner: elem_type_owner, + type_name: elem_type_name, + type_subname: elem_type_package, + sql_type_name: elem_type_owner && build_sql_type_name(elem_type_owner, elem_type_package, elem_type_name), + type_object_type: elem_type_package != nil ? "PACKAGE" : nil, + defaulted: argument_metadata[:defaulted] + } + + if elem_type_package != nil + element_metadata[:fields] = get_field_definitions(element_metadata) + end + when "TYPE" + r = @schema.select_first( + "SELECT elem_type_owner, elem_type_name, length, precision, scale, char_used + FROM ALL_COLL_TYPES t + WHERE t.owner = :owner AND t.TYPE_NAME = :type_name", + @schema_name, argument_metadata[:type_name] + ) + elem_type_owner, elem_type_name, elem_length, elem_precision, elem_scale, elem_char_used = r + + element_metadata = { + position: 1, + data_type: elem_type_owner == nil ? elem_type_name : "OBJECT", + in_out: argument_metadata[:in_out], + data_length: elem_length && elem_length.to_i, + data_precision: elem_precision && elem_precision.to_i, + data_scale: elem_scale && elem_scale.to_i, + char_used: elem_char_used, + char_length: elem_char_used && elem_length && elem_length.to_i, + type_owner: elem_type_owner, + type_name: elem_type_name, + type_subname: nil, + sql_type_name: elem_type_owner && build_sql_type_name(elem_type_owner, nil, elem_type_name), + defaulted: argument_metadata[:defaulted] + } + end + else + element_metadata = { + position: 1, + data_type: "PL/SQL RECORD", + in_out: argument_metadata[:in_out], + data_length: nil, + data_precision: nil, + data_scale: nil, + char_used: "B", + char_length: 0, + type_owner: argument_metadata[:type_owner], + type_name: argument_metadata[:type_name], + type_subname: argument_metadata[:type_subname], + sql_type_name: build_sql_type_name(argument_metadata[:type_owner], argument_metadata[:type_subname], argument_metadata[:type_name]), + defaulted: argument_metadata[:defaulted] + } + + if element_metadata[:type_subname] != nil + element_metadata[:fields] = get_field_definitions(element_metadata) + end + end + element_metadata + end + + def get_composite_type(type_owner, type_name, type_package) + r = @schema.select_first("SELECT typecode FROM all_plsql_types WHERE owner = :owner AND type_name = :type_name AND package_name = :type_package + UNION ALL + SELECT typecode FROM all_types WHERE owner = :owner AND type_name = :type_name", + type_owner, type_name, type_package, type_owner, type_name) + typecode = r[0] + raise ArgumentError, "#{type_name} type #{build_sql_type_name(type_owner, type_package, type_name)} definition inside package is not supported as part of other type definition," << + " use CREATE TYPE outside package" if typecode == "COLLECTION" + typecode + end + PLSQL_COMPOSITE_TYPES = ["PL/SQL RECORD", "PL/SQL TABLE", "TABLE", "VARRAY", "REF CURSOR"].freeze def composite_type?(data_type) #:nodoc: PLSQL_COMPOSITE_TYPES.include? data_type diff --git a/spec/plsql/procedure_spec.rb b/spec/plsql/procedure_spec.rb index d91556d..f303978 100644 --- a/spec/plsql/procedure_spec.rb +++ b/spec/plsql/procedure_spec.rb @@ -687,7 +687,7 @@ is_approved BOOLEAN ); - TYPE table_of_records IS TABLE OF t_employee; + TYPE table_of_records IS TABLE OF test_record.t_employee; FUNCTION test_full_name(p_employee t_employee) RETURN VARCHAR2; @@ -1101,7 +1101,7 @@ def new_candidate(status) last_name VARCHAR(50), hire_date DATE ); - TYPE t_employees IS TABLE OF t_employee; + TYPE t_employees IS TABLE OF test_collections.t_employee; FUNCTION test_employees (p_employees IN OUT t_employees) RETURN t_employees; -- these types with tables in lower level are not yet supported @@ -1110,7 +1110,7 @@ def new_candidate(status) first_name VARCHAR2(50), last_name VARCHAR(50), hire_date DATE, - numbers t_numbers + numbers test_collections.t_numbers ); FUNCTION test_employee2 (p_employee IN OUT t_employee2) RETURN t_employee2; @@ -1366,7 +1366,7 @@ def new_candidate(status) last_name VARCHAR(50), hire_date DATE ); - TYPE t_employees IS TABLE OF t_employee + TYPE t_employees IS TABLE OF test_collections.t_employee INDEX BY BINARY_INTEGER; FUNCTION test_employees (p_employees IN OUT t_employees) RETURN t_employees;