The DB wrapper class

class pg.DB

The pgobject methods are wrapped in the class DB. The preferred way to use this module is as follows:

import pg

db = pg.DB(...)  # see below

for r in db.query(  # just for example
    """SELECT foo,bar
     FROM foo_bar_table
     WHERE foo !~ bar"""
    ).dictresult():

    print '%(foo)s %(bar)s' % r

This class can be subclassed as in this example:

import pg

class DB_ride(pg.DB):
    """Ride database wrapper

    This class encapsulates the database functions and the specific
    methods for the ride database."""

def __init__(self):
    """Open a database connection to the rides database"""
    pg.DB.__init__(self, dbname='ride')
    self.query("SET DATESTYLE TO 'ISO'")

[Add or override methods here]

The following describes the methods and variables of this class.

Initialization

The DB class is initialized with the same arguments as the connect() function described above. It also initializes a few internal variables. The statement db = DB() will open the local database with the name of the user just like connect() does.

You can also initialize the DB class with an existing pg or pgdb connection. Pass this connection as a single unnamed parameter, or as a single parameter named db. This allows you to use all of the methods of the DB class with a DB-API 2 compliant connection. Note that the pgobject.close() and pgobject.reopen() methods are inoperative in this case.

pkey – return the primary key of a table

DB.pkey(table)

Return the primary key of a table

Parameters:table (str) – name of table
Returns:Name of the field which is the primary key of the table
Return type:str
Return type:str
Raises:KeyError – the table does not have a primary key

This method returns the primary key of a table. For composite primary keys, the return value will be a frozenset. Note that this raises a KeyError if the table does not have a primary key.

get_databases – get list of databases in the system

DB.get_databases()

Get the list of databases in the system

Returns:all databases in the system
Return type:list

Although you can do this with a simple select, it is added here for convenience.

get_relations – get list of relations in connected database

DB.get_relations([kinds][, system])

Get the list of relations in connected database

Parameters:
  • kinds (str) – a string or sequence of type letters
  • system (bool) – whether system relations should be returned
Returns:

all relations of the given kinds in the database

Return type:

list

This method returns the list of relations in the connected database. Although you can do this with a simple select, it is added here for convenience. You can select which kinds of relations you are interested in by passing type letters in the kinds parameter. The type letters are r = ordinary table, i = index, S = sequence, v = view, c = composite type, s = special, t = TOAST table. If kinds is None or an empty string, all relations are returned (this is also the default). If system is set to True, then system tables and views (temporary tables, toast tables, catalog vies and tables) will be returned as well, otherwise they will be ignored.

get_tables – get list of tables in connected database

DB.get_tables([system])

Get the list of tables in connected database

Parameters:system (bool) – whether system tables should be returned
Returns:all tables in connected database
Return type:list

This is a shortcut for get_relations('r', system) that has been added for convenience.

get_attnames – get the attribute names of a table

DB.get_attnames(table)

Get the attribute names of a table

Parameters:table (str) – name of table
Returns:a dictionary mapping attribute names to type names

Given the name of a table, digs out the set of attribute names.

Returns a dictionary of attribute names (the names are the keys, the values are the names of the attributes’ types).

By default, only a limited number of simple types will be returned. You can get the regular types after enabling this by calling the DB.use_regtypes() method.

get/set_parameter – get or set run-time parameters

DB.get_parameter(parameter)

Get the value of run-time parameters

Parameters:

parameter – the run-time parameter(s) to get

Returns:

the current value(s) of the run-time parameter(s)

Return type:

str, list or dict

Raises:
  • TypeError – Invalid parameter type(s)
  • pg.ProgrammingError – Invalid parameter name(s)

If the parameter is a string, the return value will also be a string that is the current setting of the run-time parameter with that name.

You can get several parameters at once by passing a list, set or dict. When passing a list of parameter names, the return value will be a corresponding list of parameter settings. When passing a set of parameter names, a new dict will be returned, mapping these parameter names to their settings. Finally, if you pass a dict as parameter, its values will be set to the current parameter settings corresponding to its keys.

By passing the special name ‘all’ as the parameter, you can get a dict of all existing configuration parameters.

New in version 4.2.

DB.set_parameter(parameter[, value][, local])

Set the value of run-time parameters

Parameters:
  • parameter – the run-time parameter(s) to set
  • value – the value to set
Raises:
  • TypeError – Invalid parameter type(s)
  • ValueError – Invalid value argument(s)
  • pg.ProgrammingError – Invalid parameter name(s) or values

If the parameter and the value are strings, the run-time parameter will be set to that value. If no value or None is passed as a value, then the run-time parameter will be restored to its default value.

You can set several parameters at once by passing a list of parameter names, together with a single value that all parameters should be set to or with a corresponding list of values. You can also pass the parameters as a set if you only provide a single value. Finally, you can pass a dict with parameter names as keys. In this case, you should not pass a value, since the values for the parameters will be taken from the dict.

