Module: Sequel::Postgres::DatabaseMethods
- Includes:
- UnmodifiedIdentifiers::DatabaseMethods
- Included in:
- JDBC::Postgres::DatabaseMethods, Database
- Defined in:
- lib/sequel/adapters/shared/postgres.rb
Constant Summary collapse
- PREPARED_ARG_PLACEHOLDER =
LiteralString.new('$').freeze
- FOREIGN_KEY_LIST_ON_DELETE_MAP =
{'a'=>:no_action, 'r'=>:restrict, 'c'=>:cascade, 'n'=>:set_null, 'd'=>:set_default}.freeze
- ON_COMMIT =
{:drop => 'DROP', :delete_rows => 'DELETE ROWS', :preserve_rows => 'PRESERVE ROWS'}.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(pg_get_expr(def.adbin, attr.attrelid), '''', 2) ~ '.' THEN substr(split_part(pg_get_expr(def.adbin, attr.attrelid), '''', 2), strpos(split_part(pg_get_expr(def.adbin, attr.attrelid), '''', 2), '.')+1) ELSE split_part(pg_get_expr(def.adbin, attr.attrelid), '''', 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 pg_get_expr(def.adbin, attr.attrelid) ~* '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
Instance Attribute Summary collapse
-
#conversion_procs ⇒ Object
readonly
A hash of conversion procs, keyed by type integer (oid) and having callable values for the conversion proc for that type.
Instance Method Summary collapse
-
#add_conversion_proc(oid, callable = nil, &block) ⇒ Object
Set a conversion proc for the given oid.
-
#add_named_conversion_proc(name, &block) ⇒ Object
Add a conversion proc for a named type, using the given block.
-
#check_constraints(table) ⇒ Object
A hash of metadata for CHECK constraints on the table.
- #commit_prepared_transaction(transaction_id, opts = OPTS) ⇒ Object
-
#convert_serial_to_identity(table, opts = OPTS) ⇒ Object
Convert the first primary key column in the
table
from being a serial column to being an identity column. -
#create_function(name, definition, opts = OPTS) ⇒ Object
Creates the function in the database.
-
#create_language(name, opts = OPTS) ⇒ Object
Create the procedural language in the database.
-
#create_schema(name, opts = OPTS) ⇒ Object
Create a schema in the database.
-
#create_table(name, options = OPTS, &block) ⇒ Object
Support partitions of tables using the :partition_of option.
-
#create_table?(name, options = OPTS, &block) ⇒ Boolean
Support partitions of tables using the :partition_of option.
-
#create_trigger(table, name, function, opts = OPTS) ⇒ Object
Create a trigger in the database.
- #database_type ⇒ Object
-
#do(code, opts = OPTS) ⇒ Object
Use PostgreSQL's DO syntax to execute an anonymous code block.
-
#drop_function(name, opts = OPTS) ⇒ Object
Drops the function from the database.
-
#drop_language(name, opts = OPTS) ⇒ Object
Drops a procedural language from the database.
-
#drop_schema(name, opts = OPTS) ⇒ Object
Drops a schema from the database.
-
#drop_trigger(table, name, opts = OPTS) ⇒ Object
Drops a trigger from the database.
-
#foreign_key_list(table, opts = OPTS) ⇒ Object
Return full foreign key information using the pg system tables, including :name, :on_delete, :on_update, and :deferrable entries in the hashes.
- #freeze ⇒ Object
-
#indexes(table, opts = OPTS) ⇒ Object
Use the pg_* system tables to determine indexes on a table.
-
#locks ⇒ Object
Dataset containing all current database locks.
-
#notify(channel, opts = OPTS) ⇒ Object
Notifies the given channel.
-
#primary_key(table, opts = OPTS) ⇒ Object
Return primary key for the given table.
-
#primary_key_sequence(table, opts = OPTS) ⇒ Object
Return the sequence providing the default for the primary key for the given table.
-
#refresh_view(name, opts = OPTS) ⇒ Object
Refresh the materialized view with the given name.
-
#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.
- #rollback_prepared_transaction(transaction_id, opts = OPTS) ⇒ Object
-
#serial_primary_key_options ⇒ Object
PostgreSQL uses SERIAL psuedo-type instead of AUTOINCREMENT for managing incrementing primary keys.
-
#server_version(server = nil) ⇒ Object
The version of the PostgreSQL server, used for determining capability.
-
#supports_create_table_if_not_exists? ⇒ Boolean
PostgreSQL supports CREATE TABLE IF NOT EXISTS on 9.1+.
-
#supports_deferrable_constraints? ⇒ Boolean
PostgreSQL 9.0+ supports some types of deferrable constraints beyond foreign key constraints.
-
#supports_deferrable_foreign_key_constraints? ⇒ Boolean
PostgreSQL supports deferrable foreign key constraints.
-
#supports_drop_table_if_exists? ⇒ Boolean
PostgreSQL supports DROP TABLE IF EXISTS.
-
#supports_partial_indexes? ⇒ Boolean
PostgreSQL supports partial indexes.
-
#supports_prepared_transactions? ⇒ Boolean
PostgreSQL supports prepared transactions (two-phase commit) if max_prepared_transactions is greater than 0.
-
#supports_savepoints? ⇒ Boolean
PostgreSQL supports savepoints.
-
#supports_transaction_isolation_levels? ⇒ Boolean
PostgreSQL supports transaction isolation levels.
-
#supports_transactional_ddl? ⇒ Boolean
PostgreSQL supports transaction DDL statements.
-
#supports_trigger_conditions? ⇒ Boolean
PostgreSQL 9.0+ supports trigger conditions.
-
#tables(opts = OPTS, &block) ⇒ Object
Array of symbols specifying table names in the current database.
-
#type_supported?(type) ⇒ Boolean
Check whether the given type name string/symbol (e.g. :hstore) is supported by the database.
-
#values(v) ⇒ Object
Creates a dataset that uses the VALUES clause:.
-
#views(opts = OPTS) ⇒ Object
Array of symbols specifying view names in the current database.
Instance Attribute Details
#conversion_procs ⇒ Object (readonly)
A hash of conversion procs, keyed by type integer (oid) and having callable values for the conversion proc for that type.
292 293 294 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 292 def conversion_procs @conversion_procs end |
Instance Method Details
#add_conversion_proc(oid, callable = nil, &block) ⇒ Object
Set a conversion proc for the given oid. The callable can be passed either as a argument or a block.
296 297 298 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 296 def add_conversion_proc(oid, callable=nil, &block) conversion_procs[oid] = callable || block end |
#add_named_conversion_proc(name, &block) ⇒ Object
Add a conversion proc for a named type, using the given block. This should be used for types without fixed OIDs, which includes all types that are not included in a default PostgreSQL installation.
303 304 305 306 307 308 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 303 def add_named_conversion_proc(name, &block) unless oid = from(:pg_type).where(:typtype=>['b', 'e'], :typname=>name.to_s).get(:oid) raise Error, "No matching type in pg_type for #{name.inspect}" end add_conversion_proc(oid, block) end |
#check_constraints(table) ⇒ Object
A hash of metadata for CHECK constraints on the table. Keys are CHECK constraint name symbols. Values are hashes with the following keys:
- :definition
-
An SQL fragment for the definition of the constraint
- :columns
-
An array of column symbols for the columns referenced in the constraint, can be an empty array if the database cannot deteremine the column symbols.
319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 319 def check_constraints(table) m = output_identifier_meth rows = . from{pg_constraint.as(:co)}. left_join(Sequel[:pg_attribute].as(:att), :attrelid=>:conrelid, :attnum=>SQL::Function.new(:ANY, Sequel[:co][:conkey])). where(:conrelid=>regclass_oid(table), :contype=>'c'). select{[co[:conname].as(:constraint), att[:attname].as(:column), pg_get_constraintdef(co[:oid]).as(:definition)]} hash = {} rows.each do |row| constraint = m.call(row[:constraint]) entry = hash[constraint] ||= {:definition=>row[:definition], :columns=>[]} entry[:columns] << m.call(row[:column]) if row[:column] end hash end |
#commit_prepared_transaction(transaction_id, opts = OPTS) ⇒ Object
310 311 312 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 310 def commit_prepared_transaction(transaction_id, opts=OPTS) run("COMMIT PREPARED #{literal(transaction_id)}", opts) end |
#convert_serial_to_identity(table, opts = OPTS) ⇒ Object
Convert the first primary key column in the table
from being a serial column to being an identity column. If the column is already an identity column, assume it was already converted and make no changes.
Only supported on PostgreSQL 10.2+, since on those versions Sequel will use identity columns instead of serial columns for auto incrementing primary keys. Only supported when running as a superuser, since regular users cannot modify system tables, and there is no way to keep an existing sequence when changing an existing column to be an identity column.
This method can raise an exception in at least the following cases where it may otherwise succeed (there may be additional cases not listed here):
-
The serial column was added after table creation using PostgreSQL <7.3
-
A regular index also exists on the column (such an index can probably be dropped as the primary key index should suffice)
Options:
- :column
-
Specify the column to convert instead of using the first primary key column
- :server
-
Run the SQL on the given server
356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 356 def convert_serial_to_identity(table, opts=OPTS) raise Error, "convert_serial_to_identity is only supported on PostgreSQL 10.2+" unless server_version >= 100002 server = opts[:server] server_hash = server ? {:server=>server} : OPTS ds = dataset ds = ds.server(server) if server raise Error, "convert_serial_to_identity requires superuser permissions" unless ds.get{current_setting('is_superuser')} == 'on' table_oid = regclass_oid(table) im = input_identifier_meth unless column = im.call(opts[:column] || ((sch = schema(table).find{|_, sc| sc[:primary_key] && sc[:auto_increment]}) && sch[0])) raise Error, "could not determine column to convert from serial to identity automatically" end column_num = ds.from(:pg_attribute). where(:attrelid=>table_oid, :attname=>column). get(:attnum) pg_class = Sequel.cast('pg_class', :regclass) res = ds.from(:pg_depend). where(:refclassid=>pg_class, :refobjid=>table_oid, :refobjsubid=>column_num, :classid=>pg_class, :objsubid=>0, :deptype=>%w'a i'). select_map([:objid, Sequel.as({:deptype=>'i'}, :v)]) case res.length when 0 raise Error, "unable to find related sequence when converting serial to identity" when 1 seq_oid, already_identity = res.first else raise Error, "more than one linked sequence found when converting serial to identity" end return if already_identity transaction(server_hash) do run("ALTER TABLE #{quote_schema_table(table)} ALTER COLUMN #{quote_identifier(column)} DROP DEFAULT", server_hash) ds.from(:pg_depend). where(:classid=>pg_class, :objid=>seq_oid, :objsubid=>0, :deptype=>'a'). update(:deptype=>'i') ds.from(:pg_attribute). where(:attrelid=>table_oid, :attname=>column). update(:attidentity=>'d') end remove_cached_schema(table) nil end |
#create_function(name, definition, opts = 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:
- 1
-
argument data type
- 2
-
argument name
- 3
-
argument mode (e.g. in, out, inout)
- :behavior
-
Should be IMMUTABLE, STABLE, or VOLATILE. PostgreSQL assumes VOLATILE by default.
- :parallel
-
The thread safety attribute of the function. Should be SAFE, UNSAFE, RESTRICTED. PostgreSQL assumes UNSAFE 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.
429 430 431 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 429 def create_function(name, definition, opts=OPTS) self << create_function_sql(name, definition, opts) end |
#create_language(name, opts = 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.
440 441 442 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 440 def create_language(name, opts=OPTS) self << create_language_sql(name, opts) end |
#create_schema(name, opts = OPTS) ⇒ Object
Create a schema in the database. Arguments:
- name
-
Name of the schema (e.g. admin)
- opts
-
options hash:
- :if_not_exists
-
Don't raise an error if the schema already exists (PostgreSQL 9.3+)
- :owner
-
The owner to set for the schema (defaults to current user if not specified)
449 450 451 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 449 def create_schema(name, opts=OPTS) self << create_schema_sql(name, opts) end |
#create_table(name, options = OPTS, &block) ⇒ Object
Support partitions of tables using the :partition_of option.
454 455 456 457 458 459 460 461 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 454 def create_table(name, =OPTS, &block) if [:partition_of] create_partition_of_table_from_generator(name, CreatePartitionOfTableGenerator.new(&block), ) return end super end |
#create_table?(name, options = OPTS, &block) ⇒ Boolean
Support partitions of tables using the :partition_of option.
464 465 466 467 468 469 470 471 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 464 def create_table?(name, =OPTS, &block) if [:partition_of] create_table(name, .merge!(:if_not_exists=>true), &block) return end super end |
#create_trigger(table, name, function, opts = 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.
- :replace
-
Replace the trigger with the same name if it already exists (PostgreSQL 14+).
- :when
-
A filter to use for the trigger
485 486 487 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 485 def create_trigger(table, name, function, opts=OPTS) self << create_trigger_sql(table, name, function, opts) end |
#database_type ⇒ Object
489 490 491 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 489 def database_type :postgres end |
#do(code, opts = 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.
498 499 500 501 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 498 def do(code, opts=OPTS) language = opts[:language] run "DO #{"LANGUAGE #{literal(language.to_s)} " if language}#{literal(code)}" end |
#drop_function(name, opts = 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.
509 510 511 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 509 def drop_function(name, opts=OPTS) self << drop_function_sql(name, opts) end |
#drop_language(name, opts = 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.
518 519 520 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 518 def drop_language(name, opts=OPTS) self << drop_language_sql(name, opts) end |
#drop_schema(name, opts = 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.
527 528 529 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 527 def drop_schema(name, opts=OPTS) self << drop_schema_sql(name, opts) end |
#drop_trigger(table, name, opts = 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.
537 538 539 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 537 def drop_trigger(table, name, opts=OPTS) self << drop_trigger_sql(table, name, opts) end |
#foreign_key_list(table, opts = OPTS) ⇒ Object
Return full foreign key information using the pg system tables, including :name, :on_delete, :on_update, and :deferrable entries in the hashes.
Supports additional options:
- :reverse
-
Instead of returning foreign keys in the current table, return foreign keys in other tables that reference the current table.
- :schema
-
Set to true to have the :table value in the hashes be a qualified identifier. Set to false to use a separate :schema value with the related schema. Defaults to whether the given table argument is a qualified identifier.
551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 551 def foreign_key_list(table, opts=OPTS) m = output_identifier_meth schema, _ = opts.fetch(:schema, schema_and_table(table)) oid = regclass_oid(table) reverse = opts[:reverse] if reverse ctable = Sequel[:att2] cclass = Sequel[:cl2] rtable = Sequel[:att] rclass = Sequel[:cl] else ctable = Sequel[:att] cclass = Sequel[:cl] rtable = Sequel[:att2] rclass = Sequel[:cl2] end if server_version >= 90500 cpos = Sequel.expr{array_position(co[:conkey], ctable[:attnum])} rpos = Sequel.expr{array_position(co[:confkey], rtable[:attnum])} else range = 0...32 cpos = Sequel.expr{SQL::CaseExpression.new(range.map{|x| [SQL::Subscript.new(co[:conkey], [x]), x]}, 32, ctable[:attnum])} rpos = Sequel.expr{SQL::CaseExpression.new(range.map{|x| [SQL::Subscript.new(co[:confkey], [x]), x]}, 32, rtable[:attnum])} end ds = . from{pg_constraint.as(:co)}. join(Sequel[:pg_class].as(cclass), :oid=>:conrelid). join(Sequel[:pg_attribute].as(ctable), :attrelid=>:oid, :attnum=>SQL::Function.new(:ANY, Sequel[:co][:conkey])). join(Sequel[:pg_class].as(rclass), :oid=>Sequel[:co][:confrelid]). join(Sequel[:pg_attribute].as(rtable), :attrelid=>:oid, :attnum=>SQL::Function.new(:ANY, Sequel[:co][:confkey])). join(Sequel[:pg_namespace].as(:nsp), :oid=>Sequel[:cl2][:relnamespace]). order{[co[:conname], cpos]}. where{{ cl[:relkind]=>'r', co[:contype]=>'f', cl[:oid]=>oid, cpos=>rpos }}. select{[ co[:conname].as(:name), ctable[:attname].as(:column), co[:confupdtype].as(:on_update), co[:confdeltype].as(:on_delete), cl2[:relname].as(:table), rtable[:attname].as(:refcolumn), SQL::BooleanExpression.new(:AND, co[:condeferrable], co[:condeferred]).as(:deferrable), nsp[:nspname].as(:schema) ]} if reverse ds = ds.order_append(Sequel[:nsp][:nspname], Sequel[:cl2][:relname]) end h = {} fklod_map = FOREIGN_KEY_LIST_ON_DELETE_MAP ds.each do |row| if reverse key = [row[:schema], row[:table], row[:name]] else key = row[:name] end if r = h[key] r[:columns] << m.call(row[:column]) r[:key] << m.call(row[:refcolumn]) else entry = h[key] = { :name=>m.call(row[:name]), :columns=>[m.call(row[:column])], :key=>[m.call(row[:refcolumn])], :on_update=>fklod_map[row[:on_update]], :on_delete=>fklod_map[row[:on_delete]], :deferrable=>row[:deferrable], :table=>schema ? SQL::QualifiedIdentifier.new(m.call(row[:schema]), m.call(row[:table])) : m.call(row[:table]), } unless schema # If not combining schema information into the :table entry # include it as a separate entry. entry[:schema] = m.call(row[:schema]) end end end h.values end |
#freeze ⇒ Object
642 643 644 645 646 647 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 642 def freeze server_version supports_prepared_transactions? @conversion_procs.freeze super end |
#indexes(table, opts = OPTS) ⇒ Object
Use the pg_* system tables to determine indexes on a table
650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 650 def indexes(table, opts=OPTS) m = output_identifier_meth oid = regclass_oid(table, opts) if server_version >= 90500 order = [Sequel[:indc][:relname], Sequel.function(:array_position, Sequel[:ind][:indkey], Sequel[:att][:attnum])] else range = 0...32 order = [Sequel[:indc][:relname], SQL::CaseExpression.new(range.map{|x| [SQL::Subscript.new(Sequel[:ind][:indkey], [x]), x]}, 32, Sequel[:att][:attnum])] end attnums = SQL::Function.new(:ANY, Sequel[:ind][:indkey]) ds = . from{pg_class.as(:tab)}. join(Sequel[:pg_index].as(:ind), :indrelid=>:oid). join(Sequel[:pg_class].as(:indc), :oid=>:indexrelid). join(Sequel[:pg_attribute].as(:att), :attrelid=>Sequel[:tab][:oid], :attnum=>attnums). left_join(Sequel[:pg_constraint].as(:con), :conname=>Sequel[:indc][:relname]). where{{ indc[:relkind]=>'i', ind[:indisprimary]=>false, :indexprs=>nil, :indisvalid=>true, tab[:oid]=>oid}}. order(*order). select{[indc[:relname].as(:name), ind[:indisunique].as(:unique), att[:attname].as(:column), con[:condeferrable].as(:deferrable)]} ds = ds.where(:indpred=>nil) unless opts[:include_partial] ds = ds.where(:indisready=>true) if server_version >= 80300 ds = ds.where(:indislive=>true) if server_version >= 90300 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 |
#locks ⇒ Object
Dataset containing all current database locks
691 692 693 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 691 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 = 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.
701 702 703 704 705 706 707 708 709 710 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 701 def notify(channel, opts=OPTS) sql = String.new sql << "NOTIFY " dataset.send(:identifier_append, sql, channel) if payload = opts[:payload] sql << ", " dataset.literal_append(sql, payload.to_s) end execute_ddl(sql, opts) end |
#primary_key(table, opts = OPTS) ⇒ Object
Return primary key for the given table.
713 714 715 716 717 718 719 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 713 def primary_key(table, opts=OPTS) quoted_table = quote_schema_table(table) Sequel.synchronize{return @primary_keys[quoted_table] if @primary_keys.has_key?(quoted_table)} sql = "#{SELECT_PK_SQL} AND pg_class.oid = #{literal(regclass_oid(table, opts))}" value = fetch(sql).single_value Sequel.synchronize{@primary_keys[quoted_table] = value} end |
#primary_key_sequence(table, opts = OPTS) ⇒ Object
Return the sequence providing the default for the primary key for the given table.
722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 722 def primary_key_sequence(table, opts=OPTS) quoted_table = quote_schema_table(table) Sequel.synchronize{return @primary_key_sequences[quoted_table] if @primary_key_sequences.has_key?(quoted_table)} sql = "#{SELECT_SERIAL_SEQUENCE_SQL} AND t.oid = #{literal(regclass_oid(table, opts))}" 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.oid = #{literal(regclass_oid(table, opts))}" 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 |
#refresh_view(name, opts = OPTS) ⇒ Object
Refresh the materialized view with the given name.
DB.refresh_view(:items_view)
# REFRESH MATERIALIZED VIEW items_view
DB.refresh_view(:items_view, :concurrently=>true)
# REFRESH MATERIALIZED VIEW CONCURRENTLY items_view
744 745 746 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 744 def refresh_view(name, opts=OPTS) run "REFRESH MATERIALIZED VIEW#{' CONCURRENTLY' if opts[:concurrently]} #{quote_schema_table(name)}" 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.
750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 750 def reset_primary_key_sequence(table) return unless seq = primary_key_sequence(table) pk = SQL::Identifier.new(primary_key(table)) db = self s, t = schema_and_table(table) table = Sequel.qualify(s, t) if s if server_version >= 100000 seq_ds = .from(:pg_sequence).where(:seqrelid=>regclass_oid(LiteralString.new(seq))) increment_by = :seqincrement min_value = :seqmin else seq_ds = .from(LiteralString.new(seq)) increment_by = :increment_by min_value = :min_value end 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, opts = OPTS) ⇒ Object
770 771 772 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 770 def rollback_prepared_transaction(transaction_id, opts=OPTS) run("ROLLBACK PREPARED #{literal(transaction_id)}", opts) end |
#serial_primary_key_options ⇒ Object
PostgreSQL uses SERIAL psuedo-type instead of AUTOINCREMENT for managing incrementing primary keys.
776 777 778 779 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 776 def auto_increment_key = server_version >= 100002 ? :identity : :serial {:primary_key => true, auto_increment_key => true, :type=>Integer} end |
#server_version(server = nil) ⇒ Object
The version of the PostgreSQL server, used for determining capability.
782 783 784 785 786 787 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 782 def server_version(server=nil) return @server_version if @server_version ds = dataset ds = ds.server(server) if server @server_version = swallow_database_error{ds.with_sql("SELECT CAST(current_setting('server_version_num') AS integer) AS v").single_value} || 0 end |
#supports_create_table_if_not_exists? ⇒ Boolean
PostgreSQL supports CREATE TABLE IF NOT EXISTS on 9.1+
790 791 792 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 790 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.
795 796 797 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 795 def supports_deferrable_constraints? server_version >= 90000 end |
#supports_deferrable_foreign_key_constraints? ⇒ Boolean
PostgreSQL supports deferrable foreign key constraints.
800 801 802 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 800 def supports_deferrable_foreign_key_constraints? true end |
#supports_drop_table_if_exists? ⇒ Boolean
PostgreSQL supports DROP TABLE IF EXISTS
805 806 807 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 805 def supports_drop_table_if_exists? true end |
#supports_partial_indexes? ⇒ Boolean
PostgreSQL supports partial indexes.
810 811 812 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 810 def supports_partial_indexes? true end |
#supports_prepared_transactions? ⇒ Boolean
PostgreSQL supports prepared transactions (two-phase commit) if max_prepared_transactions is greater than 0.
821 822 823 824 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 821 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
827 828 829 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 827 def supports_savepoints? true end |
#supports_transaction_isolation_levels? ⇒ Boolean
PostgreSQL supports transaction isolation levels
832 833 834 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 832 def supports_transaction_isolation_levels? true end |
#supports_transactional_ddl? ⇒ Boolean
PostgreSQL supports transaction DDL statements.
837 838 839 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 837 def supports_transactional_ddl? true end |
#supports_trigger_conditions? ⇒ Boolean
PostgreSQL 9.0+ supports trigger conditions.
815 816 817 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 815 def supports_trigger_conditions? server_version >= 90000 end |
#tables(opts = 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:
- :qualify
-
Return the tables as Sequel::SQL::QualifiedIdentifier instances, using the schema the table is located in as the qualifier.
- :schema
-
The schema to search
- :server
-
The server to use
850 851 852 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 850 def tables(opts=OPTS, &block) pg_class_relname(['r', 'p'], opts, &block) end |
#type_supported?(type) ⇒ Boolean
Check whether the given type name string/symbol (e.g. :hstore) is supported by the database.
856 857 858 859 860 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 856 def type_supported?(type) Sequel.synchronize{return @supported_types[type] if @supported_types.has_key?(type)} supported = from(:pg_type).where(:typtype=>'b', :typname=>type.to_s).count > 0 Sequel.synchronize{return @supported_types[type] = supported} end |
#values(v) ⇒ Object
Creates a dataset that uses the VALUES clause:
DB.values([[1, 2], [3, 4]])
# VALUES ((1, 2), (3, 4))
DB.values([[1, 2], [3, 4]]).order(:column2).limit(1, 1)
# VALUES ((1, 2), (3, 4)) ORDER BY column2 LIMIT 1 OFFSET 1
869 870 871 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 869 def values(v) @default_dataset.clone(:values=>v) end |
#views(opts = OPTS) ⇒ Object
Array of symbols specifying view names in the current database.
Options:
- :materialized
-
Return materialized views
- :qualify
-
Return the views as Sequel::SQL::QualifiedIdentifier instances, using the schema the view is located in as the qualifier.
- :schema
-
The schema to search
- :server
-
The server to use
881 882 883 884 |
# File 'lib/sequel/adapters/shared/postgres.rb', line 881 def views(opts=OPTS) relkind = opts[:materialized] ? 'm' : 'v' pg_class_relname(relkind, opts) end |