Skip to content
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -9,3 +9,4 @@ log
tmp
sqlnet.log
Gemfile.lock
.idea
84 changes: 48 additions & 36 deletions lib/plsql/package.rb
Original file line number Diff line number Diff line change
@@ -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

Expand All @@ -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

Expand Down
77 changes: 77 additions & 0 deletions lib/plsql/pipelined_function.rb
Original file line number Diff line number Diff line change
@@ -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
76 changes: 76 additions & 0 deletions lib/plsql/pipelined_function_call.rb
Original file line number Diff line number Diff line change
@@ -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
86 changes: 49 additions & 37 deletions lib/plsql/procedure.rb
Original file line number Diff line number Diff line change
@@ -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:
Expand Down Expand Up @@ -253,5 +266,4 @@ def exec(*args, &block)
end

end

end
Loading