postgresql_adapter.rb 32.0 KB
Newer Older
D
Initial  
David Heinemeier Hansson 已提交
1 2 3 4 5 6 7
require 'active_record/connection_adapters/abstract_adapter'

module ActiveRecord
  class Base
    # Establishes a connection to the database that's used by all Active Record objects
    def self.postgresql_connection(config) # :nodoc:
      require_library_or_gem 'postgres' unless self.class.const_defined?(:PGconn)
8 9

      config = config.symbolize_keys
D
Initial  
David Heinemeier Hansson 已提交
10
      host     = config[:host]
11
      port     = config[:port] || 5432
D
Initial  
David Heinemeier Hansson 已提交
12 13 14 15 16 17 18 19 20
      username = config[:username].to_s
      password = config[:password].to_s

      if config.has_key?(:database)
        database = config[:database]
      else
        raise ArgumentError, "No database specified. Missing argument: database."
      end

21
      # The postgres drivers don't allow the creation of an unconnected PGconn object,
22 23 24 25
      # so just pass a nil connection object for the time being.
      ConnectionAdapters::PostgreSQLAdapter.new(nil, logger, [host, port, nil, nil, database, username, password], config)
    end
  end
26

27 28 29 30 31 32 33
  module ConnectionAdapters
    # PostgreSQL-specific extensions to column definitions in a table.
    class PostgreSQLColumn < Column #:nodoc:
      # Instantiates a new PostgreSQL column definition in a table.
      def initialize(name, default, sql_type = nil, null = true)
        super(name, self.class.extract_value_from_default(default), sql_type, null)
      end
34

35 36 37 38 39 40
      private
        # Extracts the scale from PostgreSQL-specific data types.
        def extract_scale(sql_type)
          # Money type has a fixed scale of 2.
          sql_type =~ /^money/ ? 2 : super
        end
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
        # Extracts the precision from PostgreSQL-specific data types.
        def extract_precision(sql_type)
          # Actual code is defined dynamically in PostgreSQLAdapter.connect
          # depending on the server specifics
          super
        end
  
        # Escapes binary strings for bytea input to the database.
        def self.string_to_binary(value)
          if PGconn.respond_to?(:escape_bytea)
            self.class.module_eval do
              define_method(:string_to_binary) do |value|
                PGconn.escape_bytea(value) if value
              end
            end
          else
            self.class.module_eval do
              define_method(:string_to_binary) do |value|
                if value
                  result = ''
                  value.each_byte { |c| result << sprintf('\\\\%03o', c) }
                  result
                end
              end
            end
          end
          self.class.string_to_binary(value)
        end
  
        # Unescapes bytea output from a database to the binary string it represents.
        def self.binary_to_string(value)
73
          # In each case, check if the value actually is escaped PostgreSQL bytea output
74 75 76 77
          # or an unescaped Active Record attribute that was just written.
          if PGconn.respond_to?(:unescape_bytea)
            self.class.module_eval do
              define_method(:binary_to_string) do |value|
78
                if value =~ /\\\d{3}/
79 80 81 82 83 84 85 86 87
                  PGconn.unescape_bytea(value)
                else
                  value
                end
              end
            end
          else
            self.class.module_eval do
              define_method(:binary_to_string) do |value|
88
                if value =~ /\\\d{3}/
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
                  result = ''
                  i, max = 0, value.size
                  while i < max
                    char = value[i]
                    if char == ?\\
                      if value[i+1] == ?\\
                        char = ?\\
                        i += 1
                      else
                        char = value[i+1..i+3].oct
                        i += 3
                      end
                    end
                    result << char
                    i += 1
                  end
                  result
                else
                  value
                end
              end
            end
          end
          self.class.binary_to_string(value)
        end  
  
        # Maps PostgreSQL-specific data types to logical Rails types.
        def simplified_type(field_type)
          case field_type
            # Numeric and monetary types
            when /^(?:real|double precision)$/
              :float
            # Monetary types
            when /^money$/
              :decimal
            # Character types
            when /^(?:character varying|bpchar)(?:\(\d+\))?$/
              :string
            # Binary data types
            when /^bytea$/
              :binary
            # Date/time types
            when /^timestamp with(?:out)? time zone$/
              :datetime
            when /^interval$/
              :string
            # Geometric types
            when /^(?:point|line|lseg|box|"?path"?|polygon|circle)$/
              :string
            # Network address types
            when /^(?:cidr|inet|macaddr)$/
              :string
            # Bit strings
            when /^bit(?: varying)?(?:\(\d+\))?$/
              :string
            # XML type
            when /^xml$/
              :string
            # Arrays
            when /^\D+\[\]$/
              :string              
            # Object identifier types
            when /^oid$/
              :integer
            # Pass through all types that are not specific to PostgreSQL.
            else
              super
          end
        end
  
        # Extracts the value from a PostgreSQL column default definition.
        def self.extract_value_from_default(default)
          case default
            # Numeric types
