source: trunk/docs/contents/pg/db_wrapper.rst @ 747

Last change on this file since 747 was 747, checked in by cito, 4 years ago

Improve the get/set_parameter methods

In addition to a list, also allow a set as parameter.

File size: 20.1 KB
Line 
1The DB wrapper class
2====================
3
4.. py:currentmodule:: pg
5
6.. class:: DB
7
8The :class:`Connection` methods are wrapped in the class :class:`DB`.
9The preferred way to use this module is as follows::
10
11    import pg
12
13    db = pg.DB(...)  # see below
14
15    for r in db.query(  # just for example
16        """SELECT foo,bar
17         FROM foo_bar_table
18         WHERE foo !~ bar"""
19        ).dictresult():
20
21        print '%(foo)s %(bar)s' % r
22
23This class can be subclassed as in this example::
24
25    import pg
26
27    class DB_ride(pg.DB):
28        """Ride database wrapper
29
30        This class encapsulates the database functions and the specific
31        methods for the ride database."""
32
33    def __init__(self):
34        """Open a database connection to the rides database"""
35        pg.DB.__init__(self, dbname='ride')
36        self.query("SET DATESTYLE TO 'ISO'")
37
38    [Add or override methods here]
39
40The following describes the methods and variables of this class.
41
42Initialization
43--------------
44The :class:`DB` class is initialized with the same arguments as the
45:func:`connect` function described above. It also initializes a few
46internal variables. The statement ``db = DB()`` will open the local
47database with the name of the user just like ``connect()`` does.
48
49You can also initialize the DB class with an existing :mod:`pg` or :mod:`pgdb`
50connection. Pass this connection as a single unnamed parameter, or as a
51single parameter named ``db``. This allows you to use all of the methods
52of the DB class with a DB-API 2 compliant connection. Note that the
53:meth:`Connection.close` and :meth:`Connection.reopen` methods are inoperative
54in this case.
55
56pkey -- return the primary key of a table
57-----------------------------------------
58
59.. method:: DB.pkey(table)
60
61    Return the primary key of a table
62
63    :param str table: name of table
64    :returns: Name of the field which is the primary key of the table
65    :rtype: str
66    :raises KeyError: the table does not have a primary key
67
68This method returns the primary key of a table. For composite primary
69keys, the return value will be a frozenset. Note that this raises a
70KeyError if the table does not have a primary key.
71
72get_databases -- get list of databases in the system
73----------------------------------------------------
74
75.. method:: DB.get_databases()
76
77    Get the list of databases in the system
78
79    :returns: all databases in the system
80    :rtype: list
81
82Although you can do this with a simple select, it is added here for
83convenience.
84
85get_relations -- get list of relations in connected database
86------------------------------------------------------------
87
88.. method:: DB.get_relations(kinds)
89
90    Get the list of relations in connected database
91
92    :param str kinds: a string or sequence of type letters
93    :returns: all relations of the given kinds in the database
94    :rtype: list
95
96The type letters are ``r`` = ordinary table, ``i`` = index, ``S`` = sequence,
97``v`` = view, ``c`` = composite type, ``s`` = special, ``t`` = TOAST table.
98If `kinds` is None or an empty string, all relations are returned (this is
99also the default). Although you can do this with a simple select, it is
100added here for convenience.
101
102get_tables -- get list of tables in connected database
103------------------------------------------------------
104
105.. method:: DB.get_tables()
106
107    Get the list of tables in connected database
108
109    :returns: all tables in connected database
110    :rtype: list
111
112This is a shortcut for ``get_relations('r')`` that has been added for
113convenience.
114
115get_attnames -- get the attribute names of a table
116--------------------------------------------------
117
118.. method:: DB.get_attnames(table)
119
120    Get the attribute names of a table
121
122    :param str table: name of table
123    :returns: a dictionary mapping attribute names to type names
124
125Given the name of a table, digs out the set of attribute names.
126
127Returns a dictionary of attribute names (the names are the keys,
128the values are the names of the attributes' types).
129
130If your Python version supports this, the dictionary will be an
131OrderedDictionary with the column names in the right order.
132
133By default, only a limited number of simple types will be returned.
134You can get the regular types after enabling this by calling the
135:meth:`DB.use_regtypes` method.
136
137has_table_privilege -- check table privilege
138--------------------------------------------
139
140.. method:: DB.has_table_privilege(table, privilege)
141
142    Check whether current user has specified table privilege
143
144    :param str table: the name of the table
145    :param str privilege: privilege to be checked -- default is 'select'
146    :returns: whether current user has specified table privilege
147    :rtype: bool
148
149Returns True if the current user has the specified privilege for the table.
150
151.. versionadded:: 4.0
152
153get/set_parameter -- get or set  run-time parameters
154----------------------------------------------------
155
156.. method:: DB.get_parameter(parameter)
157
158    Get the value of run-time parameters
159
160    :param parameter: the run-time parameter(s) to get
161    :type param: str, tuple, list or dict
162    :returns: the current value(s) of the run-time parameter(s)
163    :rtype: str, list or dict
164    :raises TypeError: Invalid parameter type(s)
165    :raises ProgrammingError: Invalid parameter name(s)
166
167If the parameter is a string, the return value will also be a string
168that is the current setting of the run-time parameter with that name.
169
170You can get several parameters at once by passing a list, set or dict.
171When passing a list of parameter names, the return value will be a
172corresponding list of parameter settings.  When passing a set of
173parameter names, a new dict will be returned, mapping these parameter
174names to their settings.  Finally, if you pass a dict as parameter,
175its values will be set to the current parameter settings corresponding
176to its keys.
177
178By passing the special name `'all'` as the parameter, you can get a dict
179of all existing configuration parameters.
180
181.. versionadded:: 4.2
182
183.. method:: DB.set_parameter(self, parameter, [value], [local])
184
185    Set the value of run-time parameters
186
187    :param parameter: the run-time parameter(s) to set
188    :type param: string, tuple, list or dict
189    :param value: the value to set
190    :type param: str or None
191    :raises TypeError: Invalid parameter type(s)
192    :raises ValueError: Invalid value argument(s)
193    :raises ProgrammingError: Invalid parameter name(s) or values
194
195If the parameter and the value are strings, the run-time parameter
196will be set to that value.  If no value or *None* is passed as a value,
197then the run-time parameter will be restored to its default value.
198
199You can set several parameters at once by passing a list of parameter
200names, together with a single value that all parameters should be
201set to or with a corresponding list of values.  You can also pass
202the parameters as a set if you only provide a single value.
203Finally, you can pass a dict with parameter names as keys.  In this
204case, you should not pass a value, since the values for the parameters
205will be taken from the dict.
206
207By passing the special name `'all'` as the parameter, you can reset
208all existing settable run-time parameters to their default values.
209
210If you set *local* to `True`, then the command takes effect for only the
211current transaction.  After :meth:`DB.commit` or :meth:`DB.rollback`,
212the session-level setting takes effect again.  Setting *local* to `True`
213will appear to have no effect if it is executed outside a transaction,
214since the transaction will end immediately.
215
216.. versionadded:: 4.2
217
218begin/commit/rollback/savepoint/release -- transaction handling
219---------------------------------------------------------------
220
221.. method:: DB.begin([mode])
222
223    Begin a transaction
224
225    :param str mode: an optional transaction mode such as 'READ ONLY'
226
227    This initiates a transaction block, that is, all following queries
228    will be executed in a single transaction until :meth:`DB.commit`
229    or :meth:`DB.rollback` is called.
230
231.. versionadded:: 4.1
232
233.. method:: DB.start()
234
235    This is the same as the :meth:`DB.begin` method.
236
237.. method:: DB.commit()
238
239    Commit a transaction
240
241    This commits the current transaction. All changes made by the
242    transaction become visible to others and are guaranteed to be
243    durable if a crash occurs.
244
245.. method:: DB.end()
246
247    This is the same as the :meth:`DB.commit` method.
248
249.. versionadded:: 4.1
250
251.. method:: DB.rollback([name])
252
253    Roll back a transaction
254
255    :param str name: optionally, roll back to the specified savepoint
256
257    This rolls back the current transaction and causes all the updates
258    made by the transaction to be discarded.
259
260.. versionadded:: 4.1
261
262.. method:: DB.savepoint(name)
263
264    Define a new savepoint
265
266    :param str name: the name to give to the new savepoint
267
268    This establishes a new savepoint within the current transaction.
269
270.. versionadded:: 4.1
271
272.. method:: DB.release(name)
273
274    Destroy a savepoint
275
276    :param str name: the name of the savepoint to destroy
277
278    This destroys a savepoint previously defined in the current transaction.
279
280.. versionadded:: 4.1
281
282get -- get a row from a database table or view
283----------------------------------------------
284
285.. method:: DB.get(table, row, [keyname])
286
287    Get a row from a database table or view
288
289    :param str table: name of table or view
290    :param row: either a dictionary or the value to be looked up
291    :param str keyname: name of field to use as key (optional)
292    :returns: A dictionary - the keys are the attribute names,
293      the values are the row values.
294    :raises ProgrammingError: no primary key or missing privilege
295
296This method is the basic mechanism to get a single row. It assumes
297that the key specifies a unique row. If *keyname* is not specified,
298then the primary key for the table is used. If *row* is a dictionary
299then the value for the key is taken from it and it is modified to
300include the new values, replacing existing values where necessary.
301For a composite key, *keyname* can also be a sequence of key names.
302The OID is also put into the dictionary if the table has one, but in
303order to allow the caller to work with multiple tables, it is munged
304as ``oid(table)``.
305
306insert -- insert a row into a database table
307--------------------------------------------
308
309.. method:: DB.insert(table, [row], [col=val, ...])
310
311    Insert a row into a database table
312
313    :param str table: name of table
314    :param dict row: optional dictionary of values
315    :param col: optional keyword arguments for updating the dictionary
316    :returns: the inserted values in the database
317    :rtype: dict
318    :raises ProgrammingError: missing privilege or conflict
319
320This method inserts a row into a table.  If the optional dictionary is
321not supplied then the required values must be included as keyword/value
322pairs.  If a dictionary is supplied then any keywords provided will be
323added to or replace the entry in the dictionary.
324
325The dictionary is then reloaded with the values actually inserted in order
326to pick up values modified by rules, triggers, etc.
327
328Note: The method currently doesn't support insert into views
329although PostgreSQL does.
330
331update -- update a row in a database table
332------------------------------------------
333
334.. method:: DB.update(table, [row], [col=val, ...])
335
336    Update a row in a database table
337
338    :param str table: name of table
339    :param dict row: optional dictionary of values
340    :param col: optional keyword arguments for updating the dictionary
341    :returns: the new row in the database
342    :rtype: dict
343    :raises ProgrammingError: no primary key or missing privilege
344
345Similar to insert but updates an existing row.  The update is based on the
346OID value as munged by get or passed as keyword, or on the primary key of
347the table.  The dictionary is modified to reflect any changes caused by the
348update due to triggers, rules, default values, etc.
349
350Like insert, the dictionary is optional and updates will be performed
351on the fields in the keywords.  There must be an OID or primary key
352either in the dictionary where the OID must be munged, or in the keywords
353where it can be simply the string 'oid'.
354
355upsert -- insert a row with conflict resolution
356-----------------------------------------------
357
358.. method:: DB.upsert(table, [row], [col=val, ...])
359
360    Insert a row into a database table with conflict resolution
361
362    :param str table: name of table
363    :param dict row: optional dictionary of values
364    :param col: optional keyword arguments for specifying the update
365    :returns: the new row in the database
366    :rtype: dict
367    :raises ProgrammingError: no primary key or missing privilege
368
369This method inserts a row into a table, but instead of raising a
370ProgrammingError exception in case a row with the same primary key already
371exists, an update will be executed instead.  This will be performed as a
372single atomic operation on the database, so race conditions can be avoided.
373
374Like the insert method, the first parameter is the name of the table and the
375second parameter can be used to pass the values to be inserted as a dictionary.
376
377Unlike the insert und update statement, keyword parameters are not used to
378modify the dictionary, but to specify which columns shall be updated in case
379of a conflict, and in which way:
380
381A value of `False` or `None` means the column shall not be updated,
382a value of `True` means the column shall be updated with the value that
383has been proposed for insertion, i.e. has been passed as value in the
384dictionary.  Columns that are not specified by keywords but appear as keys
385in the dictionary are also updated like in the case keywords had been passed
386with the value `True`.
387
388So if in the case of a conflict you want to update every column that has been
389passed in the dictionary `d` , you would call ``upsert(table, d)``.  If you
390don't want to do anything in case of a conflict, i.e. leave the existing row
391as it is, call ``upsert(table, d, **dict.fromkeys(d))``.
392
393If you need more fine-grained control of what gets updated, you can also pass
394strings in the keyword parameters.  These strings will be used as SQL
395expressions for the update columns.  In these expressions you can refer
396to the value that already exists in the table by writing the table prefix
397``included.`` before the column name, and you can refer to the value that
398has been proposed for insertion by writing ``excluded.`` as table prefix.
399
400The dictionary is modified in any case to reflect the values in the database
401after the operation has completed.
402
403.. note::
404
405    The method uses the PostgreSQL "upsert" feature which is only available
406    since PostgreSQL 9.5. With older PostgreSQL versions, you will get a
407    ProgrammingError if you use this method.
408
409.. versionadded:: 5.0
410
411query -- execute a SQL command string
412-------------------------------------
413
414.. method:: DB.query(command, [arg1, [arg2, ...]])
415
416    Execute a SQL command string
417
418    :param str command: SQL command
419    :param arg*: optional positional arguments
420    :returns: result values
421    :rtype: :class:`Query`, None
422    :raises TypeError: bad argument type, or too many arguments
423    :raises TypeError: invalid connection
424    :raises ValueError: empty SQL query or lost connection
425    :raises pg.ProgrammingError: error in query
426    :raises pg.InternalError: error during query processing
427
428Similar to the :class:`Connection` function with the same name, except that
429positional arguments can be passed either as a single list or tuple, or as
430individual positional arguments.
431
432Example::
433
434    name = input("Name? ")
435    phone = input("Phone? ")
436    rows = db.query("update employees set phone=$2 where name=$1",
437        (name, phone)).getresult()[0][0]
438    # or
439    rows = db.query("update employees set phone=$2 where name=$1",
440         name, phone).getresult()[0][0]
441
442clear -- clear row values in memory
443-----------------------------------
444
445.. method:: DB.clear(table, [row])
446
447    Clear row values in memory
448
449    :param str table: name of table
450    :param dict row: optional dictionary of values
451    :returns: an empty row
452    :rtype: dict
453
454This method clears all the attributes to values determined by the types.
455Numeric types are set to 0, Booleans are set to ``'f'``, and everything
456else is set to the empty string.  If the row argument is present, it is
457used as the row dictionary and any entries matching attribute names are
458cleared with everything else left unchanged.
459
460If the dictionary is not supplied a new one is created.
461
462delete -- delete a row from a database table
463--------------------------------------------
464
465.. method:: DB.delete(table, [row], [col=val, ...])
466
467    Delete a row from a database table
468
469    :param str table: name of table
470    :param dict d: optional dictionary of values
471    :param col: optional keyword arguments for updating the dictionary
472    :rtype: None
473
474This method deletes the row from a table.  It deletes based on the OID value
475as munged by get or passed as keyword, or on the primary key of the table.
476The return value is the number of deleted rows (i.e. 0 if the row did not
477exist and 1 if the row was deleted).
478
479escape_literal -- escape a literal string for use within SQL
480------------------------------------------------------------
481
482.. method:: DB.escape_literal(string)
483
484    Escape a string for use within SQL as a literal constant
485
486    :param str string: the string that is to be escaped
487    :returns: the escaped string
488    :rtype: str
489
490This method escapes a string for use within an SQL command. This is useful
491when inserting data values as literal constants in SQL commands. Certain
492characters (such as quotes and backslashes) must be escaped to prevent them
493from being interpreted specially by the SQL parser.
494
495.. versionadded:: 4.1
496
497escape_identifier -- escape an identifier string for use within SQL
498-------------------------------------------------------------------
499
500.. method:: DB.escape_identifier(string)
501
502    Escape a string for use within SQL as an identifier
503
504    :param str string: the string that is to be escaped
505    :returns: the escaped string
506    :rtype: str
507
508This method escapes a string for use as an SQL identifier, such as a table,
509column, or function name. This is useful when a user-supplied identifier
510might contain special characters that would otherwise not be interpreted
511as part of the identifier by the SQL parser, or when the identifier might
512contain upper case characters whose case should be preserved.
513
514.. versionadded:: 4.1
515
516escape_string -- escape a string for use within SQL
517---------------------------------------------------
518
519.. method:: DB.escape_string(string)
520
521    Escape a string for use within SQL
522
523    :param str string: the string that is to be escaped
524    :returns: the escaped string
525    :rtype: str
526
527Similar to the module function with the same name, but the
528behavior of this method is adjusted depending on the connection properties
529(such as character encoding).
530
531escape_bytea -- escape binary data for use within SQL
532-----------------------------------------------------
533
534.. method:: DB.escape_bytea(datastring)
535
536    Escape binary data for use within SQL as type ``bytea``
537
538    :param str datastring: string containing the binary data that is to be escaped
539    :returns: the escaped string
540    :rtype: str
541
542Similar to the module function with the same name, but the
543behavior of this method is adjusted depending on the connection properties
544(in particular, whether standard-conforming strings are enabled).
545
546unescape_bytea -- unescape data that has been retrieved as text
547---------------------------------------------------------------
548
549.. method:: DB.unescape_bytea(string)
550
551    Unescape ``bytea`` data that has been retrieved as text
552
553    :param datastring: the ``bytea`` data string that has been retrieved as text
554    :returns: byte string containing the binary data
555    :rtype: bytes
556
557See the module function with the same name.
558
559use_regtypes -- determine use of regular type names
560---------------------------------------------------
561
562.. method:: DB.use_regtypes([regtypes])
563
564    Determine whether regular type names shall be used
565
566    :param bool regtypes: if passed, set whether regular type names shall be used
567    :returns: whether regular type names are used
568
569The :meth:`DB.get_attnames` method can return either simplified "classic"
570type names (the default) or more specific "regular" type names. Which kind
571of type names is used can be changed by calling :meth:`DB.get_regtypes`.
572If you pass a boolean, it sets whether regular type names shall be used.
573The method can also be used to check through its return value whether
574currently regular type names are used.
575
576.. versionadded:: 4.1
Note: See TracBrowser for help on using the repository browser.