Module: Sequel::Postgres::DatabaseMethods

Included in:
DataObjects::Postgres::DatabaseMethods, JDBC::Postgres::DatabaseMethods, Database
Defined in:
lib/sequel/adapters/shared/postgres.rb

Overview

Methods shared by Database instances that connect to PostgreSQL.

Constant Summary collapse

EXCLUDE_SCHEMAS =
%w[pg_catalog pg_toast pg_temp_1 pg_toast_temp_1 information_schema]
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

Instance Method Summary collapse

Instance Method Details

#commit_prepared_transaction(transaction_id) ⇒ Object

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



167
168
169
# File 'lib/sequel/adapters/shared/postgres.rb', line 167

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.



191
192
193
# File 'lib/sequel/adapters/shared/postgres.rb', line 191

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.

    • :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.



201
202
203
# File 'lib/sequel/adapters/shared/postgres.rb', line 201

def create_language(name, opts={})
  self << create_language_sql(name, opts)
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.



215
216
217
# File 'lib/sequel/adapters/shared/postgres.rb', line 215

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

#database_typeObject

PostgreSQL uses the :postgres database type.



220
221
222
# File 'lib/sequel/adapters/shared/postgres.rb', line 220

def database_type
  :postgres
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.



230
231
232
# File 'lib/sequel/adapters/shared/postgres.rb', line 230

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.



239
240
241
# File 'lib/sequel/adapters/shared/postgres.rb', line 239

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

#drop_table(*names) ⇒ Object

Remove the cached entries for primary keys and sequences when dropping a table.



244
245
246
247
248
249
250
251
# File 'lib/sequel/adapters/shared/postgres.rb', line 244

def drop_table(*names)
  names.each do |name|
    name = quote_schema_table(name)
    @primary_keys.delete(name)
    @primary_key_sequences.delete(name)
  end
  super
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.



259
260
261
# File 'lib/sequel/adapters/shared/postgres.rb', line 259

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

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

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



264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
# File 'lib/sequel/adapters/shared/postgres.rb', line 264

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).
    filter(:indc__relkind=>'i', :ind__indisprimary=>false, :indexprs=>nil, :indpred=>nil).
    order(:indc__relname, range.map{|x| [SQL::Subscript.new(:ind__indkey, [x]), x]}.case(32, :att__attnum)).
    select(:indc__relname___name, :ind__indisunique___unique, :att__attname___column)
  
  ds.join!(:pg_namespace___nsp, :oid=>:tab__relnamespace, :nspname=>schema.to_s) if schema
  ds.filter!(:indisvalid=>true) if server_version >= 80200
  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]}
    i[:columns] << m.call(r[:column])
  end
  indexes
end

#locksObject

Dataset containing all current database locks



292
293
294
# File 'lib/sequel/adapters/shared/postgres.rb', line 292

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

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

Return primary key for the given table.



297
298
299
300
301
302
303
304
305
# File 'lib/sequel/adapters/shared/postgres.rb', line 297

def primary_key(table, opts={})
  quoted_table = quote_schema_table(table)
  return @primary_keys[quoted_table] if @primary_keys.include?(quoted_table)
  @primary_keys[quoted_table] = if conn = opts[:conn]
    conn.primary_key(*schema_and_table(table))
  else
    synchronize(opts[:server]){|con| con.primary_key(*schema_and_table(table))}
  end
end

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

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



308
309
310
311
312
313
314
315
316
# File 'lib/sequel/adapters/shared/postgres.rb', line 308

def primary_key_sequence(table, opts={})
  quoted_table = quote_schema_table(table)
  return @primary_key_sequences[quoted_table] if @primary_key_sequences.include?(quoted_table)
  @primary_key_sequences[quoted_table] = if conn = opts[:conn]
    conn.sequence(*schema_and_table(table))
  else
    synchronize(opts[:server]){|con| con.sequence(*schema_and_table(table))}
  end
end

#reset_primary_key_sequence(table) ⇒ Object

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



320
321
322
323
324
325
326
# File 'lib/sequel/adapters/shared/postgres.rb', line 320

def reset_primary_key_sequence(table)
  pk = SQL::Identifier.new(primary_key(table))
  return unless seq = primary_key_sequence(table)
  db = self
  seq_ds = db.from(seq.lit)
  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.



330
331
332
# File 'lib/sequel/adapters/shared/postgres.rb', line 330

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.



336
337
338
# File 'lib/sequel/adapters/shared/postgres.rb', line 336

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.



341
342
343
344
345
346
347
348
349
350
351
# File 'lib/sequel/adapters/shared/postgres.rb', line 341

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
    m = /PostgreSQL (\d+)\.(\d+)(?:(?:rc\d+)|\.(\d+))?/.match(fetch('SELECT version()').single_value)
    @server_version = (m[1].to_i * 10000) + (m[2].to_i * 100) + m[3].to_i
  end
  @server_version
end

#supports_prepared_transactions?Boolean

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

Returns:

  • (Boolean)


355
356
357
358
# File 'lib/sequel/adapters/shared/postgres.rb', line 355

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)


361
362
363
# File 'lib/sequel/adapters/shared/postgres.rb', line 361

def supports_savepoints?
  true
end

#supports_transaction_isolation_levels?Boolean

PostgreSQL supports transaction isolation levels

Returns:

  • (Boolean)


366
367
368
# File 'lib/sequel/adapters/shared/postgres.rb', line 366

def supports_transaction_isolation_levels?
  true
end

#table_exists?(table, opts = {}) ⇒ Boolean

Whether the given table exists in the database

Options:

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

  • :server - The server to use

Returns:

  • (Boolean)


375
376
377
378
379
380
# File 'lib/sequel/adapters/shared/postgres.rb', line 375

def table_exists?(table, opts={})
  im = input_identifier_meth
  schema, table = schema_and_table(table)
  opts[:schema] ||= schema
  tables(opts){|ds| !ds.first(:relname=>im.call(table)).nil?}
end

#tables(opts = {}) ⇒ 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



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

def tables(opts={})
  ds = .from(:pg_class).filter(:relkind=>'r').select(:relname).exclude(SQL::StringExpression.like(:relname, SYSTEM_TABLE_REGEXP)).server(opts[:server]).join(:pg_namespace, :oid=>:relnamespace) 
  ds = filter_schema(ds, opts)
  m = output_identifier_meth
  block_given? ? yield(ds) : ds.map{|r| m.call(r[:relname])}
end