163
            when /\A-?\d+(\.\d*)?\z/
164 165
              default
            # Character types
166
            when /\A'(.*)'::(?:character varying|bpchar|text)\z/m
167
              $1
168 169 170
            # Character types (8.1 formatting)
            when /\AE'(.*)'::(?:character varying|bpchar|text)\z/m
              $1.gsub(/\\(\d\d\d)/) { $1.oct.chr }
171
            # Binary data types
172
            when /\A'(.*)'::bytea\z/m
173 174
              $1
            # Date/time types
175
            when /\A'(.+)'::(?:time(?:stamp)? with(?:out)? time zone|date)\z/
176
              $1
177
            when /\A'(.*)'::interval\z/
178 179
              $1
            # Boolean type
180
            when 'true'
181
              true
182
            when 'false'
183 184
              false
            # Geometric types
185
            when /\A'(.*)'::(?:point|line|lseg|box|"?path"?|polygon|circle)\z/
186 187
              $1
            # Network address types
188
            when /\A'(.*)'::(?:cidr|inet|macaddr)\z/
189 190
              $1
            # Bit string types
191
            when /\AB'(.*)'::"?bit(?: varying)?"?\z/
192 193
              $1
            # XML type
194
            when /\A'(.*)'::xml\z/m
195 196
              $1
            # Arrays
197
            when /\A'(.*)'::"?\D+"?\[\]\z/
198 199
              $1
            # Object identifier types
200
            when /\A-?\d+\z/
201 202 203
              $1
            else
              # Anything else is blank, some user type, or some function
204
              # and we can't know the value of that, so return nil.
205 206 207
              nil
          end
        end
D
Initial  
David Heinemeier Hansson 已提交
208 209 210 211
    end
  end

  module ConnectionAdapters
212 213
    # The PostgreSQL adapter works both with the native C (http://ruby.scripting.ca/postgres/) and the pure
    # Ruby (available both as gem and from http://rubyforge.org/frs/?group_id=234&release_id=1944) drivers.
214 215 216 217 218 219 220 221
    #
    # Options:
    #
    # * <tt>:host</tt> -- Defaults to localhost
    # * <tt>:port</tt> -- Defaults to 5432
    # * <tt>:username</tt> -- Defaults to nothing
    # * <tt>:password</tt> -- Defaults to nothing
    # * <tt>:database</tt> -- The name of the database. No default, must be provided.
222
    # * <tt>:schema_search_path</tt> -- An optional schema search path for the connection given as a string of comma-separated schema names.  This is backward-compatible with the :schema_order option.
223 224
    # * <tt>:encoding</tt> -- An optional client encoding that is used in a SET client_encoding TO <encoding> call on the connection.
    # * <tt>:min_messages</tt> -- An optional client min messages that is used in a SET client_min_messages TO <min_messages> call on the connection.
225
    # * <tt>:allow_concurrency</tt> -- If true, use async query methods so Ruby threads don't deadlock; otherwise, use blocking query methods.
226
    class PostgreSQLAdapter < AbstractAdapter
227
      # Returns 'PostgreSQL' as adapter name for identification purposes.
228 229 230 231
      def adapter_name
        'PostgreSQL'
      end

232 233
      # Initializes and connects a PostgreSQL adapter.
      def initialize(connection, logger, connection_parameters, config)
234
        super(connection, logger)
235
        @connection_parameters, @config = connection_parameters, config
236

