Module: Sequel::Postgres::DatabaseMethods

Overview

Methods shared by Database instances that connect to PostgreSQL.

Constant Summary collapse

EXCLUDE_SCHEMAS =
/pg_*|information_schema/i
PREPARED_ARG_PLACEHOLDER =
LiteralString.new('$').freeze
RE_CURRVAL_ERROR =
/currval of sequence "(.*)" is not yet defined in this session|relation "(.*)" does not exist/.freeze
SYSTEM_TABLE_REGEXP =
/^pg|sql/.freeze
FOREIGN_KEY_LIST_ON_DELETE_MAP =
{'a'.freeze=>:no_action, 'r'.freeze=>:restrict, 'c'.freeze=>:cascade, 'n'.freeze=>:set_null, 'd'.freeze=>:set_default}.freeze
POSTGRES_DEFAULT_RE =
/\A(?:B?('.*')::[^']+|\((-?\d+(?:\.\d+)?)\))\z/
UNLOGGED =
'UNLOGGED '.freeze
SELECT_CUSTOM_SEQUENCE_SQL =

SQL fragment for custom sequences (ones not created by serial primary key), Returning the schema and literal form of the sequence name, by parsing the column defaults table.

(<<-end_sql
  SELECT name.nspname AS "schema",
      CASE
      WHEN split_part(def.adsrc, '''', 2) ~ '.' THEN
        substr(split_part(def.adsrc, '''', 2),
               strpos(split_part(def.adsrc, '''', 2), '.')+1)
      ELSE split_part(def.adsrc, '''', 2)
    END AS "sequence"
  FROM pg_class t
  JOIN pg_namespace  name ON (t.relnamespace = name.oid)
  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 cons.contype = 'p'
    AND def.adsrc ~* 'nextval'
end_sql
).strip.gsub(/\s+/, ' ').freeze
SELECT_PK_SQL =

SQL fragment for determining primary key column for the given table. Only returns the first primary key if the table has a composite primary key.

(<<-end_sql
  SELECT pg_attribute.attname AS pk
  FROM pg_class, pg_attribute, pg_index, pg_namespace
  WHERE pg_class.oid = pg_attribute.attrelid
    AND pg_class.relnamespace  = pg_namespace.oid
    AND pg_class.oid = pg_index.indrelid
    AND pg_index.indkey[0] = pg_attribute.attnum
    AND pg_index.indisprimary = 't'
end_sql
).strip.gsub(/\s+/, ' ').freeze
SELECT_SERIAL_SEQUENCE_SQL =

SQL fragment for getting sequence associated with table’s primary key, assuming it was a serial primary key column.

(<<-end_sql
  SELECT  name.nspname AS "schema", seq.relname AS "sequence"
  FROM pg_class seq, pg_attribute attr, pg_depend dep,
    pg_namespace name, pg_constraint cons, pg_class t
  WHERE seq.oid = dep.objid
    AND seq.relnamespace  = name.oid
    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 attr.attrelid = t.oid
    AND cons.contype = 'p'
end_sql
).strip.gsub(/\s+/, ' ').freeze
RESET_PROCS_EXTENSIONS =

The Sequel extensions that require reseting of the conversion procs.

[:pg_array, :pg_hstore, :pg_inet, :pg_interval, :pg_json, :pg_range].freeze

Instance Attribute Summary collapse

Instance Method Summary collapse

Instance Attribute Details

#conversion_procsObject (readonly)

A hash of conversion procs, keyed by type integer (oid) and having callable values for the conversion proc for that type.



159
160
161
# File 'lib/sequel/adapters/shared/postgres.rb', line 159

def conversion_procs
  @conversion_procs
end

Instance Method Details

#commit_prepared_transaction(transaction_id) ⇒ Object

Commit an existing prepared transaction with the given transaction identifier string.



163
164
165
# File 'lib/sequel/adapters/shared/postgres.rb', line 163

def commit_prepared_transaction(transaction_id)
  run("COMMIT PREPARED #{literal(transaction_id)}")
end

#create_function(name, definition, opts = {}) ⇒ Object

Creates the function in the database. Arguments:

  • name : name of the function to create

  • definition : string definition of the function, or object file for a dynamically loaded C function.

  • opts : options hash:

    • :args : function arguments, can be either a symbol or string specifying a type or an array of 1-3 elements:

      • element 1 : argument data type

      • element 2 : argument name

      • element 3 : argument mode (e.g. in, out, inout)

    • :behavior : Should be IMMUTABLE, STABLE, or VOLATILE. PostgreSQL assumes VOLATILE by default.

    • :cost : The estimated cost of the function, used by the query planner.

    • :language : The language the function uses. SQL is the default.

    • :link_symbol : For a dynamically loaded see function, the function’s link symbol if different from the definition argument.

    • :returns : The data type returned by the function. If you are using OUT or INOUT argument modes, this is ignored. Otherwise, if this is not specified, void is used by default to specify the function is not supposed to return a value.

    • :rows : The estimated number of rows the function will return. Only use if the function returns SETOF something.

    • :security_definer : Makes the privileges of the function the same as the privileges of the user who defined the function instead of the privileges of the user who runs the function. There are security implications when doing this, see the PostgreSQL documentation.

    • :set : Configuration variables to set while the function is being run, can be a hash or an array of two pairs. search_path is often used here if :security_definer is used.

    • :strict : Makes the function return NULL when any argument is NULL.



187
188
189
# File 'lib/sequel/adapters/shared/postgres.rb', line 187

def create_function(name, definition, opts={})
  self << create_function_sql(name, definition, opts)
end

#create_language(name, opts = {}) ⇒ Object

Create the procedural language in the database. Arguments:

  • name : Name of the procedural language (e.g. plpgsql)

  • opts : options hash:

    • :handler : The name of a previously registered function used as a call handler for this language.

    • :replace: Replace the installed language if it already exists (on PostgreSQL 9.0+).

    • :trusted : Marks the language being created as trusted, allowing unprivileged users to create functions using this language.

    • :validator : The name of previously registered function used as a validator of functions defined in this language.



198
199
200
# File 'lib/sequel/adapters/shared/postgres.rb', line 198

def create_language(name, opts={})
  self << create_language_sql(name, opts)
end

#create_schema(name) ⇒ Object

Create a schema in the database. Arguments:

  • name : Name of the schema (e.g. admin)



204
205
206
# File 'lib/sequel/adapters/shared/postgres.rb', line 204

def create_schema(name)
  self << create_schema_sql(name)
end

#create_trigger(table, name, function, opts = {}) ⇒ Object

Create a trigger in the database. Arguments:

  • table : the table on which this trigger operates

  • name : the name of this trigger

  • function : the function to call for this trigger, which should return type trigger.

  • opts : options hash:

    • :after : Calls the trigger after execution instead of before.

    • :args : An argument or array of arguments to pass to the function.

    • :each_row : Calls the trigger for each row instead of for each statement.

    • :events : Can be :insert, :update, :delete, or an array of any of those. Calls the trigger whenever that type of statement is used. By default, the trigger is called for insert, update, or delete.



218
219
220
# File 'lib/sequel/adapters/shared/postgres.rb', line 218

def create_trigger(table, name, function, opts={})
  self << create_trigger_sql(table, name, function, opts)
end

#database_typeObject

PostgreSQL uses the :postgres database type.



223
224
225
# File 'lib/sequel/adapters/shared/postgres.rb', line 223

def database_type
  :postgres
end

#do(code, opts = {}) ⇒ Object

Use PostgreSQL’s DO syntax to execute an anonymous code block. The code should be the literal code string to use in the underlying procedural language. Options:

:language

The procedural language the code is written in. The PostgreSQL default is plpgsql. Can be specified as a string or a symbol.



232
233
234
235
# File 'lib/sequel/adapters/shared/postgres.rb', line 232

def do(code, opts={})
  language = opts[:language]
  run "DO #{"LANGUAGE #{literal(language.to_s)} " if language}#{literal(code)}"
end

#drop_function(name, opts = {}) ⇒ Object

Drops the function from the database. Arguments:

  • name : name of the function to drop

  • opts : options hash:

    • :args : The arguments for the function. See create_function_sql.

    • :cascade : Drop other objects depending on this function.

    • :if_exists : Don’t raise an error if the function doesn’t exist.



243
244
245
# File 'lib/sequel/adapters/shared/postgres.rb', line 243

def drop_function(name, opts={})
  self << drop_function_sql(name, opts)
end

#drop_language(name, opts = {}) ⇒ Object

Drops a procedural language from the database. Arguments:

  • name : name of the procedural language to drop

  • opts : options hash:

    • :cascade : Drop other objects depending on this function.

    • :if_exists : Don’t raise an error if the function doesn’t exist.



252
253
254
# File 'lib/sequel/adapters/shared/postgres.rb', line 252

def drop_language(name, opts={})
  self << drop_language_sql(name, opts)
end

#drop_schema(name, opts = {}) ⇒ Object

Drops a schema from the database. Arguments:

  • name : name of the schema to drop

  • opts : options hash:

    • :cascade : Drop all objects in this schema.

    • :if_exists : Don’t raise an error if the schema doesn’t exist.



261
262
263
# File 'lib/sequel/adapters/shared/postgres.rb', line 261

def drop_schema(name, opts={})
  self << drop_schema_sql(name, opts)
end

#drop_trigger(table, name, opts = {}) ⇒ Object

Drops a trigger from the database. Arguments:

  • table : table from which to drop the trigger

  • name : name of the trigger to drop

  • opts : options hash:

    • :cascade : Drop other objects depending on this function.

    • :if_exists : Don’t raise an error if the function doesn’t exist.



271
272
273
# File 'lib/sequel/adapters/shared/postgres.rb', line 271

def drop_trigger(table, name, opts={})
  self << drop_trigger_sql(table, name, opts)
end

#extension(*exts) ⇒ Object

If any of the extensions that require reseting the conversion procs is loaded, reset them. This is done here so that if you load multiple pg_* extensions in the same call, the conversion procs are only reset once instead of once for every extension.



279
280
281
282
283
284
# File 'lib/sequel/adapters/shared/postgres.rb', line 279

def extension(*exts)
  super
  unless (RESET_PROCS_EXTENSIONS & exts).empty?
    reset_conversion_procs
  end
end

#foreign_key_list(table, opts = {}) ⇒ Object

Return full foreign key information using the pg system tables, including :name, :on_delete, :on_update, and :deferrable entries in the hashes.



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
# File 'lib/sequel/adapters/shared/postgres.rb', line 288

def foreign_key_list(table, opts={})
  m = output_identifier_meth
  im = input_identifier_meth
  schema, table = schema_and_table(table)
  range = 0...32

  base_ds = .
    where(:cl__relkind=>'r', :co__contype=>'f', :cl__relname=>im.call(table)).
    from(:pg_constraint___co).
    join(:pg_class___cl, :oid=>:conrelid)

  # We split the parsing into two separate queries, which are merged manually later.
  # This is because PostgreSQL stores both the referencing and referenced columns in
  # arrays, and I don't know a simple way to not create a cross product, as PostgreSQL
  # doesn't appear to have a function that takes an array and element and gives you
  # the index of that element in the array.

  ds = base_ds.
    join(:pg_attribute___att, :attrelid=>:oid, :attnum=>SQL::Function.new(:ANY, :co__conkey)).
    order(:co__conname, SQL::CaseExpression.new(range.map{|x| [SQL::Subscript.new(:co__conkey, [x]), x]}, 32, :att__attnum)).
    select(:co__conname___name, :att__attname___column, :co__confupdtype___on_update, :co__confdeltype___on_delete,
           SQL::BooleanExpression.new(:AND, :co__condeferrable, :co__condeferred).as(:deferrable))

  ref_ds = base_ds.
    join(:pg_class___cl2, :oid=>:co__confrelid).
    join(:pg_attribute___att2, :attrelid=>:oid, :attnum=>SQL::Function.new(:ANY, :co__confkey)).
    order(:co__conname, SQL::CaseExpression.new(range.map{|x| [SQL::Subscript.new(:co__conkey, [x]), x]}, 32, :att2__attnum)).
    select(:co__conname___name, :cl2__relname___table, :att2__attname___refcolumn)

  # If a schema is given, we only search in that schema, and the returned :table
  # entry is schema qualified as well.
  if schema
    ds = ds.join(:pg_namespace___nsp, :oid=>:cl__relnamespace).
      where(:nsp__nspname=>im.call(schema))
    ref_ds = ref_ds.join(:pg_namespace___nsp2, :oid=>:cl2__relnamespace).
      select_more(:nsp2__nspname___schema)
  end

  h = {}
  fklod_map = FOREIGN_KEY_LIST_ON_DELETE_MAP 
  ds.each do |row|
    if r = h[row[:name]]
      r[:columns] << m.call(row[:column])
    else
      h[row[:name]] = {:name=>m.call(row[:name]), :columns=>[m.call(row[:column])], :on_update=>fklod_map[row[:on_update]], :on_delete=>fklod_map[row[:on_delete]], :deferrable=>row[:deferrable]}
    end
  end
  ref_ds.each do |row|
    r = h[row[:name]]
    r[:table] ||= schema ? SQL::QualifiedIdentifier.new(m.call(row[:schema]), m.call(row[:table])) : m.call(row[:table])
    r[:key] ||= []
    r[:key] << m.call(row[:refcolumn])
  end
  h.values
end

#indexes(table, opts = {}) ⇒ Object

Use the pg_* system tables to determine indexes on a table



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
# File 'lib/sequel/adapters/shared/postgres.rb', line 345

def indexes(table, opts={})
  m = output_identifier_meth
  im = input_identifier_meth
  schema, table = schema_and_table(table)
  range = 0...32
  attnums = server_version >= 80100 ? SQL::Function.new(:ANY, :ind__indkey) : range.map{|x| SQL::Subscript.new(:ind__indkey, [x])}
  ds = .
    from(:pg_class___tab).
    join(:pg_index___ind, :indrelid=>:oid, im.call(table)=>:relname).
    join(:pg_class___indc, :oid=>:indexrelid).
    join(:pg_attribute___att, :attrelid=>:tab__oid, :attnum=>attnums).
    left_join(:pg_constraint___con, :conname=>:indc__relname).
    filter(:indc__relkind=>'i', :ind__indisprimary=>false, :indexprs=>nil, :indpred=>nil, :indisvalid=>true).
    order(:indc__relname, SQL::CaseExpression.new(range.map{|x| [SQL::Subscript.new(:ind__indkey, [x]), x]}, 32, :att__attnum)).
    select(:indc__relname___name, :ind__indisunique___unique, :att__attname___column, :con__condeferrable___deferrable)

  ds.join!(:pg_namespace___nsp, :oid=>:tab__relnamespace, :nspname=>schema.to_s) if schema
  ds.filter!(:indisready=>true, :indcheckxmin=>false) if server_version >= 80300

  indexes = {}
  ds.each do |r|
    i = indexes[m.call(r[:name])] ||= {:columns=>[], :unique=>r[:unique], :deferrable=>r[:deferrable]}
    i[:columns] << m.call(r[:column])
  end
  indexes
end

#locksObject

Dataset containing all current database locks



373
374
375
# File 'lib/sequel/adapters/shared/postgres.rb', line 373

def locks
  dataset.from(:pg_class).join(:pg_locks, :relation=>:relfilenode).select(:pg_class__relname, Sequel::SQL::ColumnAll.new(:pg_locks))
end

#notify(channel, opts = {}) ⇒ Object

Notifies the given channel. See the PostgreSQL NOTIFY documentation. Options:

:payload

The payload string to use for the NOTIFY statement. Only supported in PostgreSQL 9.0+.

:server

The server to which to send the NOTIFY statement, if the sharding support is being used.



383
384
385
# File 'lib/sequel/adapters/shared/postgres.rb', line 383

def notify(channel, opts={})
  execute_ddl("NOTIFY #{dataset.send(:table_ref, channel)}#{", #{literal(opts[:payload].to_s)}" if opts[:payload]}", opts)
end

#primary_key(table, opts = {}) ⇒ Object

Return primary key for the given table.



388
389
390
391
392
393
394
395
396
# File 'lib/sequel/adapters/shared/postgres.rb', line 388

def primary_key(table, opts={})
  quoted_table = quote_schema_table(table)
  Sequel.synchronize{return @primary_keys[quoted_table] if @primary_keys.has_key?(quoted_table)}
  schema, table = schema_and_table(table)
  sql = "#{SELECT_PK_SQL} AND pg_class.relname = #{literal(table)}"
  sql << " AND pg_namespace.nspname = #{literal(schema)}" if schema
  value = fetch(sql).single_value
  Sequel.synchronize{@primary_keys[quoted_table] = value}
end

#primary_key_sequence(table, opts = {}) ⇒ Object

Return the sequence providing the default for the primary key for the given table.



399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
# File 'lib/sequel/adapters/shared/postgres.rb', line 399

def primary_key_sequence(table, opts={})
  quoted_table = quote_schema_table(table)
  Sequel.synchronize{return @primary_key_sequences[quoted_table] if @primary_key_sequences.has_key?(quoted_table)}
  schema, table = schema_and_table(table)
  table = literal(table)
  sql = "#{SELECT_SERIAL_SEQUENCE_SQL} AND t.relname = #{table}"
  sql << " AND name.nspname = #{literal(schema)}" if schema
  if pks = fetch(sql).single_record
    value = literal(SQL::QualifiedIdentifier.new(pks[:schema], pks[:sequence]))
    Sequel.synchronize{@primary_key_sequences[quoted_table] = value}
  else
    sql = "#{SELECT_CUSTOM_SEQUENCE_SQL} AND t.relname = #{table}"
    sql << " AND name.nspname = #{literal(schema)}" if schema
    if pks = fetch(sql).single_record
      value = literal(SQL::QualifiedIdentifier.new(pks[:schema], LiteralString.new(pks[:sequence])))
      Sequel.synchronize{@primary_key_sequences[quoted_table] = value}
    end
  end
end

#reset_conversion_procsObject

Reset the database’s conversion procs, requires a server query if there any named types.



421
422
423
# File 'lib/sequel/adapters/shared/postgres.rb', line 421

def reset_conversion_procs
  @conversion_procs = get_conversion_procs
end

#reset_primary_key_sequence(table) ⇒ Object

Reset the primary key sequence for the given table, basing it on the maximum current value of the table’s primary key.



427
428
429
430
431
432
433
434
435
# File 'lib/sequel/adapters/shared/postgres.rb', line 427

def reset_primary_key_sequence(table)
  return unless seq = primary_key_sequence(table)
  pk = SQL::Identifier.new(primary_key(table))
  db = self
  seq_ds = db.from(LiteralString.new(seq))
  s, t = schema_and_table(table)
  table = Sequel.qualify(s, t) if s
  get{setval(seq, db[table].select{coalesce(max(pk)+seq_ds.select{:increment_by}, seq_ds.select(:min_value))}, false)}
end

#rollback_prepared_transaction(transaction_id) ⇒ Object

Rollback an existing prepared transaction with the given transaction identifier string.



439
440
441
# File 'lib/sequel/adapters/shared/postgres.rb', line 439

def rollback_prepared_transaction(transaction_id)
  run("ROLLBACK PREPARED #{literal(transaction_id)}")
end

#serial_primary_key_optionsObject

PostgreSQL uses SERIAL psuedo-type instead of AUTOINCREMENT for managing incrementing primary keys.



445
446
447
# File 'lib/sequel/adapters/shared/postgres.rb', line 445

def serial_primary_key_options
  {:primary_key => true, :serial => true, :type=>Integer}
end

#server_version(server = nil) ⇒ Object

The version of the PostgreSQL server, used for determining capability.



450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
# File 'lib/sequel/adapters/shared/postgres.rb', line 450

def server_version(server=nil)
  return @server_version if @server_version
  @server_version = synchronize(server) do |conn|
    (conn.server_version rescue nil) if conn.respond_to?(:server_version)
  end
  unless @server_version
    @server_version = if m = /PostgreSQL (\d+)\.(\d+)(?:(?:rc\d+)|\.(\d+))?/.match(fetch('SELECT version()').single_value)
      (m[1].to_i * 10000) + (m[2].to_i * 100) + m[3].to_i
    else
      0
    end
  end
  warn 'Sequel no longer supports PostgreSQL <8.2, some things may not work' if @server_version < 80200
  @server_version
end

#supports_create_table_if_not_exists?Boolean

PostgreSQL supports CREATE TABLE IF NOT EXISTS on 9.1+

Returns:

  • (Boolean)


467
468
469
# File 'lib/sequel/adapters/shared/postgres.rb', line 467

def supports_create_table_if_not_exists?
  server_version >= 90100
end

#supports_deferrable_constraints?Boolean

PostgreSQL 9.0+ supports some types of deferrable constraints beyond foreign key constraints.

Returns:

  • (Boolean)


472
473
474
# File 'lib/sequel/adapters/shared/postgres.rb', line 472

def supports_deferrable_constraints?
  server_version >= 90000
end

#supports_deferrable_foreign_key_constraints?Boolean

PostgreSQL supports deferrable foreign key constraints.

Returns:

  • (Boolean)


477
478
479
# File 'lib/sequel/adapters/shared/postgres.rb', line 477

def supports_deferrable_foreign_key_constraints?
  true
end

#supports_drop_table_if_exists?Boolean

PostgreSQL supports DROP TABLE IF EXISTS

Returns:

  • (Boolean)


482
483
484
# File 'lib/sequel/adapters/shared/postgres.rb', line 482

def supports_drop_table_if_exists?
  true
end

#supports_prepared_transactions?Boolean

PostgreSQL supports prepared transactions (two-phase commit) if max_prepared_transactions is greater than 0.

Returns:

  • (Boolean)


488
489
490
491
# File 'lib/sequel/adapters/shared/postgres.rb', line 488

def supports_prepared_transactions?
  return @supports_prepared_transactions if defined?(@supports_prepared_transactions)
  @supports_prepared_transactions = self['SHOW max_prepared_transactions'].get.to_i > 0
end

#supports_savepoints?Boolean

PostgreSQL supports savepoints

Returns:

  • (Boolean)


494
495
496
# File 'lib/sequel/adapters/shared/postgres.rb', line 494

def supports_savepoints?
  true
end

#supports_transaction_isolation_levels?Boolean

PostgreSQL supports transaction isolation levels

Returns:

  • (Boolean)


499
500
501
# File 'lib/sequel/adapters/shared/postgres.rb', line 499

def supports_transaction_isolation_levels?
  true
end

#supports_transactional_ddl?Boolean

PostgreSQL supports transaction DDL statements.

Returns:

  • (Boolean)


504
505
506
# File 'lib/sequel/adapters/shared/postgres.rb', line 504

def supports_transactional_ddl?
  true
end

#tables(opts = {}, &block) ⇒ Object

Array of symbols specifying table names in the current database. The dataset used is yielded to the block if one is provided, otherwise, an array of symbols of table names is returned.

Options:

  • :schema - The schema to search (default_schema by default)

  • :server - The server to use



515
516
517
# File 'lib/sequel/adapters/shared/postgres.rb', line 515

def tables(opts={}, &block)
  pg_class_relname('r', opts, &block)
end

#type_supported?(type) ⇒ Boolean

Check whether the given type name string/symbol (e.g. :hstore) is supported by the database.

Returns:

  • (Boolean)


521
522
523
524
# File 'lib/sequel/adapters/shared/postgres.rb', line 521

def type_supported?(type)
  @supported_types ||= {}
  @supported_types.fetch(type){@supported_types[type] = (from(:pg_type).filter(:typtype=>'b', :typname=>type.to_s).count > 0)}
end

#views(opts = {}) ⇒ Object

Array of symbols specifying view names in the current database.

Options:

  • :schema - The schema to search (default_schema by default)

  • :server - The server to use



531
532
533
# File 'lib/sequel/adapters/shared/postgres.rb', line 531

def views(opts={})
  pg_class_relname('v', opts)
end