Ruby/OCI8 High-level API

[ Home ] [ English | Japanese ]

Ruby/OCI8 is divided to two layer APIs. One is "Low-level API". The other is "High-level API". This document describes how to use the latter, but some of the former will be described as long as it is necessary to use the latter.

"High-level API" is the library written by ruby, which based on "Low-level API". This API hides complicated structure of OCI and make it easy to issue SQL statements as possible. Please use this for general purpose.

"Low-level API" is the library written by C language. OCI *1 handles and OCI functions become ruby's classes and methods respectively. The handles and functions are converted by straight mapping rule as long as ruby's syntax allows.

In the version 0.2 I will rewrite High-level API by C language directly. Low-level API will be obsolete.

Contents

Classes List

Indispensable Classes to use high-level API are OCI8, OCI8::Cursor, OCI8::BLOB and OCI Exception Classes.

OCI8

The instance of this class corresponds to the connection with database, which corresponds to java.sql.Connection of JDBC and database handle $dbh of Perl/DBI.

To execute simple SQL, it can perform by this class only.

OCI8::Cursor

The instance of this class corresponds to cursor in the term of Oracle, which corresponds to java.sql.Statement of JDBC and statement handle $sth of Perl/DBI.

Don't create the instance by calling 'new' method. Please create it by calling OCI8#exec or OCI8#parse.

OCI8::BLOB

This is a lob locator to read/write binary data to/from BLOB column. This instance is automatically generated by select statement.

OCI Exception Classes

The class hierarchy of OCI exception class used in high-level API is as follows.

OCIException is the abstract class for all OCI exceptions. To rescue all OCI exceptions, please use this class.

OCIError is the exception class with Oracle's error code. You get the error message by OCIError#message. The error code by OCIError#code.

OCIInvalidHandle is raised when OCI call is performed to the invalid handle.

OCIBreak is raised when the OCI call is canceled by other thread. See also Blocking/Non-Blocking Mode.

Methods List

OCI8

OCI8.new(userid, password, dbname = nil, privilege = nil)

Connects to Oracle by userid and password. dbname is the connect string of Net8. If you need DBA privilege, please set privilege as :SYSDBA or :SYSOPER.

example:

# sqlplus scott/tiger@orcl.world
conn = OCI8.new("scott", "tiger", "orcl.world")

example:

# sqlplus 'sys/change_on_install as sysdba'
conn = OCI8.new("sys", "change_on_install", nil, :SYSDBA)
OCI8#logoff()

Disconnects from Oracle. Uncommitted transaction will be rollbacked.

example:

conn = OCI8.new("scott", "tiger")
... do something ...
conn.logoff
OCI8#exec(sql, *bindvars)

Executes the sql statement. The type of return value depends on the type of sql statement: select; insert, update and delete; create, alter and drop; and PL/SQL.

When bindvars are specified, they are bound as bind variables before execution.

In case of select statement with no block, it returns the instance of OCI8::Cursor.

example:

conn = OCI8.new('scott', 'tiger')
cursor = conn.exec('SELECT * FROM emp')
while r = cursor.fetch()
  puts r.join(',')
end
cursor.close
conn.logoff

In case of select statement with a block, it acts as iterator and returns the processed row counts. Fetched data is passed to the block as array. NULL value becomes nil in ruby.

example:

conn = OCI8.new('scott', 'tiger')
num_rows = conn.exec('SELECT * FROM emp') do |r|
  puts r.join(',')
end
puts num_rows.to_s + ' rows were processed.'
conn.logoff

In case of insert, update or delete statement, it returns the number of processed rows.

example:

conn = OCI8.new('scott', 'tiger')
num_rows = conn.exec('UPDATE emp SET sal = sal * 1.1')
puts num_rows.to_s + ' rows were updated.'
conn.logoff

In case of create, alter or drop statement, it returns true.

example:

conn = OCI8.new('scott', 'tiger')
conn.exec('CREATE TABLE test (col1 CHAR(6))')
conn.logoff

In case of PL/SQL statement, it returns the array of bind variables.

example:

conn = OCI8.new('scott', 'tiger')
conn.exec("BEGIN :str := TO_CHAR(:num, 'FM0999'); END;", 'ABCD', 123)
# => ["0123", 123]
conn.logoff

Above example uses two bind variables which names are :str and :num. These initial values are "the string whose width is 4 and whose value is 'ABCD'" and "the number whose value is 123". This method returns the array of these bind variables, which may modified by PL/SQL statement. The order of array is same with that of bind variables.

OCI8#parse(sql)
Creates cursor, prepare to execute SQL statement and return the instance of OCI8::Cursor.
OCI8#commit()

Commits the transaction.

example:

conn = OCI8.new("scott", "tiger")
conn.exec("UPDATE emp SET sal = sal * 1.1") # yahoo
conn.commit
conn.logoff
OCI8#rollback()

Rollbacks the transaction.

example:

