aboutsummaryrefslogtreecommitdiffstats
path: root/activerecord/lib/active_record/connection_adapters/oci_adapter.rb
blob: 1519e1cefd1b1114ad6616afccc6e5c4efb7e904 (plain) (blame)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
# oci_adapter.rb -- ActiveRecord adapter for Oracle 8i, 9i, 10g
#
# Original author: Graham Jenkins
#
# Current maintainer: Michael Schoen <schoenm@earthlink.net>
#
#########################################################################
#
# Implementation notes:
# 1. Redefines (safely) a method in ActiveRecord to make it possible to
#    implement an autonumbering solution for Oracle.
# 2. The OCI8 driver is patched to properly handle values for LONG and
#    TIMESTAMP columns. The driver-author has indicated that a future
#    release of the driver will obviate this patch.
# 3. LOB support is implemented through an after_save callback.
# 4. Oracle does not offer native LIMIT and OFFSET options; this
#    functionality is mimiced through the use of nested selects.
#    See http://asktom.oracle.com/pls/ask/f?p=4950:8:::::F4950_P8_DISPLAYID:127412348064
#
# Do what you want with this code, at your own peril, but if any
# significant portion of my code remains then please acknowledge my
# contribution.
# portions Copyright 2005 Graham Jenkins

require 'active_record/connection_adapters/abstract_adapter'