By passing the special name ‘all’ as the parameter, you can reset all existing settable run-time parameters to their default values.

If you set local to True, then the command takes effect for only the current transaction. After DB.commit() or DB.rollback(), the session-level setting takes effect again. Setting local to True will appear to have no effect if it is executed outside a transaction, since the transaction will end immediately.

New in version 4.2.

has_table_privilege – check table privilege

DB.has_table_privilege(table, privilege)

Check whether current user has specified table privilege

Parameters:
  • table (str) – the name of the table
  • privilege (str) – privilege to be checked – default is ‘select’
Returns:

whether current user has specified table privilege

Return type:

bool

Returns True if the current user has the specified privilege for the table.

New in version 4.0.

begin/commit/rollback/savepoint/release – transaction handling

DB.begin([mode])

Begin a transaction

Parameters:mode (str) – an optional transaction mode such as ‘READ ONLY’

This initiates a transaction block, that is, all following queries will be executed in a single transaction until DB.commit() or DB.rollback() is called.

New in version 4.1.

DB.start()

This is the same as the DB.begin() method.

DB.commit()

Commit a transaction

This commits the current transaction. All changes made by the transaction become visible to others and are guaranteed to be durable if a crash occurs.

DB.end()

This is the same as the DB.commit() method.

New in version 4.1.

DB.rollback([name])

Roll back a transaction

Parameters:name (str) – optionally, roll back to the specified savepoint

This rolls back the current transaction and causes all the updates made by the transaction to be discarded.

New in version 4.1.

DB.abort()

This is the same as the DB.rollback() method.

New in version 4.2.

DB.savepoint(name)

Define a new savepoint

Parameters:name (str) – the name to give to the new savepoint

This establishes a new savepoint within the current transaction.

New in version 4.1.

DB.release(name)

Destroy a savepoint

Parameters:name (str) – the name of the savepoint to destroy

This destroys a savepoint previously defined in the current transaction.

New in version 4.1.

get – get a row from a database table or view

DB.get(table, arg[, keyname])

Get a row from a database table or view

Parameters:
  • table (str) – name of table or view
  • arg – either a dictionary or the value to be looked up
  • keyname (str) – name of field to use as key (optional)
Returns:

A dictionary - the keys are the attribute names, the values are the row values.

Raises:

pg.ProgrammingError – no primary key or missing privilege

This method is the basic mechanism to get a single row. It assumes that the key specifies a unique row. If keyname is not specified, then the primary key for the table is used. If arg is a dictionary then the value for the key is taken from it and it is modified to include the new values, replacing existing values where necessary. For a composite key, keyname can also be a sequence of key names. The OID is also put into the dictionary if the table has one, but in order to allow the caller to work with multiple tables, it is munged as oid(schema.table).

insert – insert a row into a database table

DB.insert(table[, d][, key=val, ...])

Insert a row into a database table

Parameters:
  • table (str) – name of table
  • d (dict) – optional dictionary of values
Returns:

the inserted values in the database

Return type:

dict

Raises:

pg.ProgrammingError – missing privilege or conflict

This method inserts a row into a table. If the optional dictionary is not supplied then the required values must be included as keyword/value pairs. If a dictionary is supplied then any keywords provided will be added to or replace the entry in the dictionary.

The dictionary is then, if possible, reloaded with the values actually inserted in order to pick up values modified by rules, triggers, etc.

update – update a row in a database table

DB.update(table[, d][, key=val, ...])

Update a row in a database table

Parameters:
  • table (str) – name of table
  • d (dict) – optional dictionary of values
Returns:

the new row in the database

Return type:

dict

Raises:

pg.ProgrammingError – no primary key or missing privilege

Similar to insert but updates an existing row. The update is based on the OID value as munged by DB.get() or passed as keyword, or on the primary key of the table. The dictionary is modified, if possible, to reflect any changes caused by the update due to triggers, rules, default values, etc.

Like insert, the dictionary is optional and updates will be performed on the fields in the keywords. There must be an OID or primary key either in the dictionary where the OID must be munged, or in the keywords where it can be simply the string 'oid'.

query – execute a SQL command string

DB.query(command[, arg1[, arg2, ...]])

Execute a SQL command string

Parameters:
  • command (str) – SQL command
  • arg* – optional positional arguments
Returns:

result values

Return type:

pgqueryobject, None

Raises:
  • TypeError – bad argument type, or too many arguments
  • TypeError – invalid connection
  • ValueError – empty SQL query or lost connection
  • pg.ProgrammingError – error in query
  • pg.InternalError – error during query processing

Similar to the pgobject function with the same name, except that positional arguments can be passed either as a single list or tuple, or as individual positional arguments.

Example:

name = raw_input("Name? ")
phone = raw_input("Phone? ")
rows = db.query("update employees set phone=$2 where name=$1",
    (name, phone)).getresult()[0][0]
