Module: Sequel::Postgres::DatabaseMethods
- Included in:
- Database
- Defined in:
- lib/sequel_core/adapters/shared/postgres.rb
Overview
Methods shared by Database instances that connect to PostgreSQL.
Constant Summary collapse
- PREPARED_ARG_PLACEHOLDER =
'$'.lit.freeze
- RE_CURRVAL_ERROR =
/currval of sequence "(.*)" is not yet defined in this session|relation "(.*)" does not exist/.freeze
- SQL_BEGIN =
'BEGIN'.freeze
- SQL_SAVEPOINT =
'SAVEPOINT autopoint_%d'.freeze
- SQL_COMMIT =
'COMMIT'.freeze
- SQL_ROLLBACK_TO_SAVEPOINT =
'ROLLBACK TO SAVEPOINT autopoint_%d'.freeze
- SQL_ROLLBACK =
'ROLLBACK'.freeze
- SQL_RELEASE_SAVEPOINT =
'RELEASE SAVEPOINT autopoint_%d'.freeze
- SYSTEM_TABLE_REGEXP =
/^pg|sql/.freeze
Instance Method Summary collapse
-
#create_function(*args) ⇒ Object
Creates the function in the database.
-
#create_function_sql(name, definition, opts = {}) ⇒ Object
SQL statement to create database function.
-
#create_language(*args) ⇒ Object
Create the procedural language in the database.
-
#create_language_sql(name, opts = {}) ⇒ Object
SQL for creating a procedural language.
-
#create_trigger(*args) ⇒ Object
Create a trigger in the database.
-
#create_trigger_sql(table, name, function, opts = {}) ⇒ Object
SQL for creating a database trigger.
-
#default_schema ⇒ Object
The default schema to use if none is specified (default: public).
-
#drop_function(*args) ⇒ Object
Drops the function from the database.
-
#drop_function_sql(name, opts = {}) ⇒ Object
SQL for dropping a function from the database.
-
#drop_language(*args) ⇒ Object
Drops a procedural language from the database.
-
#drop_language_sql(name, opts = {}) ⇒ Object
SQL for dropping a procedural language from the database.
-
#drop_table(*names) ⇒ Object
Remove the cached entries for primary keys and sequences when dropping a table.
-
#drop_table_sql(name) ⇒ Object
Always CASCADE the table drop.
-
#drop_trigger(*args) ⇒ Object
Drops a trigger from the database.
-
#drop_trigger_sql(table, name, opts = {}) ⇒ Object
SQL for dropping a trigger from the database.
-
#index_definition_sql(table_name, index) ⇒ Object
PostgreSQL specific index SQL.
-
#locks ⇒ Object
Dataset containing all current database locks.
-
#primary_key(table, server = nil) ⇒ Object
Return primary key for the given table.
-
#rename_table_sql(name, new_name) ⇒ Object
SQL DDL statement for renaming a table.
-
#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.
-
#table_exists?(table, opts = {}) ⇒ Boolean
Whether the given table exists in the database.
-
#tables(opts = {}) ⇒ Object
Array of symbols specifying table names in the current database.
-
#transaction(server = nil) ⇒ Object
PostgreSQL supports multi-level transactions using save points.
Instance Method Details
#create_function(*args) ⇒ Object
Creates the function in the database. See create_function_sql for arguments.
160 161 162 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 160 def create_function(*args) self << create_function_sql(*args) end |
#create_function_sql(name, definition, opts = {}) ⇒ Object
SQL statement to create database function. 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.
-
184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 184 def create_function_sql(name, definition, opts={}) args = opts[:args] if !opts[:args].is_a?(Array) || !opts[:args].any?{|a| Array(a).length == 3 and %w'OUT INOUT'.include?(a[2].to_s)} returns = opts[:returns] || 'void' end language = opts[:language] || 'SQL' " CREATE\#{' OR REPLACE' if opts[:replace]} FUNCTION \#{name}\#{sql_function_args(args)}\n \#{\"RETURNS \#{returns}\" if returns}\n LANGUAGE \#{language}\n \#{opts[:behavior].to_s.upcase if opts[:behavior]}\n \#{'STRICT' if opts[:strict]}\n \#{'SECURITY DEFINER' if opts[:security_definer]}\n \#{\"COST \#{opts[:cost]}\" if opts[:cost]}\n \#{\"ROWS \#{opts[:rows]}\" if opts[:rows]}\n \#{opts[:set].map{|k,v| \" SET \#{k} = \#{v}\"}.join(\"\\n\") if opts[:set]}\n AS \#{literal(definition.to_s)}\#{\", \#{literal(opts[:link_symbol].to_s)}\" if opts[:link_symbol]}\n END\nend\n" |
#create_language(*args) ⇒ Object
Create the procedural language in the database. See create_language_sql for arguments.
205 206 207 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 205 def create_language(*args) self << create_language_sql(*args) end |
#create_language_sql(name, opts = {}) ⇒ Object
SQL for creating a procedural language. 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.
-
215 216 217 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 215 def create_language_sql(name, opts={}) "CREATE#{' TRUSTED' if opts[:trusted]} LANGUAGE #{name}#{" HANDLER #{opts[:handler]}" if opts[:handler]}#{" VALIDATOR #{opts[:validator]}" if opts[:validator]}" end |
#create_trigger(*args) ⇒ Object
Create a trigger in the database. See create_trigger_sql for arguments.
220 221 222 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 220 def create_trigger(*args) self << create_trigger_sql(*args) end |
#create_trigger_sql(table, name, function, opts = {}) ⇒ Object
SQL for creating a database trigger. 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.
-
234 235 236 237 238 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 234 def create_trigger_sql(table, name, function, opts={}) events = opts[:events] ? Array(opts[:events]) : [:insert, :update, :delete] whence = opts[:after] ? 'AFTER' : 'BEFORE' "CREATE TRIGGER #{name} #{whence} #{events.map{|e| e.to_s.upcase}.join(' OR ')} ON #{quote_schema_table(table)}#{' FOR EACH ROW' if opts[:each_row]} EXECUTE PROCEDURE #{function}(#{Array(opts[:args]).map{|a| literal(a)}.join(', ')})" end |
#default_schema ⇒ Object
The default schema to use if none is specified (default: public)
241 242 243 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 241 def default_schema @default_schema ||= :public end |
#drop_function(*args) ⇒ Object
Drops the function from the database. See drop_function_sql for arguments.
246 247 248 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 246 def drop_function(*args) self << drop_function_sql(*args) end |
#drop_function_sql(name, opts = {}) ⇒ Object
SQL for dropping a 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.
-
256 257 258 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 256 def drop_function_sql(name, opts={}) "DROP FUNCTION#{' IF EXISTS' if opts[:if_exists]} #{name}#{sql_function_args(opts[:args])}#{' CASCADE' if opts[:cascade]}" end |
#drop_language(*args) ⇒ Object
Drops a procedural language from the database. See drop_language_sql for arguments.
261 262 263 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 261 def drop_language(*args) self << drop_language_sql(*args) end |
#drop_language_sql(name, opts = {}) ⇒ Object
SQL for dropping 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.
-
270 271 272 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 270 def drop_language_sql(name, opts={}) "DROP LANGUAGE#{' IF EXISTS' if opts[:if_exists]} #{name}#{' CASCADE' if opts[:cascade]}" end |
#drop_table(*names) ⇒ Object
Remove the cached entries for primary keys and sequences when dropping a table.
275 276 277 278 279 280 281 282 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 275 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_table_sql(name) ⇒ Object
Always CASCADE the table drop
285 286 287 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 285 def drop_table_sql(name) "DROP TABLE #{quote_schema_table(name)} CASCADE" end |
#drop_trigger(*args) ⇒ Object
Drops a trigger from the database. See drop_trigger_sql for arguments.
290 291 292 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 290 def drop_trigger(*args) self << drop_trigger_sql(*args) end |
#drop_trigger_sql(table, name, opts = {}) ⇒ Object
SQL for dropping 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.
-
300 301 302 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 300 def drop_trigger_sql(table, name, opts={}) "DROP TRIGGER#{' IF EXISTS' if opts[:if_exists]} #{name} ON #{quote_schema_table(table)}#{' CASCADE' if opts[:cascade]}" end |
#index_definition_sql(table_name, index) ⇒ Object
PostgreSQL specific index SQL.
305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 305 def index_definition_sql(table_name, index) index_name = index[:name] || default_index_name(table_name, index[:columns]) expr = literal(Array(index[:columns])) unique = "UNIQUE " if index[:unique] index_type = index[:type] filter = index[:where] || index[:filter] filter = " WHERE #{filter_expr(filter)}" if filter case index_type when :full_text cols = Array(index[:columns]).map{|x| :COALESCE[x, '']}.sql_string_join(' ') expr = "(to_tsvector(#{literal(index[:language] || 'simple')}, #{literal(cols)}))" index_type = :gin when :spatial index_type = :gist end "CREATE #{unique}INDEX #{index_name} ON #{table_name} #{"USING #{index_type} " if index_type}#{expr}#{filter}" end |
#locks ⇒ Object
Dataset containing all current database locks
324 325 326 327 328 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 324 def locks dataset.from(:pg_class, :pg_locks). select(:pg_class__relname, :pg_locks.*). filter(:pg_class__relfilenode=>:pg_locks__relation) end |
#primary_key(table, server = nil) ⇒ Object
Return primary key for the given table.
331 332 333 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 331 def primary_key(table, server=nil) synchronize(server){|conn| primary_key_for_table(conn, table)} end |
#rename_table_sql(name, new_name) ⇒ Object
SQL DDL statement for renaming a table. PostgreSQL doesn’t allow you to change a table’s schema in a rename table operation, so speciying a new schema in new_name will not have an effect.
337 338 339 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 337 def rename_table_sql(name, new_name) "ALTER TABLE #{quote_schema_table(name)} RENAME TO #{quote_identifier(schema_and_table(new_name).last)}" end |
#serial_primary_key_options ⇒ Object
PostgreSQL uses SERIAL psuedo-type instead of AUTOINCREMENT for managing incrementing primary keys.
343 344 345 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 343 def {:primary_key => true, :type => :serial} end |
#server_version(server = nil) ⇒ Object
The version of the PostgreSQL server, used for determining capability.
348 349 350 351 352 353 354 355 356 357 358 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 348 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+)\.(\d+)/.match(get(:version[])) @server_version = (m[1].to_i * 10000) + (m[2].to_i * 100) + m[3].to_i end @server_version 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
365 366 367 368 369 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 365 def table_exists?(table, opts={}) schema, table = schema_and_table(table) opts[:schema] ||= schema tables(opts){|ds| !ds.first(:relname=>table.to_s).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
378 379 380 381 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 378 def tables(opts={}) ds = self[:pg_class].join(:pg_namespace, :oid=>:relnamespace, 'r'=>:relkind, :nspname=>(opts[:schema]||default_schema).to_s).select(:relname).exclude(:relname.like(SYSTEM_TABLE_REGEXP)).server(opts[:server]) block_given? ? yield(ds) : ds.map{|r| r[:relname].to_sym} end |
#transaction(server = nil) ⇒ Object
PostgreSQL supports multi-level transactions using save points.
384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 |
# File 'lib/sequel_core/adapters/shared/postgres.rb', line 384 def transaction(server=nil) synchronize(server) do |conn| conn.transaction_depth = 0 if conn.transaction_depth.nil? if conn.transaction_depth > 0 log_info(SQL_SAVEPOINT % conn.transaction_depth) conn.execute(SQL_SAVEPOINT % conn.transaction_depth) else log_info(SQL_BEGIN) conn.execute(SQL_BEGIN) end begin conn.transaction_depth += 1 yield conn rescue ::Exception => e if conn.transaction_depth > 1 log_info(SQL_ROLLBACK_TO_SAVEPOINT % [conn.transaction_depth - 1]) conn.execute(SQL_ROLLBACK_TO_SAVEPOINT % [conn.transaction_depth - 1]) else log_info(SQL_ROLLBACK) conn.execute(SQL_ROLLBACK) rescue nil end transaction_error(e, *CONVERTED_EXCEPTIONS) ensure unless e begin if conn.transaction_depth < 2 log_info(SQL_COMMIT) conn.execute(SQL_COMMIT) else log_info(SQL_RELEASE_SAVEPOINT % [conn.transaction_depth - 1]) conn.execute(SQL_RELEASE_SAVEPOINT % [conn.transaction_depth - 1]) end rescue => e log_info(e.) raise_error(e, :classes=>CONVERTED_EXCEPTIONS) end end conn.transaction_depth -= 1 end end end |