begin
  require_library_or_gem 'oci8' unless self.class.const_defined? :OCI8

  module ActiveRecord
    class Base
      def self.oci_connection(config) #:nodoc:
        conn = OCI8.new config[:username], config[:password], config[:host]
        conn.exec %q{alter session set nls_date_format = 'YYYY-MM-DD HH24:MI:SS'}
        conn.exec %q{alter session set nls_timestamp_format = 'YYYY-MM-DD HH24:MI:SS'}
        conn.autocommit = true
        ConnectionAdapters::OCIAdapter.new conn, logger
      end

      # Enable the id column to be bound into the sql later, by the adapter's insert method.
      # This is preferable to inserting the hard-coded value here, because the insert method
      # needs to know the id value explicitly.
      alias :attributes_with_quotes_pre_oci :attributes_with_quotes #:nodoc:
      def attributes_with_quotes(creating = true) #:nodoc:
        aq = attributes_with_quotes_pre_oci creating
        if connection.class == ConnectionAdapters::OCIAdapter
          aq[self.class.primary_key] = ":id" if creating && aq[self.class.primary_key].nil?
        end
        aq
      end

      # After setting large objects to empty, select the OCI8::LOB
      # and write back the data.
      after_save :write_lobs 
      def write_lobs() #:nodoc:
        if connection.is_a?(ConnectionAdapters::OCIAdapter)
          self.class.columns.select { |c| c.type == :binary }.each { |c|
            value = self[c.name]
            next if value.nil?  || (value == '')
            lob = connection.select_one(
              "select #{ c.name} from #{ self.class.table_name } WHERE #{ self.class.primary_key} = #{quote(id)}",
              'Writable Large Object')[c.name]
            lob.write value
          }
        end
      end

      private :write_lobs
    end


    module ConnectionAdapters #:nodoc:
      class OCIColumn < Column #:nodoc:
        attr_reader :sql_type

        # overridden to add the concept of scale, required to differentiate
        # between integer and float fields
        def initialize(name, default, sql_type, limit, scale, null)
          @name, @limit, @sql_type, @scale, @null = name, limit, sql_type, scale, null

          @type = simplified_type(sql_type)
          @default = type_cast(default)

          @primary = nil
          @text    = [:string, :text].include? @type
          @number  = [:float, :integer].include? @type
        end

        def type_cast(value)
          return nil if value.nil? || value =~ /^\s*null\s*$/i
          case type
          when :string   then value
          when :integer  then defined?(value.to_i) ? value.to_i : (value ? 1 : 0)
          when :float    then value.to_f
          when :datetime then cast_to_date_or_time(value)
          when :time     then cast_to_time(value)
          else value
          end
        end

        private
        def simplified_type(field_type)
          case field_type
          when /char/i                          : :string
          when /num|float|double|dec|real|int/i : @scale == 0 ? :integer : :float
          when /date|time/i                     : @name =~ /_at$/ ? :time : :datetime
          when /lob/i                           : :binary
          end
        end

        def cast_to_date_or_time(value)
          return value if value.is_a? Date
          guess_date_or_time (value.is_a? Time) ? value : cast_to_time(value)
        end

        def cast_to_time(value)
          return value if value.is_a? Time
          time_array = ParseDate.parsedate value
          time_array[0] ||= 2000; time_array[1] ||= 1; time_array[2] ||= 1;
          Time.send Base.default_timezone, *time_array
        end

        def guess_date_or_time(value)
          (value.hour == 0 and value.min == 0 and value.sec == 0) ?
            Date.new(value.year, value.month, value.day) : value
        end
      end


      # This is an Oracle/OCI adapter for the ActiveRecord persistence
      # framework. It relies upon the OCI8 driver, which works with Oracle 8i
      # and above. Most recent development has been on Debian Linux against
      # a 10g database, ActiveRecord 1.12.1 and OCI8 0.1.13.
      # See: http://rubyforge.org/projects/ruby-oci8/
      #
      # Usage notes:
      # * Key generation assumes a "${table_name}_seq" sequence is available
      #   for all tables; the sequence name can be changed using
      #   ActiveRecord::Base.set_sequence_name. When using Migrations, these
      #   sequences are created automatically.
      # * Oracle uses DATE or TIMESTAMP datatypes for both dates and times.
      #   Consequently some hacks are employed to map data back to Date or Time
      #   in Ruby. If the column_name ends in _time it's created as a Ruby Time.
      #   Else if the hours/minutes/seconds are 0, I make it a Ruby Date. Else
      #   it's a Ruby Time. This is a bit nasty - but if you use Duck Typing
      #   you'll probably not care very much. In 9i and up it's tempting to
      #   map DATE to Date and TIMESTAMP to Time, but too many databases use
      #   DATE for both. Timezones and sub-second precision on timestamps are
      #   not supported.
      # * Default values that are functions (such as "SYSDATE") are not
      #   supported. This is a restriction of the way ActiveRecord supports
      #   default values.
      #
      # Options:
      #
      # * <tt>:username</tt> -- Defaults to root
      # * <tt>:password</tt> -- Defaults to nothing
      # * <tt>:host</tt> -- Defaults to localhost
      class OCIAdapter < AbstractAdapter

        def adapter_name #:nodoc:
          'OCI'
        end

        def supports_migrations? #:nodoc:
          true
        end
        
        def native_database_types #:nodoc
          {
            :primary_key => "NUMBER(38) NOT NULL",
            :string      => { :name => "VARCHAR2", :limit => 255 },
            :text        => { :name => "LONG" },
            :integer     => { :name => "NUMBER", :limit => 38 },
            :float       => { :name => "NUMBER" },
            :datetime    => { :name => "DATE" },
            :timestamp   => { :name => "DATE" },
            :time        => { :name => "DATE" },
            :date        => { :name => "DATE" },
            :binary      => { :name => "BLOB" },
            :boolean     => { :name => "NUMBER", :limit => 1 }
          }
        end


        # QUOTING ==================================================
        #
        # see: abstract/quoting.rb

        # camelCase column names need to be quoted; not that anyone using Oracle
        # would really do this, but handling this case means we pass the test...
        def quote_column_name(name) #:nodoc:
          name =~ /[A-Z]/ ? "\"#{name}\"" : name
        end

        def quote_string(string) #:nodoc:
          string.gsub(/'/, "''")
        end

        def quote(value, column = nil) #:nodoc:
          if column and column.type == :binary then %Q{empty_#{ column.sql_type }()}
          else case value
            when String       then %Q{'#{quote_string(value)}'}
            when NilClass     then 'null'
            when TrueClass    then '1'
            when FalseClass   then '0'
            when Numeric      then value.to_s
            when Date, Time   then %Q{'#{value.strftime("%Y-%m-%d %H:%M:%S")}'}
            else                   %Q{'#{quote_string(value.to_yaml)}'}
            end
          end
        end


        # DATABASE STATEMENTS ======================================
        #
        # see: abstract/database_statements.rb

        def select_all(sql, name = nil) #:nodoc:
          select(sql, name)
        end

        def select_one(sql, name = nil) #:nodoc:
          result = select_all(sql, name)
          result.size > 0 ? result.first : nil
        end

        def execute(sql, name = nil) #:nodoc:
          log(sql, name) { @connection.exec sql }
        end

        def insert(sql, name = nil, pk = nil, id_value = nil, sequence_name = nil) #:nodoc:
          if pk.nil? # Who called us? What does the sql look like? No idea!
            execute sql, name
          elsif id_value # Pre-assigned id
            log(sql, name) { @connection.exec sql }
          else # Assume the sql contains a bind-variable for the id
            id_value = select_one("select #{sequence_name}.nextval id from dual")['id']
            log(sql, name) { @connection.exec sql, id_value }
          end

          id_value
        end

        alias :update :execute #:nodoc:
        alias :delete :execute #:nodoc:

        def begin_db_transaction #:nodoc:
          @connection.autocommit = false
        end

        def commit_db_transaction #:nodoc:
          @connection.commit
        ensure
          @connection.autocommit = true
        end

        def rollback_db_transaction #:nodoc:
          @connection.rollback
        ensure
          @connection.autocommit = true
        end

        def add_limit_offset!(sql, options) #:nodoc:
          offset = options[:offset] || 0

          if limit = options[:limit]
            sql.replace "select * from (select raw_sql_.*, rownum raw_rnum_ from (#{sql}) raw_sql_ where rownum <= #{offset+limit}) where raw_rnum_ > #{offset}"
          elsif offset > 0
            sql.replace "select * from (select raw_sql_.*, rownum raw_rnum_ from (#{sql}) raw_sql_) where raw_rnum_ > #{offset}"
          end
        end

        def default_sequence_name(table, column) #:nodoc:
          "#{table}_seq"
        end


        # SCHEMA STATEMENTS ========================================
        #
        # see: abstract/schema_statements.rb

        def tables(name = nil) #:nodoc:
          select_all("select lower(table_name) from user_tables").inject([]) do | tabs, t |
            tabs << t.to_a.first.last
          end
        end

        def indexes(table_name, name = nil) #:nodoc:
          result = select_all(<<-SQL, name)
            SELECT lower(i.index_name) as index_name, i.uniqueness, lower(c.column_name) as column_name
              FROM user_indexes i, user_ind_columns c
             WHERE i.table_name = '#{table_name.to_s.upcase}'
               AND c.index_name = i.index_name
               AND i.index_name NOT IN (SELECT index_name FROM user_constraints WHERE constraint_type = 'P')
              ORDER BY i.index_name, c.column_position
          SQL

          current_index = nil
          indexes = []

          result.each do |row|
            if current_index != row['index_name']
              indexes << IndexDefinition.new(table_name, row['index_name'], row['uniqueness'] == "UNIQUE", [])
              current_index = row['index_name']
            end

            indexes.last.columns << row['column_name']
          end

          indexes
        end

        def columns(table_name, name = nil) #:nodoc:
          select_all(%Q{
              select column_name, data_type, data_default, nullable,
                     case when data_type = 'NUMBER' then data_precision
                          when data_type = 'VARCHAR2' then data_length 
                          else null end as length,
                     case when data_type = 'NUMBER' then data_scale
                          else null end as scale
              from user_catalog cat, user_synonyms syn, all_tab_columns col
              where cat.table_name = '#{table_name.to_s.upcase}'
              and syn.synonym_name (+)= cat.table_name
              and col.owner = nvl(syn.table_owner, user)
              and col.table_name = nvl(syn.table_name, cat.table_name)}
          ).map do |row|
            row['data_default'].gsub!(/^'(.*)'$/, '\1') if row['data_default']
            OCIColumn.new(
              oci_downcase(row['column_name']), 
              row['data_default'],
              row['data_type'], 
              row['length'], 
              row['scale'],
              row['nullable'] == 'Y'
            )
          end
        end

        def create_table(name, options = {}) #:nodoc:
          super(name, options)
          execute "CREATE SEQUENCE #{name}_seq"
        end

        def rename_table(name, new_name) #:nodoc:
          execute "RENAME #{name} TO #{new_name}"
          execute "RENAME #{name}_seq TO #{new_name}_seq"
        end  

        def drop_table(name) #:nodoc:
          super(name)
          execute "DROP SEQUENCE #{name}_seq"
        end

        def remove_index(table_name, options = {}) #:nodoc:
          execute "DROP INDEX #{index_name(table_name, options)}"
        end

        def change_column_default(table_name, column_name, default) #:nodoc:
          execute "ALTER TABLE #{table_name} MODIFY #{column_name} DEFAULT #{quote(default)}"
        end

        def change_column(table_name, column_name, type, options = {}) #:nodoc:
          change_column_sql = "ALTER TABLE #{table_name} MODIFY #{column_name} #{type_to_sql(type, options[:limit])}"
          add_column_options!(change_column_sql, options)
          execute(change_column_sql)
        end

        def rename_column(table_name, column_name, new_column_name) #:nodoc:
          execute "ALTER TABLE #{table_name} RENAME COLUMN #{column_name} to #{new_column_name}"
        end

        def remove_column(table_name, column_name) #:nodoc:
          execute "ALTER TABLE #{table_name} DROP COLUMN #{column_name}"
        end

        def structure_dump #:nodoc:
          s = select_all("select sequence_name from user_sequences").inject("") do |structure, seq|
            structure << "create sequence #{seq.to_a.first.last};\n\n"
          end

          select_all("select table_name from user_tables").inject(s) do |structure, table|
            ddl = "create table #{table.to_a.first.last} (\n "  
            cols = select_all(%Q{
              select column_name, data_type, data_length, data_precision, data_scale, data_default, nullable
              from user_tab_columns
              where table_name = '#{table.to_a.first.last}'
              order by column_id
            }).map do |row|              
              col = "#{row['column_name'].downcase} #{row['data_type'].downcase}"      
              if row['data_type'] =='NUMBER' and !row['data_precision'].nil?
                col << "(#{row['data_precision'].to_i}"
                col << ",#{row['data_scale'].to_i}" if !row['data_scale'].nil?
                col << ')'
              elsif row['data_type'].include?('CHAR')
                col << "(#{row['data_length'].to_i})"  
              end
              col << " default #{row['data_default']}" if !row['data_default'].nil?
              col << ' not null' if row['nullable'] == 'N'
              col
            end
            ddl << cols.join(",\n ")
            ddl << ");\n\n"
            structure << ddl
          end
        end

        def structure_drop #:nodoc:
          s = select_all("select sequence_name from user_sequences").inject("") do |drop, seq|
            drop << "drop sequence #{seq.to_a.first.last};\n\n"
          end

          select_all("select table_name from user_tables").inject(s) do |drop, table|
            drop << "drop table #{table.to_a.first.last} cascade constraints;\n\n"
          end
        end


        private

        def select(sql, name = nil)
          cursor = log(sql, name) { @connection.exec sql }
          cols = cursor.get_col_names.map { |x| oci_downcase(x) }
          rows = []

          while row = cursor.fetch
            hash = Hash.new

            cols.each_with_index do |col, i|
              hash[col] =
                case row[i]
                when OCI8::LOB
                  name == 'Writable Large Object' ? row[i]: row[i].read
                when OraDate
                  (row[i].hour == 0 and row[i].minute == 0 and row[i].second == 0) ?
                  row[i].to_date : row[i].to_time
                else row[i]
                end unless col == 'raw_rnum_'
            end

            rows << hash
          end

          rows
        ensure
          cursor.close if cursor
        end

        # Oracle column names by default are case-insensitive, but treated as upcase;
        # for neatness, we'll downcase within Rails. EXCEPT that folks CAN quote
        # their column names when creating Oracle tables, which makes then case-sensitive.
        # I don't know anybody who does this, but we'll handle the theoretical case of a
        # camelCase column name. I imagine other dbs handle this different, since there's a
        # unit test that's currently failing test_oci.
        def oci_downcase(column_name)
          column_name =~ /[a-z]/ ? column_name : column_name.downcase
        end

      end
    end
  end


  # This OCI8 patch may not longer be required with the upcoming
  # release of version 0.2.
  class OCI8 #:nodoc:
    class Cursor #:nodoc:
      alias :define_a_column_pre_ar :define_a_column
      def define_a_column(i)
        case do_ocicall(@ctx) { @parms[i - 1].attrGet(OCI_ATTR_DATA_TYPE) }
        when 8    : @stmt.defineByPos(i, String, 65535) # Read LONG values
        when 187  : @stmt.defineByPos(i, OraDate) # Read TIMESTAMP values
        else define_a_column_pre_ar i
        end
    	end
    end
  end

rescue LoadError
  # OCI8 driver is unavailable.
end