2 # Don't need to load native postgres adapter
3 $LOADED_FEATURES << "active_record/connection_adapters/postgresql_adapter.rb"
5 module ActiveRecordExtensions
6 def postgresql_connection(config)
7 config[:host] ||= "localhost"
9 config[:url] ||= "jdbc:postgresql://#{config[:host]}:#{config[:port]}/#{config[:database]}"
10 config[:url] << config[:pg_params] if config[:pg_params]
11 config[:driver] ||= "org.postgresql.Driver"
12 jdbc_connection(config)
17 def self.column_selector
18 [/postgre/i, lambda {|cfg,col| col.extend(::JdbcSpec::PostgreSQL::Column)}]
21 def self.adapter_selector
22 [/postgre/i, lambda {|cfg,adapt| adapt.extend(::JdbcSpec::PostgreSQL)}]
28 when :boolean then cast_to_boolean(value)
33 def simplified_type(field_type)
34 return :integer if field_type =~ /^serial/i
35 return :string if field_type =~ /\[\]$/i || field_type =~ /^interval/i
36 return :string if field_type =~ /^(?:point|lseg|box|"?path"?|polygon|circle)/i
37 return :datetime if field_type =~ /^timestamp/i
38 return :float if field_type =~ /^real|^money/i
39 return :binary if field_type =~ /^bytea/i
40 return :boolean if field_type =~ /^bool/i
44 def cast_to_boolean(value)
45 if value == true || value == false
48 %w(true t 1).include?(value.to_s.downcase)
52 def cast_to_date_or_time(value)
53 return value if value.is_a? Date
54 return nil if value.blank?
55 guess_date_or_time((value.is_a? Time) ? value : cast_to_time(value))
58 def cast_to_time(value)
59 return value if value.is_a? Time
60 time_array = ParseDate.parsedate value
61 time_array[0] ||= 2000; time_array[1] ||= 1; time_array[2] ||= 1;
62 Time.send(ActiveRecord::Base.default_timezone, *time_array) rescue nil
65 def guess_date_or_time(value)
66 (value.hour == 0 and value.min == 0 and value.sec == 0) ?
67 Date.new(value.year, value.month, value.day) : value
70 def default_value(value)
72 return "t" if value =~ /true/i
73 return "f" if value =~ /false/i
75 # Char/String/Bytea type values
76 return $1 if value =~ /^'(.*)'::(bpchar|text|character varying|bytea)$/
79 return value if value =~ /^-?[0-9]+(\.[0-9]*)?/
81 # Fixed dates / timestamp
82 return $1 if value =~ /^'(.+)'::(date|timestamp)/
84 # Anything else is blank, some user type, or some function
85 # and we can't know the value of that, so return nil.
91 tp[:primary_key] = "serial primary key"
92 tp[:string][:limit] = 255
93 tp[:integer][:limit] = nil
94 tp[:boolean][:limit] = nil
98 def default_sequence_name(table_name, pk = nil)
99 default_pk, default_seq = pk_and_sequence_for(table_name)
100 default_seq || "#{table_name}_#{pk || default_pk || 'id'}_seq"
103 # Resets sequence to the max value of the table's pk if present.
104 def reset_pk_sequence!(table, pk = nil, sequence = nil)
105 unless pk and sequence
106 default_pk, default_sequence = pk_and_sequence_for(table)
108 sequence ||= default_sequence
112 select_value <<-end_sql, 'Reset sequence'
113 SELECT setval('#{sequence}', (SELECT COALESCE(MAX(#{pk})+(SELECT increment_by FROM #{sequence}), (SELECT min_value FROM #{sequence})) FROM #{table}), false)
116 @logger.warn "#{table} has primary key #{pk} with no default sequence" if @logger
121 # Find a table's primary key and sequence.
122 def pk_and_sequence_for(table)
123 # First try looking for a sequence with a dependency on the
124 # given table's primary key.
125 result = select(<<-end_sql, 'PK and serial sequence')[0]
126 SELECT attr.attname AS nm, name.nspname AS nsp, seq.relname AS rel
132 WHERE seq.oid = dep.objid
133 AND seq.relnamespace = name.oid
134 AND seq.relkind = 'S'
135 AND attr.attrelid = dep.refobjid
136 AND attr.attnum = dep.refobjsubid
137 AND attr.attrelid = cons.conrelid
138 AND attr.attnum = cons.conkey[1]
139 AND cons.contype = 'p'
140 AND dep.refobjid = '#{table}'::regclass
143 if result.nil? or result.empty?
144 # If that fails, try parsing the primary key's default value.
145 # Support the 7.x and 8.0 nextval('foo'::text) as well as
146 # the 8.1+ nextval('foo'::regclass).
147 # TODO: assumes sequence is in same schema as table.
148 result = select(<<-end_sql, 'PK and custom sequence')[0]
149 SELECT attr.attname AS nm, name.nspname AS nsp, split_part(def.adsrc, '\\\'', 2) AS rel
151 JOIN pg_namespace name ON (t.relnamespace = name.oid)
152 JOIN pg_attribute attr ON (t.oid = attrelid)
153 JOIN pg_attrdef def ON (adrelid = attrelid AND adnum = attnum)
154 JOIN pg_constraint cons ON (conrelid = adrelid AND adnum = conkey[1])
155 WHERE t.oid = '#{table}'::regclass
156 AND cons.contype = 'p'
157 AND def.adsrc ~* 'nextval'
160 # check for existence of . in sequence name as in public.foo_sequence. if it does not exist, join the current namespace
161 result['rel']['.'] ? [result['nm'], result['rel']] : [result['nm'], "#{result['nsp']}.#{result['rel']}"]
166 def insert(sql, name = nil, pk = nil, id_value = nil, sequence_name = nil) #:nodoc:
168 table = sql.split(" ", 4)[2]
169 id_value || pk && last_insert_id(table, sequence_name || default_sequence_name(table, pk))
172 def columns(table_name, name=nil)
173 schema_name = "public"
174 if table_name =~ /\./
175 parts = table_name.split(/\./)
176 table_name = parts.pop
177 schema_name = parts.join(".")
179 @connection.columns_internal(table_name, name, schema_name)
182 # From postgresql_adapter.rb
183 def indexes(table_name, name = nil)
184 result = select_rows(<<-SQL, name)
185 SELECT i.relname, d.indisunique, a.attname
186 FROM pg_class t, pg_class i, pg_index d, pg_attribute a
187 WHERE i.relkind = 'i'
188 AND d.indexrelid = i.oid
189 AND d.indisprimary = 'f'
190 AND t.oid = d.indrelid
191 AND t.relname = '#{table_name}'
192 AND a.attrelid = t.oid
193 AND ( d.indkey[0]=a.attnum OR d.indkey[1]=a.attnum
194 OR d.indkey[2]=a.attnum OR d.indkey[3]=a.attnum
195 OR d.indkey[4]=a.attnum OR d.indkey[5]=a.attnum
196 OR d.indkey[6]=a.attnum OR d.indkey[7]=a.attnum
197 OR d.indkey[8]=a.attnum OR d.indkey[9]=a.attnum )
205 if current_index != row[0]
206 indexes << ::ActiveRecord::ConnectionAdapters::IndexDefinition.new(table_name, row[0], row[1] == "t", [])
207 current_index = row[0]
210 indexes.last.columns << row[2]
216 def last_insert_id(table, sequence_name)
217 Integer(select_value("SELECT currval('#{sequence_name}')"))
220 def recreate_database(name)
222 create_database(name)
225 def create_database(name, options = {})
226 execute "CREATE DATABASE \"#{name}\" ENCODING='#{options[:encoding] || 'utf8'}'"
229 def drop_database(name)
230 execute "DROP DATABASE \"#{name}\""
234 database = @config[:database]
236 if @config[:url] =~ /\/([^\/]*)$/
239 raise "Could not figure out what database this url is for #{@config["url"]}"
243 ENV['PGHOST'] = @config[:host] if @config[:host]
244 ENV['PGPORT'] = @config[:port].to_s if @config[:port]
245 ENV['PGPASSWORD'] = @config[:password].to_s if @config[:password]
246 search_path = @config[:schema_search_path]
247 search_path = "--schema=#{search_path}" if search_path
249 @connection.connection.close
251 file = "db/#{RAILS_ENV}_structure.sql"
252 `pg_dump -i -U "#{@config[:username]}" -s -x -O -f #{file} #{search_path} #{database}`
253 raise "Error dumping database" if $?.exitstatus == 1
255 # need to patch away any references to SQL_ASCII as it breaks the JDBC driver
256 lines = File.readlines(file)
257 File.open(file, "w") do |io|
259 line.gsub!(/SQL_ASCII/, 'UNICODE')
268 def _execute(sql, name = nil)
270 when /\A\(?\s*(select|show)/i:
271 @connection.execute_query(sql)
273 @connection.execute_update(sql)
277 # SELECT DISTINCT clause for a given set of columns and a given ORDER BY clause.
279 # PostgreSQL requires the ORDER BY columns in the select list for distinct queries, and
280 # requires that the ORDER BY include the distinct column.
282 # distinct("posts.id", "posts.created_at desc")
283 def distinct(columns, order_by)
284 return "DISTINCT #{columns}" if order_by.blank?
286 # construct a clean list of column names from the ORDER BY clause, removing
287 # any asc/desc modifiers
288 order_columns = order_by.split(',').collect { |s| s.split.first }
289 order_columns.delete_if(&:blank?)
290 order_columns = order_columns.zip((0...order_columns.size).to_a).map { |s,i| "#{s} AS alias_#{i}" }
292 # return a DISTINCT ON() clause that's distinct on the columns we want but includes
293 # all the required columns for the ORDER BY to work properly
294 sql = "DISTINCT ON (#{columns}) #{columns}, "
295 sql << order_columns * ', '
298 # ORDER BY clause for the passed order option.
300 # PostgreSQL does not allow arbitrary ordering when using DISTINCT ON, so we work around this
301 # by wrapping the sql as a sub-select and ordering in that query.
302 def add_order_by_for_association_limiting!(sql, options)
303 return sql if options[:order].blank?
305 order = options[:order].split(',').collect { |s| s.strip }.reject(&:blank?)
306 order.map! { |s| 'DESC' if s =~ /\bdesc$/i }
307 order = order.zip((0...order.size).to_a).map { |s,i| "id_list.alias_#{i} #{s}" }.join(', ')
309 sql.replace "SELECT * FROM (#{sql}) AS id_list ORDER BY #{order}"
312 def quote(value, column = nil)
313 return value.quoted_id if value.respond_to?(:quoted_id)
315 if value.kind_of?(String) && column && column.type == :binary
316 "'#{escape_bytea(value)}'"
317 elsif column && column.type == :primary_key
327 s.each_byte { |c| result << sprintf('\\\\%03o', c) }
332 def quote_column_name(name)
336 def quoted_date(value)
337 value.strftime("%Y-%m-%d %H:%M:%S")
340 def disable_referential_integrity(&block) #:nodoc:
341 execute(tables.collect { |name| "ALTER TABLE #{quote_table_name(name)} DISABLE TRIGGER ALL" }.join(";"))
344 execute(tables.collect { |name| "ALTER TABLE #{quote_table_name(name)} ENABLE TRIGGER ALL" }.join(";"))
347 def rename_table(name, new_name)
348 execute "ALTER TABLE #{name} RENAME TO #{new_name}"
351 def add_column(table_name, column_name, type, options = {})
352 execute("ALTER TABLE #{table_name} ADD #{column_name} #{type_to_sql(type, options[:limit])}")
353 change_column_default(table_name, column_name, options[:default]) unless options[:default].nil?
354 if options[:null] == false
355 execute("UPDATE #{table_name} SET #{column_name} = '#{options[:default]}'") if options[:default]
356 execute("ALTER TABLE #{table_name} ALTER #{column_name} SET NOT NULL")
360 def change_column(table_name, column_name, type, options = {}) #:nodoc:
362 execute "ALTER TABLE #{table_name} ALTER #{column_name} TYPE #{type_to_sql(type, options[:limit])}"
363 rescue ActiveRecord::StatementInvalid
364 # This is PG7, so we use a more arcane way of doing it.
366 add_column(table_name, "#{column_name}_ar_tmp", type, options)
367 execute "UPDATE #{table_name} SET #{column_name}_ar_tmp = CAST(#{column_name} AS #{type_to_sql(type, options[:limit])})"
368 remove_column(table_name, column_name)
369 rename_column(table_name, "#{column_name}_ar_tmp", column_name)
370 commit_db_transaction
372 change_column_default(table_name, column_name, options[:default]) unless options[:default].nil?
375 def change_column_default(table_name, column_name, default) #:nodoc:
376 execute "ALTER TABLE #{table_name} ALTER COLUMN #{column_name} SET DEFAULT '#{default}'"
379 def rename_column(table_name, column_name, new_column_name) #:nodoc:
380 execute "ALTER TABLE #{table_name} RENAME COLUMN #{column_name} TO #{new_column_name}"
383 def remove_index(table_name, options) #:nodoc:
384 execute "DROP INDEX #{index_name(table_name, options)}"
387 def type_to_sql(type, limit = nil, precision = nil, scale = nil) #:nodoc:
388 return super unless type.to_s == 'integer'
390 if limit.nil? || limit == 4
400 @connection.tables(database_name, nil, nil, ["TABLE"])