237
        connect
238 239
      end

240 241 242
      # Is this connection alive and ready for queries?
      def active?
        if @connection.respond_to?(:status)
243
          @connection.status == PGconn::CONNECTION_OK
244
        else
245
          # We're asking the driver, not ActiveRecord, so use @connection.query instead of #query
246
          @connection.query 'SELECT 1'
247 248
          true
        end
249
      # postgres-pr raises a NoMethodError when querying if no connection is available.
250
      rescue PGError, NoMethodError
251
        false
252 253 254 255 256 257
      end

      # Close then reopen the connection.
      def reconnect!
        if @connection.respond_to?(:reset)
          @connection.reset
258
          configure_connection
259 260 261
        else
          disconnect!
          connect
262 263
        end
      end
264

265
      # Close the connection.
266 267 268
      def disconnect!
        @connection.close rescue nil
      end
269

270
      def native_database_types #:nodoc:
271 272 273 274 275 276
        {
          :primary_key => "serial primary key",
          :string      => { :name => "character varying", :limit => 255 },
          :text        => { :name => "text" },
          :integer     => { :name => "integer" },
          :float       => { :name => "float" },
277
          :decimal     => { :name => "decimal" },
278 279
          :datetime    => { :name => "timestamp" },
          :timestamp   => { :name => "timestamp" },
280
          :time        => { :name => "time" },
281 282
          :date        => { :name => "date" },
          :binary      => { :name => "bytea" },
283
          :boolean     => { :name => "boolean" }
284 285
        }
      end
286

287
      # Does PostgreSQL support migrations?
288 289
      def supports_migrations?
        true
290 291
      end

292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309
      # Does PostgreSQL support standard conforming strings?
      def supports_standard_conforming_strings?
        # Temporarily set the client message level above error to prevent unintentional
        # error messages in the logs when working on a PostgreSQL database server that
        # does not support standard conforming strings.
        client_min_messages_old = client_min_messages
        self.client_min_messages = 'panic'

        # postgres-pr does not raise an exception when client_min_messages is set higher
        # than error and "SHOW standard_conforming_strings" fails, but returns an empty
        # PGresult instead.
        has_support = execute('SHOW standard_conforming_strings')[0][0] rescue false
        self.client_min_messages = client_min_messages_old
        has_support
      end

      # Returns the configured supported identifier length supported by PostgreSQL,
      # or report the default of 63 on PostgreSQL 7.x.
310
      def table_alias_length
311
        @table_alias_length ||= (postgresql_version >= 80000 ? query('SHOW max_identifier_length')[0][0].to_i : 63)
312
      end
313

314 315
      # QUOTING ==================================================

316 317
      # Quotes PostgreSQL-specific data types for SQL input.
      def quote(value, column = nil) #:nodoc:
318
        if value.kind_of?(String) && column && column.type == :binary
319 320 321 322 323 324 325 326 327 328 329 330 331
          "#{quoted_string_prefix}'#{column.class.string_to_binary(value)}'"
        elsif value.kind_of?(String) && column && column.sql_type =~ /^xml$/
          "xml '#{quote_string(value)}'"
        elsif value.kind_of?(Numeric) && column && column.sql_type =~ /^money$/
          # Not truly string input, so doesn't require (or allow) escape string syntax.
          "'#{value.to_s}'"
        elsif value.kind_of?(String) && column && column.sql_type =~ /^bit/
          case value
            when /^[01]*$/
              "B'#{value}'" # Bit-string notation
            when /^[0-9A-F]*$/i
              "X'#{value}'" # Hexadecimal notation
          end
332 333 334 335 336
        else
          super
        end
      end

337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356
      # Quotes strings for use in SQL input in the postgres driver for better performance.
      def quote_string(s) #:nodoc:
        if PGconn.respond_to?(:escape)
          self.class.instance_eval do
            define_method(:quote_string) do |s|
              PGconn.escape(s)
            end
          end
        else
          # There are some incorrectly compiled postgres drivers out there
          # that don't define PGconn.escape.
          self.class.instance_eval do
            undef_method(:quote_string)
          end
        end
        quote_string(s)
      end

      # Quotes column names for use in SQL queries.
      def quote_column_name(name) #:nodoc:
357 358 359
        %("#{name}")
      end

360 361 362
      # Quote date/time values for use in SQL input. Includes microseconds
      # if the value is a Time responding to usec.
      def quoted_date(value) #:nodoc:
363 364 365 366 367
        if value.acts_like?(:time) && value.respond_to?(:usec)
          "#{super}.#{sprintf("%06d", value.usec)}"
        else
          super
        end
368 369
      end

370 371 372 373 374 375 376 377
      # REFERENTIAL INTEGRITY ====================================

      def disable_referential_integrity(&block) #:nodoc:
        execute(tables.collect { |name| "ALTER TABLE #{quote_table_name(name)} DISABLE TRIGGER ALL" }.join(";"))
        yield
      ensure
        execute(tables.collect { |name| "ALTER TABLE #{quote_table_name(name)} ENABLE TRIGGER ALL" }.join(";"))
      end
378 379 380

      # DATABASE STATEMENTS ======================================

381 382 383 384 385 386
      # Executes a SELECT query and returns an array of rows. Each row is an
      # array of field values.
      def select_rows(sql, name = nil)
        select_raw(sql, name).last
      end

387
      # Executes an INSERT query and returns the new record's ID
388
      def insert(sql, name = nil, pk = nil, id_value = nil, sequence_name = nil)
389
        table = sql.split(" ", 4)[2]
390
        super || last_insert_id(table, sequence_name || default_sequence_name(table, pk))
391 392
      end

393
      # Queries the database and returns the results in an Array or nil otherwise.
394
      def query(sql, name = nil) #:nodoc:
395 396 397 398 399 400 401
        log(sql, name) do
          if @async
            @connection.async_query(sql)
          else
            @connection.query(sql)
          end
        end
402 403
      end

404
      # Executes an SQL statement, returning a PGresult object on success
405 406
      # or raising a PGError exception otherwise.
      def execute(sql, name = nil)
407 408 409 410 411 412 413
        log(sql, name) do
          if @async
            @connection.async_exec(sql)
          else
            @connection.exec(sql)
          end
        end
414 415
      end

416
      # Executes an UPDATE query and returns the number of affected tuples.
417 418
      def update_sql(sql, name = nil)
        super.cmdtuples
419 420
      end

421 422
      # Begins a transaction.
      def begin_db_transaction
423 424 425
        execute "BEGIN"
      end

426 427
      # Commits a transaction.
      def commit_db_transaction
428 429
        execute "COMMIT"
      end
430

431 432
      # Aborts a transaction.
      def rollback_db_transaction
433 434 435 436 437
        execute "ROLLBACK"
      end

      # SCHEMA STATEMENTS ========================================

438 439
      # Returns the list of all tables in the schema search path or a specified schema.
      def tables(name = nil)