conn = OCI8.new("scott", "tiger")
conn.exec("UPDATE emp SET sal = sal * 0.9") # boos
conn.rollback
conn.logoff
OCI8#autocommit?
Returns the state of the autocommit mode. The default value is false. If true, the transaction is committed automatically whenever executing insert/update/delete statements.
OCI8#autocommit
Alias of OCI8#autocommit?.
OCI8#autocommit=

Changes the status of the autocommit mode. Acceptable values are true and false.

example:

conn = OCI8.new("scott", "tiger")
conn.autocommit = true
... do something ...
conn.logoff
OCI8#non_blocking?
Returns the status of blocking/non-blocking mode. The default value is false, that is blocking mode. See Blocking/Non-Blocking Mode.
OCI8#non_blocking=
Changes the status of blocking/non-blocking mode. Acceptable values are true and false. See Blocking/Non-Blocking Mode.
OCI8#break()
Cancels the OCI call performing in other thread. To use this, the connection status must be non-blocking mode. See Blocking/Non-Blocking Mode.

OCI8::Cursor

OCI8::Cursor#define(pos, type, length = nil)

explicitly indicate the date type of fetched value. run this method within parse and exec. pos starts from 1. lentgh is used when type is String.

example:

cursor = conn.parse("SELECT ename, hiredate FROM emp")
cursor.define(1, String, 20) # fetch the first column as String.
cursor.define(2, Time)       # fetch the second column as Time.
cursor.exec()
OCI8::Cursor#bind_param(key, val, type = nil, length = nil)

Binds variables explicitly.

When key is number, it binds by position, which starts from 1. When key is string, it binds by the name of placeholder.

example:

cursor = conn.parse("SELECT * FROM emp WHERE ename = :ename")
cursor.bind_param(1, 'SMITH') # bind by position
  ...or...
cursor.bind_param(':ename', 'SMITH') # bind by name

To bind as number, Fixnum and Float are available, but Bignum is not supported. If its initial value is NULL, please set nil to type and Fixnum or Float to val.

example:

cursor.bind_param(1, 1234) # bind as Fixnum, Initial value is 1234.
cursor.bind_param(1, 1234.0) # bind as Float, Initial value is 1234.0.
cursor.bind_param(1, nil, Fixnum) # bind as Fixnum, Initial value is NULL.
cursor.bind_param(1, nil, Float) # bind as Float, Initial value is NULL.

In case of binding a string, set the string itself to val. When the bind variable is used as output, set the string whose length is enough to store or set the length.

example:

cursor = conn.parse("BEGIN :out := :in || '_OUT'; END;")
cursor.bind_param(':in', 'DATA') # bind as String with width 4.
cursor.bind_param(':out', nil, String, 7) # bind as String with width 7.
cursor.exec()
p cursor[':out'] # => 'DATA_OU'
# Though the length of :out is 8 bytes in PL/SQL block, it is
# bound as 7 bytes. So result is cut off at 7 byte.

In case of binding a string as RAW, set OCI::RAW to type.

example:

cursor = conn.parse("INSERT INTO raw_table(raw_column) VALUE (:1)")
cursor.bind_param(1, 'RAW_STRING', OCI8::RAW)
cursor.exec()
cursor.close()
OCI8::Cursor#[key]

Gets the value of the bind variable.

In case of binding explicitly, use same key with that of OCI8::Cursor#bind_param. A placeholder can be bound by name or position. If you bind by name, use that name. If you bind by position, use the position.

example:

cursor = conn.parse("BEGIN :out := 'BAR'; END;")
cursor.bind_param(':out', 'FOO') # bind by name
p cursor[':out'] # => 'FOO'
p cursor[1] # => nil
cursor.exec()
p cursor[':out'] # => 'BAR'
p cursor[1] # => nil

example:

cursor = conn.parse("BEGIN :out := 'BAR'; END;")
cursor.bind_param(1, 'FOO') # bind by position
p cursor[':out'] # => nil
p cursor[1] # => 'FOO'
cursor.exec()
p cursor[':out'] # => nil
p cursor[1] # => 'BAR'

In case of binding by OCI8#exec or OCI8::Cursor#exec, get the value by position, which starts from 1.

example:

cursor = conn.exec("BEGIN :out := 'BAR'; END;", 'FOO')
# 1st bind variable is bound as String with width 3. Its initial value is 'FOO'
# After execute, the value become 'BAR'.
p cursor[1] # => 'BAR'
OCI8::Cursor#[key] = val

Sets the value to the bind variable. The way to specify the key is same with OCI8::Cursor#[]. This is available to replace the value and execute many times.

example1:

cursor = conn.parse("INSERT INTO test(col1) VALUES(:1)")
cursor.bind_params(1, nil, String, 3)
['FOO', 'BAR', 'BAZ'].each do |key|
  cursor[1] = key
  cursor.exec
end
cursor.close()

example2:

['FOO', 'BAR', 'BAZ'].each do |key|
  conn.exec("INSERT INTO test(col1) VALUES(:1)", key)