# or
rows = db.query("update employees set phone=$2 where name=$1",
     name, phone).getresult()[0][0]

clear – clear row values in memory

DB.clear(table[, d])

Clear row values in memory

Parameters:
  • table (str) – name of table
  • d (dict) – optional dictionary of values
Returns:

an empty row

Return type:

dict

This method clears all the attributes to values determined by the types. Numeric types are set to 0, Booleans are set to 'f', and everything else is set to the empty string. If the optional dictionary is present, it is used as the row and any entries matching attribute names are cleared with everything else left unchanged.

If the dictionary is not supplied a new one is created.

delete – delete a row from a database table

DB.delete(table[, d][, key=val, ...])

Delete a row from a database table

Parameters:
  • table (str) – name of table
  • d (dict) – optional dictionary of values
Return type:

None

Raises:

pg.ProgrammingError – table has no primary key, row is still referenced or missing privilege

This method deletes the row from a table. It deletes based on the OID value as munged by DB.get() or passed as keyword, or on the primary key of the table. The return value is the number of deleted rows (i.e. 0 if the row did not exist and 1 if the row was deleted).

truncate – quickly empty database tables

DB.truncate(table[, restart][, cascade][, only])

Empty a table or set of tables

Parameters:
  • table (str, list or set) – the name of the table(s)
  • restart (bool) – whether table sequences should be restarted
  • cascade (bool) – whether referenced tables should also be truncated
  • only (bool or list) – whether only parent tables should be truncated

This method quickly removes all rows from the given table or set of tables. It has the same effect as an unqualified DELETE on each table, but since it does not actually scan the tables it is faster. Furthermore, it reclaims disk space immediately, rather than requiring a subsequent VACUUM operation. This is most useful on large tables.

If restart is set to True, sequences owned by columns of the truncated table(s) are automatically restarted. If cascade is set to True, it also truncates all tables that have foreign-key references to any of the named tables. If the parameter only is not set to True, all the descendant tables (if any) will also be truncated. Optionally, a * can be specified after the table name to explicitly indicate that descendant tables are included. If the parameter table is a list, the parameter only can also be a list of corresponding boolean values.

New in version 4.2.

escape_literal/identifier/string/bytea – escape for SQL

The following methods escape text or binary strings so that they can be inserted directly into an SQL command. Except for DB.escape_byte(), you don’t need to call these methods for the strings passed as parameters to DB.query(). You also don’t need to call any of these methods when storing data using DB.insert() and similar.

DB.escape_literal(string)

Escape a string for use within SQL as a literal constant

Parameters:string (str) – the string that is to be escaped
Returns:the escaped string
Return type:str

This method escapes a string for use within an SQL command. This is useful when inserting data values as literal constants in SQL commands. Certain characters (such as quotes and backslashes) must be escaped to prevent them from being interpreted specially by the SQL parser.

New in version 4.1.

DB.escape_identifier(string)

Escape a string for use within SQL as an identifier

Parameters:string (str) – the string that is to be escaped
Returns:the escaped string
Return type:str

This method escapes a string for use as an SQL identifier, such as a table, column, or function name. This is useful when a user-supplied identifier might contain special characters that would otherwise not be interpreted as part of the identifier by the SQL parser, or when the identifier might contain upper case characters whose case should be preserved.

New in version 4.1.

DB.escape_bytea(datastring)

Escape binary data for use within SQL as type bytea

Parameters:datastring (str) – string containing the binary data that is to be escaped
Returns:the escaped string
Return type:str

Similar to the module function pg.escape_string() with the same name, but the behavior of this method is adjusted depending on the connection properties (such as character encoding).

unescape_bytea – unescape data retrieved from the database

DB.unescape_bytea(string)

Unescape bytea data that has been retrieved as text

Parameters:datastring – the bytea data string that has been retrieved as text
Returns:byte string containing the binary data
Return type:str

See the module function pg.unescape_bytea() with the same name.

use_regtypes – determine use of regular type names

DB.use_regtypes([regtypes])

Determine whether regular type names shall be used

Parameters:regtypes (bool) – if passed, set whether regular type names shall be used
Returns:whether regular type names are used

The DB.get_attnames() method can return either simplified “classic” type names (the default) or more specific “regular” type names. Which kind of type names is used can be changed by calling DB.get_regtypes(). If you pass a boolean, it sets whether regular type names shall be used. The method can also be used to check through its return value whether currently regular type names are used.

New in version 4.1.

notification_handler – create a notification handler

class DB.notification_handler(event, callback[, arg_dict][, timeout][, stop_event])

Create a notification handler instance

Parameters:
  • event (str) – the name of an event to listen for
  • callback – a callback function
  • arg_dict (dict) – an optional dictionary for passing arguments
  • timeout (int, float or None) – the time-out when waiting for notifications
  • stop_event (str) – an optional different name to be used as stop event

This method creates a pg.NotificationHandler object using the DB connection as explained under The Notification Handler.

New in version 4.1.1.