440 441 442 443 444 445 446 447
        schemas = schema_search_path.split(/,/).map { |p| quote(p) }.join(',')
        query(<<-SQL, name).map { |row| row[0] }
          SELECT tablename
            FROM pg_tables
           WHERE schemaname IN (#{schemas})
        SQL
      end

448 449
      # Returns the list of all indexes for a table.
      def indexes(table_name, name = nil)
450 451 452 453 454 455 456 457 458
        result = query(<<-SQL, name)
          SELECT i.relname, d.indisunique, a.attname
            FROM pg_class t, pg_class i, pg_index d, pg_attribute a
           WHERE i.relkind = 'i'
             AND d.indexrelid = i.oid
             AND d.indisprimary = 'f'
             AND t.oid = d.indrelid
             AND t.relname = '#{table_name}'
             AND a.attrelid = t.oid
459 460 461 462 463
             AND ( d.indkey[0]=a.attnum OR d.indkey[1]=a.attnum
                OR d.indkey[2]=a.attnum OR d.indkey[3]=a.attnum
                OR d.indkey[4]=a.attnum OR d.indkey[5]=a.attnum
                OR d.indkey[6]=a.attnum OR d.indkey[7]=a.attnum
                OR d.indkey[8]=a.attnum OR d.indkey[9]=a.attnum )
464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481
          ORDER BY i.relname
        SQL

        current_index = nil
        indexes = []

        result.each do |row|
          if current_index != row[0]
            indexes << IndexDefinition.new(table_name, row[0], row[1] == "t", [])
            current_index = row[0]
          end

          indexes.last.columns << row[2]
        end

        indexes
      end

482 483
      # Returns the list of all column definitions for a table.
      def columns(table_name, name = nil)
484
        # Limit, precision, and scale are all handled by the superclass.
485 486
        column_definitions(table_name).collect do |name, type, default, notnull|
          PostgreSQLColumn.new(name, default, type, notnull == 'f')
D
Initial  
David Heinemeier Hansson 已提交
487 488 489
        end
      end

490 491 492 493 494 495
      # Sets the schema search path to a string of comma-separated schema names.
      # Names beginning with $ have to be quoted (e.g. $user => '$user').
      # See: http://www.postgresql.org/docs/current/static/ddl-schemas.html
      #
      # This should be not be called manually but set in database.yml.
      def schema_search_path=(schema_csv)
496 497
        if schema_csv
          execute "SET search_path TO #{schema_csv}"
498
          @schema_search_path = schema_csv
499
        end
D
Initial  
David Heinemeier Hansson 已提交
500 501
      end

502 503
      # Returns the active schema search path.
      def schema_search_path
504
        @schema_search_path ||= query('SHOW search_path')[0][0]
505
      end
506

507 508 509 510 511 512 513 514 515 516 517 518
      # Returns the current client message level.
      def client_min_messages
        query('SHOW client_min_messages')[0][0]
      end

      # Set the client message level.
      def client_min_messages=(level)
        execute("SET client_min_messages TO '#{level}'")
      end

      # Returns the sequence name for a table's primary key or some other specified key.
      def default_sequence_name(table_name, pk = nil) #:nodoc:
519
        default_pk, default_seq = pk_and_sequence_for(table_name)
520
        default_seq || "#{table_name}_#{pk || default_pk || 'id'}_seq"
521 522
      end

523 524
      # Resets the sequence of a table's primary key to the maximum value.
      def reset_pk_sequence!(table, pk = nil, sequence = nil) #:nodoc:
525 526 527 528 529 530 531 532 533 534 535 536 537
        unless pk and sequence
          default_pk, default_sequence = pk_and_sequence_for(table)
          pk ||= default_pk
          sequence ||= default_sequence
        end
        if pk
          if sequence
            select_value <<-end_sql, 'Reset sequence'
              SELECT setval('#{sequence}', (SELECT COALESCE(MAX(#{pk})+(SELECT increment_by FROM #{sequence}), (SELECT min_value FROM #{sequence})) FROM #{table}), false)
            end_sql
          else
            @logger.warn "#{table} has primary key #{pk} with no default sequence" if @logger
          end
538 539 540
        end
      end

541 542
      # Returns a table's primary key and belonging sequence.
      def pk_and_sequence_for(table) #:nodoc:
543 544
        # First try looking for a sequence with a dependency on the
        # given table's primary key.
545
        result = query(<<-end_sql, 'PK and serial sequence')[0]
546
          SELECT attr.attname, seq.relname
547 548 549 550 551 552 553 554 555 556 557 558 559
          FROM pg_class      seq,
               pg_attribute  attr,
               pg_depend     dep,
               pg_namespace  name,
               pg_constraint cons
          WHERE seq.oid           = dep.objid
            AND seq.relkind       = 'S'
            AND attr.attrelid     = dep.refobjid
            AND attr.attnum       = dep.refobjsubid
            AND attr.attrelid     = cons.conrelid
            AND attr.attnum       = cons.conkey[1]
            AND cons.contype      = 'p'
            AND dep.refobjid      = '#{table}'::regclass
560
        end_sql
561 562 563 564 565

        if result.nil? or result.empty?
          # If that fails, try parsing the primary key's default value.
          # Support the 7.x and 8.0 nextval('foo'::text) as well as
          # the 8.1+ nextval('foo'::regclass).
566
          result = query(<<-end_sql, 'PK and custom sequence')[0]
567
            SELECT attr.attname, split_part(def.adsrc, '''', 2)
568 569 570 571 572 573
            FROM pg_class       t
            JOIN pg_attribute   attr ON (t.oid = attrelid)
            JOIN pg_attrdef     def  ON (adrelid = attrelid AND adnum = attnum)
            JOIN pg_constraint  cons ON (conrelid = adrelid AND adnum = conkey[1])
            WHERE t.oid = '#{table}'::regclass
              AND cons.contype = 'p'
574
              AND def.adsrc ~* 'nextval'
575 576
          end_sql
        end
577
        # [primary_key, sequence]
578
        [result.first, result.last]
579 580
      rescue
        nil
581 582
      end

583
      # Renames a table.
584 585 586
      def rename_table(name, new_name)
        execute "ALTER TABLE #{name} RENAME TO #{new_name}"
      end
587

588
      # Adds a column to a table.
S
Scott Barron 已提交
589
      def add_column(table_name, column_name, type, options = {})
590 591 592 593
        default = options[:default]
        notnull = options[:null] == false

        # Add the column.
594
        execute("ALTER TABLE #{table_name} ADD COLUMN #{quote_column_name(column_name)} #{type_to_sql(type, options[:limit])}")
595

596 597
        change_column_default(table_name, column_name, default) if options_include_default?(options)
        change_column_null(table_name, column_name, false, default) if notnull
S
Scott Barron 已提交
598
      end
D
Initial  
David Heinemeier Hansson 已提交
599

600 601
      # Changes the column of a table.
      def change_column(table_name, column_name, type, options = {})
602
        begin
603
          execute "ALTER TABLE #{table_name} ALTER COLUMN #{quote_column_name(column_name)} TYPE #{type_to_sql(type, options[:limit], options[:precision], options[:scale])}"
604
        rescue ActiveRecord::StatementInvalid
605
          # This is PostgreSQL 7.x, so we have to use a more arcane way of doing it.
606
          begin_db_transaction
607 608 609
          tmp_column_name = "#{column_name}_ar_tmp"
          add_column(table_name, tmp_column_name, type, options)
          execute "UPDATE #{table_name} SET #{quote_column_name(tmp_column_name)} = CAST(#{quote_column_name(column_name)} AS #{type_to_sql(type, options[:limit], options[:precision], options[:scale])})"
610
          remove_column(table_name, column_name)
611
          rename_column(table_name, tmp_column_name, column_name)
612 613
          commit_db_transaction
        end
614

615 616
        change_column_default(table_name, column_name, options[:default]) if options_include_default?(options)
        change_column_null(table_name, column_name, options[:null], options[:default]) if options.key?(:null)
617
      end
618

619 620
      # Changes the default value of a table column.
      def change_column_default(table_name, column_name, default)
621
        execute "ALTER TABLE #{table_name} ALTER COLUMN #{quote_column_name(column_name)} SET DEFAULT #{quote(default)}"
622
      end
623

624 625 626 627 628 629 630
      def change_column_null(table_name, column_name, null, default = nil)
        unless null || default.nil?
          execute("UPDATE #{table_name} SET #{quote_column_name(column_name)}=#{quote(default)} WHERE #{quote_column_name(column_name)} IS NULL")
        end
        execute("ALTER TABLE #{table_name} ALTER #{quote_column_name(column_name)} #{null ? 'DROP' : 'SET'} NOT NULL")
      end

631 632
      # Renames a column in a table.
      def rename_column(table_name, column_name, new_column_name)
633
        execute "ALTER TABLE #{table_name} RENAME COLUMN #{quote_column_name(column_name)} TO #{quote_column_name(new_column_name)}"
634
      end
635

636 637
      # Drops an index from a table.
      def remove_index(table_name, options = {})
638
        execute "DROP INDEX #{index_name(table_name, options)}"
639
      end
640

641 642
      # Maps logical Rails types to PostgreSQL-specific data types.
      def type_to_sql(type, limit = nil, precision = nil, scale = nil)
643 644 645 646 647 648 649 650 651 652
        return super unless type.to_s == 'integer'

        if limit.nil? || limit == 4
          'integer'
        elsif limit < 4
          'smallint'
        else
          'bigint'
        end
      end
653
      
654
      # Returns a SELECT DISTINCT clause for a given set of columns and a given ORDER BY clause.
655 656 657
      #
      # PostgreSQL requires the ORDER BY columns in the select list for distinct queries, and
      # requires that the ORDER BY include the distinct column.
658
      #
659
      #   distinct("posts.id", "posts.created_at desc")
660
      def distinct(columns, order_by) #:nodoc:
661 662
        return "DISTINCT #{columns}" if order_by.blank?

663 664
        # Construct a clean list of column names from the ORDER BY clause, removing
        # any ASC/DESC modifiers
665
        order_columns = order_by.split(',').collect { |s| s.split.first }
666
        order_columns.delete_if &:blank?
667
        order_columns = order_columns.zip((0...order_columns.size).to_a).map { |s,i| "#{s} AS alias_#{i}" }
668

669 670
        # Return a DISTINCT ON() clause that's distinct on the columns we want but includes
        # all the required columns for the ORDER BY to work properly.
671 672
        sql = "DISTINCT ON (#{columns}) #{columns}, "
        sql << order_columns * ', '
673
      end
674
      
675
      # Returns an ORDER BY clause for the passed order option.
676 677 678
      # 
      # PostgreSQL does not allow arbitrary ordering when using DISTINCT ON, so we work around this
      # by wrapping the sql as a sub-select and ordering in that query.
679
      def add_order_by_for_association_limiting!(sql, options) #:nodoc:
680 681 682 683 684 685 686 687
        return sql if options[:order].blank?
        
        order = options[:order].split(',').collect { |s| s.strip }.reject(&:blank?)
        order.map! { |s| 'DESC' if s =~ /\bdesc$/i }
        order = order.zip((0...order.size).to_a).map { |s,i| "id_list.alias_#{i} #{s}" }.join(', ')
        
        sql.replace "SELECT * FROM (#{sql}) AS id_list ORDER BY #{order}"
      end
688

689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705
      protected
        # Returns the version of the connected PostgreSQL version.
        def postgresql_version
          @postgresql_version ||=
            if @connection.respond_to?(:server_version)
              @connection.server_version
            else
              # Mimic PGconn.server_version behavior
              begin
                query('SELECT version()')[0][0] =~ /PostgreSQL (\d+)\.(\d+)\.(\d+)/
                ($1.to_i * 10000) + ($2.to_i * 100) + $3.to_i
              rescue
                0
              end
            end
        end

D
Initial  
David Heinemeier Hansson 已提交
706
      private
707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728
        # The internal PostgreSQL identifer of the money data type.
        MONEY_COLUMN_TYPE_OID = 790 #:nodoc:

        # Connects to a PostgreSQL server and sets up the adapter depending on the
        # connected server's characteristics.
        def connect
          @connection = PGconn.connect(*@connection_parameters)
          PGconn.translate_results = false if PGconn.respond_to?(:translate_results=)

          # Ignore async_exec and async_query when using postgres-pr.
          @async = @config[:allow_concurrency] && @connection.respond_to?(:async_exec)

          # Use escape string syntax if available. We cannot do this lazily when encountering
          # the first string, because that could then break any transactions in progress.
          # See: http://www.postgresql.org/docs/current/static/runtime-config-compatible.html
          # If PostgreSQL doesn't know the standard_conforming_strings parameter then it doesn't
          # support escape string syntax. Don't override the inherited quoted_string_prefix.
          if supports_standard_conforming_strings?
            self.class.instance_eval do
              define_method(:quoted_string_prefix) { 'E' }
            end
          end
729

730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748
          # Money type has a fixed precision of 10 in PostgreSQL 8.2 and below, and as of
          # PostgreSQL 8.3 it has a fixed precision of 19. PostgreSQLColumn.extract_precision
          # should know about this but can't detect it there, so deal with it here.
          money_precision = (postgresql_version >= 80300) ? 19 : 10
          PostgreSQLColumn.module_eval(<<-end_eval)
            def extract_precision(sql_type)
              if sql_type =~ /^money$/
                #{money_precision}
              else
                super
              end
            end
          end_eval

          configure_connection
        end

        # Configures the encoding, verbosity, and schema search path of the connection.
        # This is called by #connect and should not be called manually.
749 750
        def configure_connection
          if @config[:encoding]
751 752 753 754 755
            if @connection.respond_to?(:set_client_encoding)
              @connection.set_client_encoding(@config[:encoding])
            else
              execute("SET client_encoding TO '#{@config[:encoding]}'")
            end
756
          end
757 758
          self.client_min_messages = @config[:min_messages] if @config[:min_messages]
          self.schema_search_path = @config[:schema_search_path] || @config[:schema_order]
759 760
        end

761 762
        # Returns the current ID of a table's sequence.
        def last_insert_id(table, sequence_name) #:nodoc:
763
          Integer(select_value("SELECT currval('#{sequence_name}')"))
D
Initial  
David Heinemeier Hansson 已提交
764 765
        end

766
        # Executes a SELECT query and returns the results, performing any data type
767
        # conversions that are required to be performed here instead of in PostgreSQLColumn.
D
Initial  
David Heinemeier Hansson 已提交
768
        def select(sql, name = nil)
769 770 771 772 773 774 775 776 777 778 779 780 781
          fields, rows = select_raw(sql, name)
          result = []
          for row in rows
            row_hash = {}
            fields.each_with_index do |f, i|
              row_hash[f] = row[i]
            end
            result << row_hash
          end
          result
        end

        def select_raw(sql, name = nil)
782
          res = execute(sql, name)
783
          results = res.result
784
          fields = []
M
Marcel Molina 已提交
785 786 787 788 789
          rows = []
          if results.length > 0
            fields = res.fields
            results.each do |row|
              hashed_row = {}
790 791 792
              row.each_index do |cell_index|
                # If this is a money type column and there are any currency symbols,
                # then strip them off. Indeed it would be prettier to do this in
793
                # PostgreSQLColumn.string_to_decimal but would break form input
794 795 796
                # fields that call value_before_type_cast.
                if res.type(cell_index) == MONEY_COLUMN_TYPE_OID
                  # Because money output is formatted according to the locale, there are two
797
                  # cases to consider (note the decimal separators):
798 799
                  #  (1) $12,345,678.12        
                  #  (2) $12.345.678,12
800
                  case column = row[cell_index]
801
                    when /^-?\D+[\d,]+\.\d{2}$/  # (1)
802
                      row[cell_index] = column.gsub(/[^-\d\.]/, '')
803
                    when /^-?\D+[\d\.]+,\d{2}$/  # (2)
804
                      row[cell_index] = column.gsub(/[^-\d,]/, '').sub(/,/, '.')
805
                  end
M
Marcel Molina 已提交
806
                end
807

808
                hashed_row[fields[cell_index]] = column
M
Marcel Molina 已提交
809
              end
810
              rows << row
M
Marcel Molina 已提交
811 812
            end
          end
813
          res.clear
814
          return fields, rows
M
Marcel Molina 已提交
815 816
        end

817
        # Returns the list of a table's column names, data types, and default values.
818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834
        #
        # The underlying query is roughly:
        #  SELECT column.name, column.type, default.value
        #    FROM column LEFT JOIN default
        #      ON column.table_id = default.table_id
        #     AND column.num = default.column_num
        #   WHERE column.table_id = get_table_id('table_name')
        #     AND column.num > 0
        #     AND NOT column.is_dropped
        #   ORDER BY column.num
        #
        # If the table name is not prefixed with a schema, the database will
        # take the first match from the schema search path.
        #
        # Query implementation notes:
        #  - format_type includes the column size constraint, e.g. varchar(50)
        #  - ::regclass is a function that gives the id for a table name
835
        def column_definitions(table_name) #:nodoc:
836
          query <<-end_sql
837
            SELECT a.attname, format_type(a.atttypid, a.atttypmod), d.adsrc, a.attnotnull
838 839 840 841 842 843
              FROM pg_attribute a LEFT JOIN pg_attrdef d
                ON a.attrelid = d.adrelid AND a.attnum = d.adnum
             WHERE a.attrelid = '#{table_name}'::regclass
               AND a.attnum > 0 AND NOT a.attisdropped
             ORDER BY a.attnum
          end_sql
D
Initial  
David Heinemeier Hansson 已提交
844 845 846 847
        end
    end
  end
end