Froze rails gems
[depot.git] / vendor / rails / activerecord / lib / active_record / connection_adapters / postgresql_adapter.rb
1 require 'active_record/connection_adapters/abstract_adapter'
2
3 begin
4 require_library_or_gem 'pg'
5 rescue LoadError => e
6 begin
7 require_library_or_gem 'postgres'
8 class PGresult
9 alias_method :nfields, :num_fields unless self.method_defined?(:nfields)
10 alias_method :ntuples, :num_tuples unless self.method_defined?(:ntuples)
11 alias_method :ftype, :type unless self.method_defined?(:ftype)
12 alias_method :cmd_tuples, :cmdtuples unless self.method_defined?(:cmd_tuples)
13 end
14 rescue LoadError
15 raise e
16 end
17 end
18
19 module ActiveRecord
20 class Base
21 # Establishes a connection to the database that's used by all Active Record objects
22 def self.postgresql_connection(config) # :nodoc:
23 config = config.symbolize_keys
24 host = config[:host]
25 port = config[:port] || 5432
26 username = config[:username].to_s if config[:username]
27 password = config[:password].to_s if config[:password]
28
29 if config.has_key?(:database)
30 database = config[:database]
31 else
32 raise ArgumentError, "No database specified. Missing argument: database."
33 end
34
35 # The postgres drivers don't allow the creation of an unconnected PGconn object,
36 # so just pass a nil connection object for the time being.
37 ConnectionAdapters::PostgreSQLAdapter.new(nil, logger, [host, port, nil, nil, database, username, password], config)
38 end
39 end
40
41 module ConnectionAdapters
42 # PostgreSQL-specific extensions to column definitions in a table.
43 class PostgreSQLColumn < Column #:nodoc:
44 # Instantiates a new PostgreSQL column definition in a table.
45 def initialize(name, default, sql_type = nil, null = true)
46 super(name, self.class.extract_value_from_default(default), sql_type, null)
47 end
48
49 private
50 def extract_limit(sql_type)
51 case sql_type
52 when /^bigint/i; 8
53 when /^smallint/i; 2
54 else super
55 end
56 end
57
58 # Extracts the scale from PostgreSQL-specific data types.
59 def extract_scale(sql_type)
60 # Money type has a fixed scale of 2.
61 sql_type =~ /^money/ ? 2 : super
62 end
63
64 # Extracts the precision from PostgreSQL-specific data types.
65 def extract_precision(sql_type)
66 # Actual code is defined dynamically in PostgreSQLAdapter.connect
67 # depending on the server specifics
68 super
69 end
70
71 # Maps PostgreSQL-specific data types to logical Rails types.
72 def simplified_type(field_type)
73 case field_type
74 # Numeric and monetary types
75 when /^(?:real|double precision)$/
76 :float
77 # Monetary types
78 when /^money$/
79 :decimal
80 # Character types
81 when /^(?:character varying|bpchar)(?:\(\d+\))?$/
82 :string
83 # Binary data types
84 when /^bytea$/
85 :binary
86 # Date/time types
87 when /^timestamp with(?:out)? time zone$/
88 :datetime
89 when /^interval$/
90 :string
91 # Geometric types
92 when /^(?:point|line|lseg|box|"?path"?|polygon|circle)$/
93 :string
94 # Network address types
95 when /^(?:cidr|inet|macaddr)$/
96 :string
97 # Bit strings
98 when /^bit(?: varying)?(?:\(\d+\))?$/
99 :string
100 # XML type
101 when /^xml$/
102 :string
103 # Arrays
104 when /^\D+\[\]$/
105 :string
106 # Object identifier types
107 when /^oid$/
108 :integer
109 # Pass through all types that are not specific to PostgreSQL.
110 else
111 super
112 end
113 end
114
115 # Extracts the value from a PostgreSQL column default definition.
116 def self.extract_value_from_default(default)
117 case default
118 # Numeric types
119 when /\A\(?(-?\d+(\.\d*)?\)?)\z/
120 $1
121 # Character types
122 when /\A'(.*)'::(?:character varying|bpchar|text)\z/m
123 $1
124 # Character types (8.1 formatting)
125 when /\AE'(.*)'::(?:character varying|bpchar|text)\z/m
126 $1.gsub(/\\(\d\d\d)/) { $1.oct.chr }
127 # Binary data types
128 when /\A'(.*)'::bytea\z/m
129 $1
130 # Date/time types
131 when /\A'(.+)'::(?:time(?:stamp)? with(?:out)? time zone|date)\z/
132 $1
133 when /\A'(.*)'::interval\z/
134 $1
135 # Boolean type
136 when 'true'
137 true
138 when 'false'
139 false
140 # Geometric types
141 when /\A'(.*)'::(?:point|line|lseg|box|"?path"?|polygon|circle)\z/
142 $1
143 # Network address types
144 when /\A'(.*)'::(?:cidr|inet|macaddr)\z/
145 $1
146 # Bit string types
147 when /\AB'(.*)'::"?bit(?: varying)?"?\z/
148 $1
149 # XML type
150 when /\A'(.*)'::xml\z/m
151 $1
152 # Arrays
153 when /\A'(.*)'::"?\D+"?\[\]\z/
154 $1
155 # Object identifier types
156 when /\A-?\d+\z/
157 $1
158 else
159 # Anything else is blank, some user type, or some function
160 # and we can't know the value of that, so return nil.
161 nil
162 end
163 end
164 end
165 end
166
167 module ConnectionAdapters
168 # The PostgreSQL adapter works both with the native C (http://ruby.scripting.ca/postgres/) and the pure
169 # Ruby (available both as gem and from http://rubyforge.org/frs/?group_id=234&release_id=1944) drivers.
170 #
171 # Options:
172 #
173 # * <tt>:host</tt> - Defaults to "localhost".
174 # * <tt>:port</tt> - Defaults to 5432.
175 # * <tt>:username</tt> - Defaults to nothing.
176 # * <tt>:password</tt> - Defaults to nothing.
177 # * <tt>:database</tt> - The name of the database. No default, must be provided.
178 # * <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 <tt>:schema_order</tt> option.
179 # * <tt>:encoding</tt> - An optional client encoding that is used in a <tt>SET client_encoding TO <encoding></tt> call on the connection.
180 # * <tt>:min_messages</tt> - An optional client min messages that is used in a <tt>SET client_min_messages TO <min_messages></tt> call on the connection.
181 # * <tt>:allow_concurrency</tt> - If true, use async query methods so Ruby threads don't deadlock; otherwise, use blocking query methods.
182 class PostgreSQLAdapter < AbstractAdapter
183 ADAPTER_NAME = 'PostgreSQL'.freeze
184
185 NATIVE_DATABASE_TYPES = {
186 :primary_key => "serial primary key".freeze,
187 :string => { :name => "character varying", :limit => 255 },
188 :text => { :name => "text" },
189 :integer => { :name => "integer" },
190 :float => { :name => "float" },
191 :decimal => { :name => "decimal" },
192 :datetime => { :name => "timestamp" },
193 :timestamp => { :name => "timestamp" },
194 :time => { :name => "time" },
195 :date => { :name => "date" },
196 :binary => { :name => "bytea" },
197 :boolean => { :name => "boolean" }
198 }
199
200 # Returns 'PostgreSQL' as adapter name for identification purposes.
201 def adapter_name
202 ADAPTER_NAME
203 end
204
205 # Initializes and connects a PostgreSQL adapter.
206 def initialize(connection, logger, connection_parameters, config)
207 super(connection, logger)
208 @connection_parameters, @config = connection_parameters, config
209
210 connect
211 end
212
213 # Is this connection alive and ready for queries?
214 def active?
215 if @connection.respond_to?(:status)
216 @connection.status == PGconn::CONNECTION_OK
217 else
218 # We're asking the driver, not ActiveRecord, so use @connection.query instead of #query
219 @connection.query 'SELECT 1'
220 true
221 end
222 # postgres-pr raises a NoMethodError when querying if no connection is available.
223 rescue PGError, NoMethodError
224 false
225 end
226
227 # Close then reopen the connection.
228 def reconnect!
229 if @connection.respond_to?(:reset)
230 @connection.reset
231 configure_connection
232 else
233 disconnect!
234 connect
235 end
236 end
237
238 # Close the connection.
239 def disconnect!
240 @connection.close rescue nil
241 end
242
243 def native_database_types #:nodoc:
244 NATIVE_DATABASE_TYPES
245 end
246
247 # Does PostgreSQL support migrations?
248 def supports_migrations?
249 true
250 end
251
252 # Does PostgreSQL support standard conforming strings?
253 def supports_standard_conforming_strings?
254 # Temporarily set the client message level above error to prevent unintentional
255 # error messages in the logs when working on a PostgreSQL database server that
256 # does not support standard conforming strings.
257 client_min_messages_old = client_min_messages
258 self.client_min_messages = 'panic'
259
260 # postgres-pr does not raise an exception when client_min_messages is set higher
261 # than error and "SHOW standard_conforming_strings" fails, but returns an empty
262 # PGresult instead.
263 has_support = query('SHOW standard_conforming_strings')[0][0] rescue false
264 self.client_min_messages = client_min_messages_old
265 has_support
266 end
267
268 def supports_insert_with_returning?
269 postgresql_version >= 80200
270 end
271
272 def supports_ddl_transactions?
273 true
274 end
275
276 # Returns the configured supported identifier length supported by PostgreSQL,
277 # or report the default of 63 on PostgreSQL 7.x.
278 def table_alias_length
279 @table_alias_length ||= (postgresql_version >= 80000 ? query('SHOW max_identifier_length')[0][0].to_i : 63)
280 end
281
282 # QUOTING ==================================================
283
284 # Escapes binary strings for bytea input to the database.
285 def escape_bytea(value)
286 if PGconn.respond_to?(:escape_bytea)
287 self.class.instance_eval do
288 define_method(:escape_bytea) do |value|
289 PGconn.escape_bytea(value) if value
290 end
291 end
292 else
293 self.class.instance_eval do
294 define_method(:escape_bytea) do |value|
295 if value
296 result = ''
297 value.each_byte { |c| result << sprintf('\\\\%03o', c) }
298 result
299 end
300 end
301 end
302 end
303 escape_bytea(value)
304 end
305
306 # Unescapes bytea output from a database to the binary string it represents.
307 # NOTE: This is NOT an inverse of escape_bytea! This is only to be used
308 # on escaped binary output from database drive.
309 def unescape_bytea(value)
310 # In each case, check if the value actually is escaped PostgreSQL bytea output
311 # or an unescaped Active Record attribute that was just written.
312 if PGconn.respond_to?(:unescape_bytea)
313 self.class.instance_eval do
314 define_method(:unescape_bytea) do |value|
315 if value =~ /\\\d{3}/
316 PGconn.unescape_bytea(value)
317 else
318 value
319 end
320 end
321 end
322 else
323 self.class.instance_eval do
324 define_method(:unescape_bytea) do |value|
325 if value =~ /\\\d{3}/
326 result = ''
327 i, max = 0, value.size
328 while i < max
329 char = value[i]
330 if char == ?\\
331 if value[i+1] == ?\\
332 char = ?\\
333 i += 1
334 else
335 char = value[i+1..i+3].oct
336 i += 3
337 end
338 end
339 result << char
340 i += 1
341 end
342 result
343 else
344 value
345 end
346 end
347 end
348 end
349 unescape_bytea(value)
350 end
351
352 # Quotes PostgreSQL-specific data types for SQL input.
353 def quote(value, column = nil) #:nodoc:
354 if value.kind_of?(String) && column && column.type == :binary
355 "#{quoted_string_prefix}'#{escape_bytea(value)}'"
356 elsif value.kind_of?(String) && column && column.sql_type =~ /^xml$/
357 "xml '#{quote_string(value)}'"
358 elsif value.kind_of?(Numeric) && column && column.sql_type =~ /^money$/
359 # Not truly string input, so doesn't require (or allow) escape string syntax.
360 "'#{value.to_s}'"
361 elsif value.kind_of?(String) && column && column.sql_type =~ /^bit/
362 case value
363 when /^[01]*$/
364 "B'#{value}'" # Bit-string notation
365 when /^[0-9A-F]*$/i
366 "X'#{value}'" # Hexadecimal notation
367 end
368 else
369 super
370 end
371 end
372
373 # Quotes strings for use in SQL input in the postgres driver for better performance.
374 def quote_string(s) #:nodoc:
375 if PGconn.respond_to?(:escape)
376 self.class.instance_eval do
377 define_method(:quote_string) do |s|
378 PGconn.escape(s)
379 end
380 end
381 else
382 # There are some incorrectly compiled postgres drivers out there
383 # that don't define PGconn.escape.
384 self.class.instance_eval do
385 remove_method(:quote_string)
386 end
387 end
388 quote_string(s)
389 end
390
391 # Quotes column names for use in SQL queries.
392 def quote_column_name(name) #:nodoc:
393 %("#{name}")
394 end
395
396 # Quote date/time values for use in SQL input. Includes microseconds
397 # if the value is a Time responding to usec.
398 def quoted_date(value) #:nodoc:
399 if value.acts_like?(:time) && value.respond_to?(:usec)
400 "#{super}.#{sprintf("%06d", value.usec)}"
401 else
402 super
403 end
404 end
405
406 # REFERENTIAL INTEGRITY ====================================
407
408 def supports_disable_referential_integrity?() #:nodoc:
409 version = query("SHOW server_version")[0][0].split('.')
410 (version[0].to_i >= 8 && version[1].to_i >= 1) ? true : false
411 rescue
412 return false
413 end
414
415 def disable_referential_integrity(&block) #:nodoc:
416 if supports_disable_referential_integrity?() then
417 execute(tables.collect { |name| "ALTER TABLE #{quote_table_name(name)} DISABLE TRIGGER ALL" }.join(";"))
418 end
419 yield
420 ensure
421 if supports_disable_referential_integrity?() then
422 execute(tables.collect { |name| "ALTER TABLE #{quote_table_name(name)} ENABLE TRIGGER ALL" }.join(";"))
423 end
424 end
425
426 # DATABASE STATEMENTS ======================================
427
428 # Executes a SELECT query and returns an array of rows. Each row is an
429 # array of field values.
430 def select_rows(sql, name = nil)
431 select_raw(sql, name).last
432 end
433
434 # Executes an INSERT query and returns the new record's ID
435 def insert(sql, name = nil, pk = nil, id_value = nil, sequence_name = nil)
436 # Extract the table from the insert sql. Yuck.
437 table = sql.split(" ", 4)[2].gsub('"', '')
438
439 # Try an insert with 'returning id' if available (PG >= 8.2)
440 if supports_insert_with_returning?
441 pk, sequence_name = *pk_and_sequence_for(table) unless pk
442 if pk
443 id = select_value("#{sql} RETURNING #{quote_column_name(pk)}")
444 clear_query_cache
445 return id
446 end
447 end
448
449 # Otherwise, insert then grab last_insert_id.
450 if insert_id = super
451 insert_id
452 else
453 # If neither pk nor sequence name is given, look them up.
454 unless pk || sequence_name
455 pk, sequence_name = *pk_and_sequence_for(table)
456 end
457
458 # If a pk is given, fallback to default sequence name.
459 # Don't fetch last insert id for a table without a pk.
460 if pk && sequence_name ||= default_sequence_name(table, pk)
461 last_insert_id(table, sequence_name)
462 end
463 end
464 end
465
466 # create a 2D array representing the result set
467 def result_as_array(res) #:nodoc:
468 # check if we have any binary column and if they need escaping
469 unescape_col = []
470 for j in 0...res.nfields do
471 # unescape string passed BYTEA field (OID == 17)
472 unescape_col << ( res.ftype(j)==17 )
473 end
474
475 ary = []
476 for i in 0...res.ntuples do
477 ary << []
478 for j in 0...res.nfields do
479 data = res.getvalue(i,j)
480 data = unescape_bytea(data) if unescape_col[j] and data.is_a?(String)
481 ary[i] << data
482 end
483 end
484 return ary
485 end
486
487
488 # Queries the database and returns the results in an Array-like object
489 def query(sql, name = nil) #:nodoc:
490 log(sql, name) do
491 if @async
492 res = @connection.async_exec(sql)
493 else
494 res = @connection.exec(sql)
495 end
496 return result_as_array(res)
497 end
498 end
499
500 # Executes an SQL statement, returning a PGresult object on success
501 # or raising a PGError exception otherwise.
502 def execute(sql, name = nil)
503 log(sql, name) do
504 if @async
505 @connection.async_exec(sql)
506 else
507 @connection.exec(sql)
508 end
509 end
510 end
511
512 # Executes an UPDATE query and returns the number of affected tuples.
513 def update_sql(sql, name = nil)
514 super.cmd_tuples
515 end
516
517 # Begins a transaction.
518 def begin_db_transaction
519 execute "BEGIN"
520 end
521
522 # Commits a transaction.
523 def commit_db_transaction
524 execute "COMMIT"
525 end
526
527 # Aborts a transaction.
528 def rollback_db_transaction
529 execute "ROLLBACK"
530 end
531
532 # ruby-pg defines Ruby constants for transaction status,
533 # ruby-postgres does not.
534 PQTRANS_IDLE = defined?(PGconn::PQTRANS_IDLE) ? PGconn::PQTRANS_IDLE : 0
535
536 # Check whether a transaction is active.
537 def transaction_active?
538 @connection.transaction_status != PQTRANS_IDLE
539 end
540
541 # Wrap a block in a transaction. Returns result of block.
542 def transaction(start_db_transaction = true)
543 transaction_open = false
544 begin
545 if block_given?
546 if start_db_transaction
547 begin_db_transaction
548 transaction_open = true
549 end
550 yield
551 end
552 rescue Exception => database_transaction_rollback
553 if transaction_open && transaction_active?
554 transaction_open = false
555 rollback_db_transaction
556 end
557 raise unless database_transaction_rollback.is_a? ActiveRecord::Rollback
558 end
559 ensure
560 if transaction_open && transaction_active?
561 begin
562 commit_db_transaction
563 rescue Exception => database_transaction_rollback
564 rollback_db_transaction
565 raise
566 end
567 end
568 end
569
570
571 # SCHEMA STATEMENTS ========================================
572
573 def recreate_database(name) #:nodoc:
574 drop_database(name)
575 create_database(name)
576 end
577
578 # Create a new PostgreSQL database. Options include <tt>:owner</tt>, <tt>:template</tt>,
579 # <tt>:encoding</tt>, <tt>:tablespace</tt>, and <tt>:connection_limit</tt> (note that MySQL uses
580 # <tt>:charset</tt> while PostgreSQL uses <tt>:encoding</tt>).
581 #
582 # Example:
583 # create_database config[:database], config
584 # create_database 'foo_development', :encoding => 'unicode'
585 def create_database(name, options = {})
586 options = options.reverse_merge(:encoding => "utf8")
587
588 option_string = options.symbolize_keys.sum do |key, value|
589 case key
590 when :owner
591 " OWNER = \"#{value}\""
592 when :template
593 " TEMPLATE = \"#{value}\""
594 when :encoding
595 " ENCODING = '#{value}'"
596 when :tablespace
597 " TABLESPACE = \"#{value}\""
598 when :connection_limit
599 " CONNECTION LIMIT = #{value}"
600 else
601 ""
602 end
603 end
604
605 execute "CREATE DATABASE #{quote_table_name(name)}#{option_string}"
606 end
607
608 # Drops a PostgreSQL database
609 #
610 # Example:
611 # drop_database 'matt_development'
612 def drop_database(name) #:nodoc:
613 if postgresql_version >= 80200
614 execute "DROP DATABASE IF EXISTS #{quote_table_name(name)}"
615 else
616 begin
617 execute "DROP DATABASE #{quote_table_name(name)}"
618 rescue ActiveRecord::StatementInvalid
619 @logger.warn "#{name} database doesn't exist." if @logger
620 end
621 end
622 end
623
624
625 # Returns the list of all tables in the schema search path or a specified schema.
626 def tables(name = nil)
627 schemas = schema_search_path.split(/,/).map { |p| quote(p) }.join(',')
628 query(<<-SQL, name).map { |row| row[0] }
629 SELECT tablename
630 FROM pg_tables
631 WHERE schemaname IN (#{schemas})
632 SQL
633 end
634
635 # Returns the list of all indexes for a table.
636 def indexes(table_name, name = nil)
637 schemas = schema_search_path.split(/,/).map { |p| quote(p) }.join(',')
638 result = query(<<-SQL, name)
639 SELECT distinct i.relname, d.indisunique, a.attname
640 FROM pg_class t, pg_class i, pg_index d, pg_attribute a
641 WHERE i.relkind = 'i'
642 AND d.indexrelid = i.oid
643 AND d.indisprimary = 'f'
644 AND t.oid = d.indrelid
645 AND t.relname = '#{table_name}'
646 AND i.relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname IN (#{schemas}) )
647 AND a.attrelid = t.oid
648 AND ( d.indkey[0]=a.attnum OR d.indkey[1]=a.attnum
649 OR d.indkey[2]=a.attnum OR d.indkey[3]=a.attnum
650 OR d.indkey[4]=a.attnum OR d.indkey[5]=a.attnum
651 OR d.indkey[6]=a.attnum OR d.indkey[7]=a.attnum
652 OR d.indkey[8]=a.attnum OR d.indkey[9]=a.attnum )
653 ORDER BY i.relname
654 SQL
655
656 current_index = nil
657 indexes = []
658
659 result.each do |row|
660 if current_index != row[0]
661 indexes << IndexDefinition.new(table_name, row[0], row[1] == "t", [])
662 current_index = row[0]
663 end
664
665 indexes.last.columns << row[2]
666 end
667
668 indexes
669 end
670
671 # Returns the list of all column definitions for a table.
672 def columns(table_name, name = nil)
673 # Limit, precision, and scale are all handled by the superclass.
674 column_definitions(table_name).collect do |name, type, default, notnull|
675 PostgreSQLColumn.new(name, default, type, notnull == 'f')
676 end
677 end
678
679 # Returns the current database name.
680 def current_database
681 query('select current_database()')[0][0]
682 end
683
684 # Returns the current database encoding format.
685 def encoding
686 query(<<-end_sql)[0][0]
687 SELECT pg_encoding_to_char(pg_database.encoding) FROM pg_database
688 WHERE pg_database.datname LIKE '#{current_database}'
689 end_sql
690 end
691
692 # Sets the schema search path to a string of comma-separated schema names.
693 # Names beginning with $ have to be quoted (e.g. $user => '$user').
694 # See: http://www.postgresql.org/docs/current/static/ddl-schemas.html
695 #
696 # This should be not be called manually but set in database.yml.
697 def schema_search_path=(schema_csv)
698 if schema_csv
699 execute "SET search_path TO #{schema_csv}"
700 @schema_search_path = schema_csv
701 end
702 end
703
704 # Returns the active schema search path.
705 def schema_search_path
706 @schema_search_path ||= query('SHOW search_path')[0][0]
707 end
708
709 # Returns the current client message level.
710 def client_min_messages
711 query('SHOW client_min_messages')[0][0]
712 end
713
714 # Set the client message level.
715 def client_min_messages=(level)
716 execute("SET client_min_messages TO '#{level}'")
717 end
718
719 # Returns the sequence name for a table's primary key or some other specified key.
720 def default_sequence_name(table_name, pk = nil) #:nodoc:
721 default_pk, default_seq = pk_and_sequence_for(table_name)
722 default_seq || "#{table_name}_#{pk || default_pk || 'id'}_seq"
723 end
724
725 # Resets the sequence of a table's primary key to the maximum value.
726 def reset_pk_sequence!(table, pk = nil, sequence = nil) #:nodoc:
727 unless pk and sequence
728 default_pk, default_sequence = pk_and_sequence_for(table)
729 pk ||= default_pk
730 sequence ||= default_sequence
731 end
732 if pk
733 if sequence
734 quoted_sequence = quote_column_name(sequence)
735
736 select_value <<-end_sql, 'Reset sequence'
737 SELECT setval('#{quoted_sequence}', (SELECT COALESCE(MAX(#{quote_column_name pk})+(SELECT increment_by FROM #{quoted_sequence}), (SELECT min_value FROM #{quoted_sequence})) FROM #{quote_table_name(table)}), false)
738 end_sql
739 else
740 @logger.warn "#{table} has primary key #{pk} with no default sequence" if @logger
741 end
742 end
743 end
744
745 # Returns a table's primary key and belonging sequence.
746 def pk_and_sequence_for(table) #:nodoc:
747 # First try looking for a sequence with a dependency on the
748 # given table's primary key.
749 result = query(<<-end_sql, 'PK and serial sequence')[0]
750 SELECT attr.attname, seq.relname
751 FROM pg_class seq,
752 pg_attribute attr,
753 pg_depend dep,
754 pg_namespace name,
755 pg_constraint cons
756 WHERE seq.oid = dep.objid
757 AND seq.relkind = 'S'
758 AND attr.attrelid = dep.refobjid
759 AND attr.attnum = dep.refobjsubid
760 AND attr.attrelid = cons.conrelid
761 AND attr.attnum = cons.conkey[1]
762 AND cons.contype = 'p'
763 AND dep.refobjid = '#{table}'::regclass
764 end_sql
765
766 if result.nil? or result.empty?
767 # If that fails, try parsing the primary key's default value.
768 # Support the 7.x and 8.0 nextval('foo'::text) as well as
769 # the 8.1+ nextval('foo'::regclass).
770 result = query(<<-end_sql, 'PK and custom sequence')[0]
771 SELECT attr.attname,
772 CASE
773 WHEN split_part(def.adsrc, '''', 2) ~ '.' THEN
774 substr(split_part(def.adsrc, '''', 2),
775 strpos(split_part(def.adsrc, '''', 2), '.')+1)
776 ELSE split_part(def.adsrc, '''', 2)
777 END
778 FROM pg_class t
779 JOIN pg_attribute attr ON (t.oid = attrelid)
780 JOIN pg_attrdef def ON (adrelid = attrelid AND adnum = attnum)
781 JOIN pg_constraint cons ON (conrelid = adrelid AND adnum = conkey[1])
782 WHERE t.oid = '#{table}'::regclass
783 AND cons.contype = 'p'
784 AND def.adsrc ~* 'nextval'
785 end_sql
786 end
787
788 # [primary_key, sequence]
789 [result.first, result.last]
790 rescue
791 nil
792 end
793
794 # Renames a table.
795 def rename_table(name, new_name)
796 execute "ALTER TABLE #{quote_table_name(name)} RENAME TO #{quote_table_name(new_name)}"
797 end
798
799 # Adds a new column to the named table.
800 # See TableDefinition#column for details of the options you can use.
801 def add_column(table_name, column_name, type, options = {})
802 default = options[:default]
803 notnull = options[:null] == false
804
805 # Add the column.
806 execute("ALTER TABLE #{quote_table_name(table_name)} ADD COLUMN #{quote_column_name(column_name)} #{type_to_sql(type, options[:limit], options[:precision], options[:scale])}")
807
808 change_column_default(table_name, column_name, default) if options_include_default?(options)
809 change_column_null(table_name, column_name, false, default) if notnull
810 end
811
812 # Changes the column of a table.
813 def change_column(table_name, column_name, type, options = {})
814 quoted_table_name = quote_table_name(table_name)
815
816 begin
817 execute "ALTER TABLE #{quoted_table_name} ALTER COLUMN #{quote_column_name(column_name)} TYPE #{type_to_sql(type, options[:limit], options[:precision], options[:scale])}"
818 rescue ActiveRecord::StatementInvalid => e
819 raise e if postgresql_version > 80000
820 # This is PostgreSQL 7.x, so we have to use a more arcane way of doing it.
821 begin
822 begin_db_transaction
823 tmp_column_name = "#{column_name}_ar_tmp"
824 add_column(table_name, tmp_column_name, type, options)
825 execute "UPDATE #{quoted_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])})"
826 remove_column(table_name, column_name)
827 rename_column(table_name, tmp_column_name, column_name)
828 commit_db_transaction
829 rescue
830 rollback_db_transaction
831 end
832 end
833
834 change_column_default(table_name, column_name, options[:default]) if options_include_default?(options)
835 change_column_null(table_name, column_name, options[:null], options[:default]) if options.key?(:null)
836 end
837
838 # Changes the default value of a table column.
839 def change_column_default(table_name, column_name, default)
840 execute "ALTER TABLE #{quote_table_name(table_name)} ALTER COLUMN #{quote_column_name(column_name)} SET DEFAULT #{quote(default)}"
841 end
842
843 def change_column_null(table_name, column_name, null, default = nil)
844 unless null || default.nil?
845 execute("UPDATE #{quote_table_name(table_name)} SET #{quote_column_name(column_name)}=#{quote(default)} WHERE #{quote_column_name(column_name)} IS NULL")
846 end
847 execute("ALTER TABLE #{quote_table_name(table_name)} ALTER #{quote_column_name(column_name)} #{null ? 'DROP' : 'SET'} NOT NULL")
848 end
849
850 # Renames a column in a table.
851 def rename_column(table_name, column_name, new_column_name)
852 execute "ALTER TABLE #{quote_table_name(table_name)} RENAME COLUMN #{quote_column_name(column_name)} TO #{quote_column_name(new_column_name)}"
853 end
854
855 # Drops an index from a table.
856 def remove_index(table_name, options = {})
857 execute "DROP INDEX #{index_name(table_name, options)}"
858 end
859
860 # Maps logical Rails types to PostgreSQL-specific data types.
861 def type_to_sql(type, limit = nil, precision = nil, scale = nil)
862 return super unless type.to_s == 'integer'
863
864 case limit
865 when 1..2; 'smallint'
866 when 3..4, nil; 'integer'
867 when 5..8; 'bigint'
868 else raise(ActiveRecordError, "No integer type has byte size #{limit}. Use a numeric with precision 0 instead.")
869 end
870 end
871
872 # Returns a SELECT DISTINCT clause for a given set of columns and a given ORDER BY clause.
873 #
874 # PostgreSQL requires the ORDER BY columns in the select list for distinct queries, and
875 # requires that the ORDER BY include the distinct column.
876 #
877 # distinct("posts.id", "posts.created_at desc")
878 def distinct(columns, order_by) #:nodoc:
879 return "DISTINCT #{columns}" if order_by.blank?
880
881 # Construct a clean list of column names from the ORDER BY clause, removing
882 # any ASC/DESC modifiers
883 order_columns = order_by.split(',').collect { |s| s.split.first }
884 order_columns.delete_if &:blank?
885 order_columns = order_columns.zip((0...order_columns.size).to_a).map { |s,i| "#{s} AS alias_#{i}" }
886
887 # Return a DISTINCT ON() clause that's distinct on the columns we want but includes
888 # all the required columns for the ORDER BY to work properly.
889 sql = "DISTINCT ON (#{columns}) #{columns}, "
890 sql << order_columns * ', '
891 end
892
893 # Returns an ORDER BY clause for the passed order option.
894 #
895 # PostgreSQL does not allow arbitrary ordering when using DISTINCT ON, so we work around this
896 # by wrapping the +sql+ string as a sub-select and ordering in that query.
897 def add_order_by_for_association_limiting!(sql, options) #:nodoc:
898 return sql if options[:order].blank?
899
900 order = options[:order].split(',').collect { |s| s.strip }.reject(&:blank?)
901 order.map! { |s| 'DESC' if s =~ /\bdesc$/i }
902 order = order.zip((0...order.size).to_a).map { |s,i| "id_list.alias_#{i} #{s}" }.join(', ')
903
904 sql.replace "SELECT * FROM (#{sql}) AS id_list ORDER BY #{order}"
905 end
906
907 protected
908 # Returns the version of the connected PostgreSQL version.
909 def postgresql_version
910 @postgresql_version ||=
911 if @connection.respond_to?(:server_version)
912 @connection.server_version
913 else
914 # Mimic PGconn.server_version behavior
915 begin
916 query('SELECT version()')[0][0] =~ /PostgreSQL (\d+)\.(\d+)\.(\d+)/
917 ($1.to_i * 10000) + ($2.to_i * 100) + $3.to_i
918 rescue
919 0
920 end
921 end
922 end
923
924 private
925 # The internal PostgreSQL identifier of the money data type.
926 MONEY_COLUMN_TYPE_OID = 790 #:nodoc:
927
928 # Connects to a PostgreSQL server and sets up the adapter depending on the
929 # connected server's characteristics.
930 def connect
931 @connection = PGconn.connect(*@connection_parameters)
932 PGconn.translate_results = false if PGconn.respond_to?(:translate_results=)
933
934 # Ignore async_exec and async_query when using postgres-pr.
935 @async = @config[:allow_concurrency] && @connection.respond_to?(:async_exec)
936
937 # Use escape string syntax if available. We cannot do this lazily when encountering
938 # the first string, because that could then break any transactions in progress.
939 # See: http://www.postgresql.org/docs/current/static/runtime-config-compatible.html
940 # If PostgreSQL doesn't know the standard_conforming_strings parameter then it doesn't
941 # support escape string syntax. Don't override the inherited quoted_string_prefix.
942 if supports_standard_conforming_strings?
943 self.class.instance_eval do
944 define_method(:quoted_string_prefix) { 'E' }
945 end
946 end
947
948 # Money type has a fixed precision of 10 in PostgreSQL 8.2 and below, and as of
949 # PostgreSQL 8.3 it has a fixed precision of 19. PostgreSQLColumn.extract_precision
950 # should know about this but can't detect it there, so deal with it here.
951 money_precision = (postgresql_version >= 80300) ? 19 : 10
952 PostgreSQLColumn.module_eval(<<-end_eval)
953 def extract_precision(sql_type)
954 if sql_type =~ /^money$/
955 #{money_precision}
956 else
957 super
958 end
959 end
960 end_eval
961
962 configure_connection
963 end
964
965 # Configures the encoding, verbosity, and schema search path of the connection.
966 # This is called by #connect and should not be called manually.
967 def configure_connection
968 if @config[:encoding]
969 if @connection.respond_to?(:set_client_encoding)
970 @connection.set_client_encoding(@config[:encoding])
971 else
972 execute("SET client_encoding TO '#{@config[:encoding]}'")
973 end
974 end
975 self.client_min_messages = @config[:min_messages] if @config[:min_messages]
976 self.schema_search_path = @config[:schema_search_path] || @config[:schema_order]
977 end
978
979 # Returns the current ID of a table's sequence.
980 def last_insert_id(table, sequence_name) #:nodoc:
981 Integer(select_value("SELECT currval('#{sequence_name}')"))
982 end
983
984 # Executes a SELECT query and returns the results, performing any data type
985 # conversions that are required to be performed here instead of in PostgreSQLColumn.
986 def select(sql, name = nil)
987 fields, rows = select_raw(sql, name)
988 result = []
989 for row in rows
990 row_hash = {}
991 fields.each_with_index do |f, i|
992 row_hash[f] = row[i]
993 end
994 result << row_hash
995 end
996 result
997 end
998
999 def select_raw(sql, name = nil)
1000 res = execute(sql, name)
1001 results = result_as_array(res)
1002 fields = []
1003 rows = []
1004 if res.ntuples > 0
1005 fields = res.fields
1006 results.each do |row|
1007 hashed_row = {}
1008 row.each_index do |cell_index|
1009 # If this is a money type column and there are any currency symbols,
1010 # then strip them off. Indeed it would be prettier to do this in
1011 # PostgreSQLColumn.string_to_decimal but would break form input
1012 # fields that call value_before_type_cast.
1013 if res.ftype(cell_index) == MONEY_COLUMN_TYPE_OID
1014 # Because money output is formatted according to the locale, there are two
1015 # cases to consider (note the decimal separators):
1016 # (1) $12,345,678.12
1017 # (2) $12.345.678,12
1018 case column = row[cell_index]
1019 when /^-?\D+[\d,]+\.\d{2}$/ # (1)
1020 row[cell_index] = column.gsub(/[^-\d\.]/, '')
1021 when /^-?\D+[\d\.]+,\d{2}$/ # (2)
1022 row[cell_index] = column.gsub(/[^-\d,]/, '').sub(/,/, '.')
1023 end
1024 end
1025
1026 hashed_row[fields[cell_index]] = column
1027 end
1028 rows << row
1029 end
1030 end
1031 res.clear
1032 return fields, rows
1033 end
1034
1035 # Returns the list of a table's column names, data types, and default values.
1036 #
1037 # The underlying query is roughly:
1038 # SELECT column.name, column.type, default.value
1039 # FROM column LEFT JOIN default
1040 # ON column.table_id = default.table_id
1041 # AND column.num = default.column_num
1042 # WHERE column.table_id = get_table_id('table_name')
1043 # AND column.num > 0
1044 # AND NOT column.is_dropped
1045 # ORDER BY column.num
1046 #
1047 # If the table name is not prefixed with a schema, the database will
1048 # take the first match from the schema search path.
1049 #
1050 # Query implementation notes:
1051 # - format_type includes the column size constraint, e.g. varchar(50)
1052 # - ::regclass is a function that gives the id for a table name
1053 def column_definitions(table_name) #:nodoc:
1054 query <<-end_sql
1055 SELECT a.attname, format_type(a.atttypid, a.atttypmod), d.adsrc, a.attnotnull
1056 FROM pg_attribute a LEFT JOIN pg_attrdef d
1057 ON a.attrelid = d.adrelid AND a.attnum = d.adnum
1058 WHERE a.attrelid = '#{table_name}'::regclass
1059 AND a.attnum > 0 AND NOT a.attisdropped
1060 ORDER BY a.attnum
1061 end_sql
1062 end
1063 end
1064 end
1065 end