end

Both example's results are same. But the former will use less resources.

OCI8::Cursor#keys()
Returns the keys of bind variables as array.
OCI8::Cursor#exec(*bindvars)

Executes the SQL statement assigned the cursor. The type of return value depends on the type of sql statement: select; insert, update and delete; create, alter, drop and PL/SQL.

In case of select statement, it returns the number of the select-list.

In case of insert, update or delete statement, it returns the number of processed rows.

In case of create, alter, drop and PL/SQL statement, it returns true. In contrast with OCI8#exec, it returns true even though PL/SQL. Use OCI8::Cursor#[] explicitly to get bind variables.

OCI8::Cursor#type

gets the type of SQL statement. Its value is one of the follows.

For PL/SQL statement, it returns OCI8::STMT_BEGIN or OCI8::STMT_DECLARE.

OCI8::Cursor#row_count
Returns the number of processed rows.
OCI8::Cursor#get_col_names
Gets the names of select-list as array. Please use this method after exec.
OCI8::Cursor#getColNames
Alias of OCI8::Cursor#get_col_names.
OCI8::Cursor#fetch()

Gets fetched data as array. This is available for select statement only.

example:

conn = OCI8.new('scott', 'tiger')
cursor = conn.exec('SELECT * FROM emp')
while r = cursor.fetch()
  puts r.join(',')
end
cursor.close
conn.logoff
OCI8::Cursor#close()
close the cursor.
OCI8::Cursor#rowid()
get the rowid of the last processed row. This value is available as bind data. On the other hand it isn't available for other purpose.

OCI8::BLOB

OCI8::BLOB#available?

check whether BLOB is available or not. To use BLOB you need to insert EMPTY_BLOB() at first.

example:

conn.exec("CREATE TABLE photo (name VARCHAR2(50), image BLOB)")
conn.exec("INSERT INTO photo VALUES ('null-data', NULL)")
conn.exec("INSERT INTO photo VALUES ('empty-data', EMPTY_BLOB())")
conn.exec("SELECT name, image FROM photo") do |name, image|
  case name
  when 'null-data'
    puts "#{name} => #{image.available?.to_s}"
    # => false
  when 'empty-data'
    puts "#{name} => #{image.available?.to_s}"
    # => true
  end
end
OCI8::BLOB#read(size = nil)

read at most size bytes from BLOB, or to the end of file if size is omitted.

example: read chunks of chunk size.

conn.exec("SELECT name, image FROM photo") do |name, image|
  chunk_size = image.chunk_size
  File.open(name, 'w') do |f|
    until image.eof?
      f.write(image.read(chunk_size))
    end
  end
end

example: read at once.

conn.exec("SELECT name, image FROM photo") do |name, image|
  File.open(name, 'w') do |f|
    f.write(image.read)
  end
end
OCI8::BLOB#write(string)

write the given string to BLOB. If old data is longer than new data, resize by OCI8::BLOB#size=.

example: write chunks of chunk size.

cursor = conn.parse("INSERT INTO photo VALUES(:name, EMPTY_BLOB())")
Dir["*.png"].each do |fname|
  cursor.exec(fname)
end
conn.exec("SELECT name, image FROM photo") do |name, image|
  chunk_size = image.chunk_size
  File.open(name, 'r') do |f|
    until f.eof?
      image.write(f.read(chunk_size))
    end
    image.size = f.pos
  end
end
conn.commit

example: write at once.

conn.exec("SELECT name, image FROM photo") do |name, image|
  File.open(name, 'r') do |f|
    image.write(f.read)
    image.size = f.pos
  end
end
OCI8::BLOB#size
return the size of BLOB.
OCI8::BLOB#size=(len)
set the size of BLOB.
OCI8::BLOB#chunk_size
return the chunk size of BLOB.
OCI8::BLOB#truncate(len)
set the size of BLOB.
OCI8::BLOB#pos
return the current offset of BLOB.
OCI8::BLOB#pos=(pos)
set the current offset of BLOB.
OCI8::BLOB#eof?
return true if BLOB is at end of file
OCI8::BLOB#tell
Synonym for OCI8::BLOB#pos.
OCI8::BLOB#seek(pos)
Synonym for OCI8::BLOB#pos=.
OCI8::BLOB#rewind
set the current offset to zero.

Appendix

Blocking/Non-Blocking Mode

The default mode is blocking mode. You can change the mode by OCI8#non_blocking=.

When the mode is blocking, heavy OCI calls will block the process itself even though multithread application because ruby's thread is not native one.

when the mode is non-blocking, heavy OCI calls will not block the process, but block the thread only. Instead of the merit, each OCI call become a bit slower because it polls many times whether the OCI call is finished or not.

You can cancel a OCI call by using OCI8#break from other thread. The canceled OCI call raises OCIBreak exception.

Restriction of non-blocking mode: Don't do OCI calls at the same time for a same connection.


*1Oracle Call Interface