1 """GNUmed PostgreSQL connection handling.
2
3 TODO: iterator/generator batch fetching:
4 - http://groups-beta.google.com/group/comp.lang.python/msg/7ff516d7d9387dad
5 - search Google for "Geneator/Iterator Nesting Problem - Any Ideas? 2.4"
6
7 winner:
8 def resultset_functional_batchgenerator(cursor, size=100):
9 for results in iter(lambda: cursor.fetchmany(size), []):
10 for rec in results:
11 yield rec
12 """
13
14 __author__ = "K.Hilbert <Karsten.Hilbert@gmx.net>"
15 __license__ = 'GPL v2 or later (details at http://www.gnu.org)'
16
17
18 import time
19 import sys
20 import os
21 import codecs
22 import types
23 import logging
24 import datetime as pydt
25 import re as regex
26
27
28
29 if __name__ == '__main__':
30 sys.path.insert(0, '../../')
31 from Gnumed.pycommon import gmLoginInfo
32 from Gnumed.pycommon import gmExceptions
33 from Gnumed.pycommon import gmDateTime
34 from Gnumed.pycommon import gmBorg
35 from Gnumed.pycommon import gmI18N
36 from Gnumed.pycommon import gmLog2
37 from Gnumed.pycommon.gmTools import prompted_input, u_replacement_character
38
39 _log = logging.getLogger('gm.db')
40
41
42
43 try:
44 import psycopg2 as dbapi
45 except ImportError:
46 _log.exception("Python database adapter psycopg2 not found.")
47 print "CRITICAL ERROR: Cannot find module psycopg2 for connecting to the database server."
48 raise
49
50
51 _log.info('psycopg2 version: %s' % dbapi.__version__)
52 _log.info('PostgreSQL via DB-API module "%s": API level %s, thread safety %s, parameter style "%s"' % (dbapi, dbapi.apilevel, dbapi.threadsafety, dbapi.paramstyle))
53 if not (float(dbapi.apilevel) >= 2.0):
54 raise ImportError('gmPG2: supported DB-API level too low')
55 if not (dbapi.threadsafety > 0):
56 raise ImportError('gmPG2: lacking minimum thread safety in psycopg2')
57 if not (dbapi.paramstyle == 'pyformat'):
58 raise ImportError('gmPG2: lacking pyformat (%%(<name>)s style) placeholder support in psycopg2')
59 try:
60 dbapi.__version__.index('dt')
61 except ValueError:
62 raise ImportError('gmPG2: lacking datetime support in psycopg2')
63 try:
64 dbapi.__version__.index('ext')
65 except ValueError:
66 raise ImportError('gmPG2: lacking extensions support in psycopg2')
67 try:
68 dbapi.__version__.index('pq3')
69 except ValueError:
70 raise ImportError('gmPG2: lacking v3 backend protocol support in psycopg2')
71
72 import psycopg2.extras
73 import psycopg2.extensions
74 import psycopg2.pool
75 import psycopg2.errorcodes as sql_error_codes
76
77
78 _default_client_encoding = 'UTF8'
79 _log.info('assuming default client encoding of [%s]' % _default_client_encoding)
80
81
82 _default_client_timezone = None
83 _sql_set_timezone = None
84 _timestamp_template = "cast('%s' as timestamp with time zone)"
85 FixedOffsetTimezone = dbapi.tz.FixedOffsetTimezone
86
87 _default_dsn = None
88 _default_login = None
89
90 postgresql_version_string = None
91 postgresql_version = None
92
93 __ro_conn_pool = None
94
95 auto_request_login_params = True
96
97
98
99
100 known_schema_hashes = {
101 0: 'not released, testing only',
102 2: 'b09d50d7ed3f91ddf4c4ddb8ea507720',
103 3: 'e73718eaf230d8f1d2d01afa8462e176',
104 4: '4428ccf2e54c289136819e701bb095ea',
105 5: '7e7b093af57aea48c288e76632a382e5',
106 6: '90e2026ac2efd236da9c8608b8685b2d',
107 7: '6c9f6d3981483f8e9433df99d1947b27',
108 8: '89b13a7af83337c3aad153b717e52360',
109 9: '641a9b2be3c378ffc2bb2f0b1c9f051d',
110 10: '7ef42a8fb2bd929a2cdd0c63864b4e8a',
111 11: '03042ae24f3f92877d986fb0a6184d76',
112 12: '06183a6616db62257e22814007a8ed07',
113 13: 'fab7c1ae408a6530c47f9b5111a0841e',
114 14: 'e170d543f067d1ea60bfe9076b1560cf',
115 15: '70012ff960b77ecdff4981c94b5b55b6',
116 16: '0bcf44ca22c479b52976e5eda1de8161',
117 17: '161428ee97a00e3bf56168c3a15b7b50',
118 18: 'a0f9efcabdecfb4ddb6d8c0b69c02092'
119 }
120
121 map_schema_hash2version = {
122 'b09d50d7ed3f91ddf4c4ddb8ea507720': 2,
123 'e73718eaf230d8f1d2d01afa8462e176': 3,
124 '4428ccf2e54c289136819e701bb095ea': 4,
125 '7e7b093af57aea48c288e76632a382e5': 5,
126 '90e2026ac2efd236da9c8608b8685b2d': 6,
127 '6c9f6d3981483f8e9433df99d1947b27': 7,
128 '89b13a7af83337c3aad153b717e52360': 8,
129 '641a9b2be3c378ffc2bb2f0b1c9f051d': 9,
130 '7ef42a8fb2bd929a2cdd0c63864b4e8a': 10,
131 '03042ae24f3f92877d986fb0a6184d76': 11,
132 '06183a6616db62257e22814007a8ed07': 12,
133 'fab7c1ae408a6530c47f9b5111a0841e': 13,
134 'e170d543f067d1ea60bfe9076b1560cf': 14,
135 '70012ff960b77ecdff4981c94b5b55b6': 15,
136 '0bcf44ca22c479b52976e5eda1de8161': 16,
137 '161428ee97a00e3bf56168c3a15b7b50': 17,
138 'a0f9efcabdecfb4ddb6d8c0b69c02092': 18
139 }
140
141 map_client_branch2required_db_version = {
142 u'GIT tree': 0,
143 u'0.3': 9,
144 u'0.4': 10,
145 u'0.5': 11,
146 u'0.6': 12,
147 u'0.7': 13,
148 u'0.8': 14,
149 u'0.9': 15,
150 u'1.0': 16,
151 u'1.1': 16,
152 u'1.2': 17,
153 u'1.3': 18
154 }
155
156
157 query_table_col_defs = u"""select
158 cols.column_name,
159 cols.udt_name
160 from
161 information_schema.columns cols
162 where
163 cols.table_schema = %s
164 and
165 cols.table_name = %s
166 order by
167 cols.ordinal_position"""
168
169 query_table_attributes = u"""select
170 cols.column_name
171 from
172 information_schema.columns cols
173 where
174 cols.table_schema = %s
175 and
176 cols.table_name = %s
177 order by
178 cols.ordinal_position"""
179
180
181
182 SQL_foreign_key_name = u"""SELECT tc.constraint_schema, tc.constraint_name
183 FROM
184 information_schema.table_constraints tc
185 INNER JOIN information_schema.constraint_column_usage ccu USING (constraint_catalog, constraint_schema, constraint_name)
186 INNER JOIN information_schema.key_column_usage kcu USING (constraint_catalog, constraint_schema, constraint_name)
187 WHERE
188 tc.constraint_type = 'FOREIGN KEY'
189 AND
190 kcu.table_schema = %(src_schema)s
191 AND
192 kcu.table_name = %(src_tbl)s
193 AND
194 kcu.column_name = %(src_col)s
195 AND
196 ccu.table_schema = %(target_schema)s
197 AND
198 ccu.table_name = %(target_tbl)s
199 AND
200 ccu.column_name = %(target_col)s"""
201
202
203
204
206
207 if encoding not in psycopg2.extensions.encodings:
208 raise ValueError('psycopg2 does not know how to handle client (wire) encoding [%s]' % encoding)
209
210 py_enc = psycopg2.extensions.encodings[encoding]
211 try:
212 codecs.lookup(py_enc)
213 except LookupError:
214 _log.warning('<codecs> module can NOT handle encoding [psycopg2::<%s> -> Python::<%s>]' % (encoding, py_enc))
215 raise
216
217
218
219
220 global _default_client_encoding
221 _log.info('setting default client encoding from [%s] to [%s]' % (_default_client_encoding, str(encoding)))
222 _default_client_encoding = encoding
223 return True
224
236
238
239 _log.debug(u'validating time zone [%s]', timezone)
240
241 cmd = u'set timezone to %(tz)s'
242 args = {u'tz': timezone}
243
244 conn.commit()
245 curs = conn.cursor()
246 is_valid = False
247 try:
248 curs.execute(cmd, args)
249 _log.info(u'time zone [%s] is settable', timezone)
250
251 cmd = u"""select '1920-01-19 23:00:00+01'::timestamp with time zone"""
252 try:
253 curs.execute(cmd)
254 curs.fetchone()
255 _log.info(u'time zone [%s] is usable', timezone)
256 is_valid = True
257 except:
258 _log.error('error using time zone [%s]', timezone)
259 except dbapi.DataError:
260 _log.warning(u'time zone [%s] is not settable', timezone)
261 except:
262 _log.error(u'failed to set time zone to [%s]', timezone)
263 _log.exception(u'')
264
265 curs.close()
266 conn.rollback()
267
268 return is_valid
269
271 """some timezone defs are abbreviations so try to expand
272 them because "set time zone" doesn't take abbreviations"""
273
274 cmd = u"""
275 select distinct on (abbrev) name
276 from pg_timezone_names
277 where
278 abbrev = %(tz)s and
279 name ~ '^[^/]+/[^/]+$' and
280 name !~ '^Etc/'
281 """
282 args = {u'tz': timezone}
283
284 conn.commit()
285 curs = conn.cursor()
286
287 result = timezone
288 try:
289 curs.execute(cmd, args)
290 rows = curs.fetchall()
291 if len(rows) > 0:
292 result = rows[0][0]
293 _log.debug(u'[%s] maps to [%s]', timezone, result)
294 except:
295 _log.exception(u'cannot expand timezone abbreviation [%s]', timezone)
296
297 curs.close()
298 conn.rollback()
299
300 return result
301
347
348
349
369
394
396 """Request login parameters for database connection."""
397
398 if not auto_request_login_params:
399 raise Exception('Cannot request login parameters.')
400
401
402
403
404 if os.environ.has_key('DISPLAY'):
405
406 try: return __request_login_params_gui_wx()
407 except: pass
408
409
410
411 return __request_login_params_tui()
412
413
414
415
416 -def make_psycopg2_dsn(database=None, host=None, port=5432, user=None, password=None):
417 dsn_parts = []
418
419 if (database is not None) and (database.strip() != ''):
420 dsn_parts.append('dbname=%s' % database)
421
422 if (host is not None) and (host.strip() != ''):
423 dsn_parts.append('host=%s' % host)
424
425 if (port is not None) and (str(port).strip() != ''):
426 dsn_parts.append('port=%s' % port)
427
428 if (user is not None) and (user.strip() != ''):
429 dsn_parts.append('user=%s' % user)
430
431 if (password is not None) and (password.strip() != ''):
432 dsn_parts.append('password=%s' % password)
433
434 dsn_parts.append('sslmode=prefer')
435
436 return ' '.join(dsn_parts)
437
442
452
454 if login is None:
455 return False
456
457 if login.host is not None:
458 if login.host.strip() == u'':
459 login.host = None
460
461 global _default_login
462 _default_login = login
463 _log.info('setting default login from [%s] to [%s]' % (_default_login, login))
464
465 dsn = make_psycopg2_dsn(login.database, login.host, login.port, login.user, login.password)
466
467 global _default_dsn
468 if _default_dsn is None:
469 old_dsn = u'None'
470 else:
471 old_dsn = regex.sub(r'password=[^\s]+', u'password=%s' % u_replacement_character, _default_dsn)
472 _log.info ('setting default DSN from [%s] to [%s]',
473 old_dsn,
474 regex.sub(r'password=[^\s]+', u'password=%s' % u_replacement_character, dsn)
475 )
476 _default_dsn = dsn
477
478 return True
479
480
481
483 expected_hash = known_schema_hashes[version]
484 if version == 0:
485 args = {'ver': 9999}
486 else:
487 args = {'ver': version}
488 rows, idx = run_ro_queries (
489 link_obj = link_obj,
490 queries = [{
491 'cmd': u'select md5(gm.concat_table_structure(%(ver)s::integer)) as md5',
492 'args': args
493 }]
494 )
495 if rows[0]['md5'] != expected_hash:
496 _log.error('database schema version mismatch')
497 _log.error('expected: %s (%s)' % (version, expected_hash))
498 _log.error('detected: %s (%s)' % (get_schema_version(link_obj=link_obj), rows[0]['md5']))
499 if verbose:
500 _log.debug('schema dump follows:')
501 for line in get_schema_structure(link_obj = link_obj).split():
502 _log.debug(line)
503 _log.debug('schema revision history dump follows:')
504 for line in get_schema_revision_history(link_obj = link_obj):
505 _log.debug(u' - '.join(line))
506 return False
507 _log.info('detected schema version [%s], hash [%s]' % (map_schema_hash2version[rows[0]['md5']], rows[0]['md5']))
508 return True
509
511 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': u'select md5(gm.concat_table_structure()) as md5'}])
512 try:
513 return map_schema_hash2version[rows[0]['md5']]
514 except KeyError:
515 return u'unknown database schema version, MD5 hash is [%s]' % rows[0]['md5']
516
518 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': u'select gm.concat_table_structure()'}])
519 return rows[0][0]
520
522 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': u'select md5(gm.concat_table_structure()) as md5'}])
523 return rows[0]['md5']
524
526
527 if table_exists(link_obj = link_obj, schema = 'gm', table = 'schema_revision'):
528 cmd = u"""
529 SELECT
530 imported::text,
531 version,
532 filename
533 FROM gm.schema_revision
534 ORDER BY imported"""
535 elif table_exists(link_obj = link_obj, schema = 'public', table = 'gm_schema_revision'):
536 cmd = u"""
537 SELECT
538 imported::text,
539 version,
540 filename
541 FROM public.gm_schema_revision
542 ORDER BY imported"""
543 else:
544 return []
545
546 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd}])
547 return rows
548
550 rows, idx = run_ro_queries(queries = [{'cmd': u'select CURRENT_USER'}])
551 return rows[0][0]
552
554 """Get the foreign keys pointing to schema.table.column.
555
556 Does not properly work with multi-column FKs.
557 GNUmed doesn't use any, however.
558 """
559 cmd = u"""
560 select
561 %(schema)s as referenced_schema,
562 %(tbl)s as referenced_table,
563 %(col)s as referenced_column,
564 pgc.confkey as referenced_column_list,
565 pgc.conrelid::regclass as referencing_table,
566 pgc.conkey as referencing_column_list,
567 (select attname from pg_attribute where attnum = pgc.conkey[1] and attrelid = pgc.conrelid) as referencing_column
568 from
569 pg_constraint pgc
570 where
571 pgc.contype = 'f'
572 and
573 pgc.confrelid = (
574 select oid from pg_class where relname = %(tbl)s and relnamespace = (
575 select oid from pg_namespace where nspname = %(schema)s
576 )
577 ) and
578 (
579 select attnum
580 from pg_attribute
581 where
582 attrelid = (select oid from pg_class where relname = %(tbl)s and relnamespace = (
583 select oid from pg_namespace where nspname = %(schema)s
584 ))
585 and
586 attname = %(col)s
587 ) = any(pgc.confkey)
588 """
589
590 args = {
591 'schema': schema,
592 'tbl': table,
593 'col': column
594 }
595
596 rows, idx = run_ro_queries (
597 link_obj = link_obj,
598 queries = [
599 {'cmd': cmd, 'args': args}
600 ]
601 )
602
603 return rows
604
605
606 -def get_foreign_key_names(src_schema=None, src_table=None, src_column=None, target_schema=None, target_table=None, target_column=None, link_obj=None):
607
608 args = {
609 'src_schema': src_schema,
610 'src_tbl': src_table,
611 'src_col': src_column,
612 'target_schema': target_schema,
613 'target_tbl': target_table,
614 'target_col': target_column
615 }
616
617 rows, idx = run_ro_queries (
618 link_obj = link_obj,
619 queries = [{'cmd': SQL_foreign_key_name, 'args': args}],
620 get_col_idx = False
621 )
622
623 return rows
624
625
627 """Return child tables of <table>."""
628 cmd = u"""
629 select
630 pgn.nspname as namespace,
631 pgc.relname as table
632 from
633 pg_namespace pgn,
634 pg_class pgc
635 where
636 pgc.relnamespace = pgn.oid
637 and
638 pgc.oid in (
639 select inhrelid from pg_inherits where inhparent = (
640 select oid from pg_class where
641 relnamespace = (select oid from pg_namespace where nspname = %(schema)s) and
642 relname = %(table)s
643 )
644 )"""
645 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': {'schema': schema, 'table': table}}])
646 return rows
647
649 cmd = u"""SELECT EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = %(schema)s)"""
650 args = {'schema': schema}
651 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}])
652 return rows[0][0]
653
655 """Returns false, true."""
656 cmd = u"""
657 select exists (
658 select 1 from information_schema.tables
659 where
660 table_schema = %s and
661 table_name = %s and
662 table_type = 'BASE TABLE'
663 )"""
664 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': (schema, table)}])
665 return rows[0][0]
666
668 if cursor.description is None:
669 _log.error('no result description available: unused cursor or last query did not select rows')
670 return None
671 col_indices = {}
672 col_index = 0
673 for col_desc in cursor.description:
674 col_name = col_desc[0]
675
676
677
678 if col_indices.has_key(col_name):
679 col_name = '%s_%s' % (col_name, col_index)
680 col_indices[col_name] = col_index
681 col_index += 1
682
683 return col_indices
684
685 -def get_col_defs(link_obj=None, schema='public', table=None):
686 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_col_defs, 'args': (schema, table)}])
687 col_names = []
688 col_type = {}
689 for row in rows:
690 col_names.append(row[0])
691
692 if row[1].startswith('_'):
693 col_type[row[0]] = row[1][1:] + '[]'
694 else:
695 col_type[row[0]] = row[1]
696 col_defs = []
697 col_defs.append(col_names)
698 col_defs.append(col_type)
699 return col_defs
700
702 """Return column attributes of table"""
703 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_attributes, 'args': (schema, table)}])
704 cols = []
705 for row in rows:
706 cols.append(row[0])
707 return cols
708
709
710
711
713 tx_file = codecs.open(filename, 'wb', 'utf8')
714 tx_file.write(u'-- GNUmed database string translations exported %s\n' % gmDateTime.pydt_now_here().strftime('%Y-%m-%d %H:%M'))
715 tx_file.write(u'-- - contains translations for each of [%s]\n' % u', '.join(get_translation_languages()))
716 tx_file.write(u'-- - user database language is set to [%s]\n\n' % get_current_user_language())
717 tx_file.write(u'-- Please email this file to <gnumed-devel@gnu.org>.\n')
718 tx_file.write(u'-- ----------------------------------------------------------------------------------------------\n\n')
719 tx_file.write(u'set default_transaction_read_only to off;\n\n')
720 tx_file.write(u"set client_encoding to 'utf-8';\n\n")
721 tx_file.write(u'\\unset ON_ERROR_STOP\n\n')
722
723 cmd = u'SELECT lang, orig, trans FROM i18n.translations ORDER BY lang, orig'
724 rows, idx = run_ro_queries(queries = [{'cmd': cmd}], get_col_idx = False)
725 for row in rows:
726 line = u"select i18n.upd_tx(E'%s', E'%s', E'%s');\n" % (
727 row['lang'].replace("'", "\\'"),
728 row['orig'].replace("'", "\\'"),
729 row['trans'].replace("'", "\\'")
730 )
731 tx_file.write(line)
732 tx_file.write(u'\n')
733
734 tx_file.write(u'\set ON_ERROR_STOP 1\n')
735 tx_file.close()
736
737 return True
738
740 cmd = u'DELETE FROM i18n.translations WHERE lang = %(lang)s AND orig = %(orig)s'
741 args = {'lang': language, 'orig': original}
742 run_rw_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}], return_data = False, end_tx = True)
743 return True
744
745
747 cmd = u'SELECT i18n.upd_tx(%(lang)s, %(orig)s, %(trans)s)'
748 args = {'lang': language, 'orig': original, 'trans': translation}
749 run_rw_queries(queries = [{'cmd': cmd, 'args': args}], return_data = False)
750 return args
751
752
754 rows, idx = run_ro_queries (
755 queries = [{'cmd': u'select distinct lang from i18n.translations'}]
756 )
757 return [ r[0] for r in rows ]
758
759
761
762 args = {'lang': language}
763 _log.debug('language [%s]', language)
764
765 if order_by is None:
766 order_by = u'ORDER BY %s' % order_by
767 else:
768 order_by = u'ORDER BY lang, orig'
769
770 if language is None:
771 cmd = u"""
772 SELECT DISTINCT ON (orig, lang)
773 lang, orig, trans
774 FROM ((
775
776 -- strings stored as translation keys whether translated or not
777 SELECT
778 NULL as lang,
779 ik.orig,
780 NULL AS trans
781 FROM
782 i18n.keys ik
783
784 ) UNION ALL (
785
786 -- already translated strings
787 SELECT
788 it.lang,
789 it.orig,
790 it.trans
791 FROM
792 i18n.translations it
793
794 )) as translatable_strings
795 %s""" % order_by
796 else:
797 cmd = u"""
798 SELECT DISTINCT ON (orig, lang)
799 lang, orig, trans
800 FROM ((
801
802 -- strings stored as translation keys whether translated or not
803 SELECT
804 %%(lang)s as lang,
805 ik.orig,
806 i18n._(ik.orig, %%(lang)s) AS trans
807 FROM
808 i18n.keys ik
809
810 ) UNION ALL (
811
812 -- already translated strings
813 SELECT
814 %%(lang)s as lang,
815 it.orig,
816 i18n._(it.orig, %%(lang)s) AS trans
817 FROM
818 i18n.translations it
819
820 )) AS translatable_strings
821 %s""" % order_by
822
823 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False)
824
825 if rows is None:
826 _log.error('no translatable strings found')
827 else:
828 _log.debug('%s translatable strings found', len(rows))
829
830 return rows
831
832
834 cmd = u'select i18n.get_curr_lang()'
835 rows, idx = run_ro_queries(queries = [{'cmd': cmd}])
836 return rows[0][0]
837
838
840 """Set the user language in the database.
841
842 user = None: current db user
843 language = None: unset
844 """
845 _log.info('setting database language for user [%s] to [%s]', user, language)
846
847 args = {
848 'usr': user,
849 'lang': language
850 }
851
852 if language is None:
853 if user is None:
854 queries = [{'cmd': u'select i18n.unset_curr_lang()'}]
855 else:
856 queries = [{'cmd': u'select i18n.unset_curr_lang(%(usr)s)', 'args': args}]
857 queries.append({'cmd': u'select True'})
858 else:
859 if user is None:
860 queries = [{'cmd': u'select i18n.set_curr_lang(%(lang)s)', 'args': args}]
861 else:
862 queries = [{'cmd': u'select i18n.set_curr_lang(%(lang)s, %(usr)s)', 'args': args}]
863
864 rows, idx = run_rw_queries(queries = queries, return_data = True)
865
866 if not rows[0][0]:
867 _log.error('cannot set database language to [%s] for user [%s]', language, user)
868
869 return rows[0][0]
870
872 """Set the user language in the database.
873
874 - regardless of whether there is any translation available.
875 - only for the current user
876 """
877 _log.info('forcing database language for current db user to [%s]', language)
878
879 run_rw_queries(queries = [{
880 'cmd': u'select i18n.force_curr_lang(%(lang)s)',
881 'args': {'lang': language}
882 }])
883
884
885
886
888 cmd = u'notify "db_maintenance_warning"'
889 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
890
892 cmd = u'notify "db_maintenance_disconnect"'
893 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
894
896 cmd = u'SELECT %(candidate)s::interval'
897 try:
898 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}])
899 return True
900 except:
901 cmd = u'SELECT %(candidate)s::text::interval'
902 try:
903 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}])
904 return True
905 except:
906 return False
907
908
909 -def lock_row(link_obj=None, table=None, pk=None, exclusive=False):
910 """Uses pg_advisory(_shared).
911
912 - locks stack and need one unlock per lock
913 - same connection:
914 - all locks succeed
915 - different connections:
916 - shared + shared succeed
917 - shared + exclusive fail
918 """
919 _log.debug('locking row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
920 if exclusive:
921 cmd = u"""SELECT pg_try_advisory_lock('%s'::regclass::oid::int, %s)""" % (table, pk)
922 else:
923 cmd = u"""SELECT pg_try_advisory_lock_shared('%s'::regclass::oid::int, %s)""" % (table, pk)
924 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd}], get_col_idx = False)
925 if rows[0][0]:
926 return True
927 _log.warning('cannot lock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
928 return False
929
930
931 -def unlock_row(link_obj=None, table=None, pk=None, exclusive=False):
932 """Uses pg_advisory_unlock(_shared).
933
934 - each lock needs one unlock
935 """
936 _log.debug('trying to unlock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
937 if exclusive:
938 cmd = u"SELECT pg_advisory_unlock('%s'::regclass::oid::int, %s)" % (table, pk)
939 else:
940 cmd = u"SELECT pg_advisory_unlock_shared('%s'::regclass::oid::int, %s)" % (table, pk)
941 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd}], get_col_idx = False)
942 if rows[0][0]:
943 return True
944 _log.warning('cannot unlock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
945 return False
946
947
949 """Looks at pk_locks
950
951 - does not take into account locks other than 'advisory', however
952 """
953 cmd = u"""SELECT EXISTS (
954 SELECT 1 FROM pg_locks WHERE
955 classid = '%s'::regclass::oid::int
956 AND
957 objid = %s
958 AND
959 locktype = 'advisory'
960 )""" % (table, pk)
961 rows, idx = run_ro_queries(queries = [{'cmd': cmd}], get_col_idx = False)
962 if rows[0][0]:
963 _log.debug('row is locked: [%s] [%s]', table, pk)
964 return True
965 _log.debug('row is NOT locked: [%s] [%s]', table, pk)
966 return False
967
968
969 -def bytea2file(data_query=None, filename=None, chunk_size=0, data_size=None, data_size_query=None):
970 outfile = file(filename, 'wb')
971 result = bytea2file_object(data_query=data_query, file_obj=outfile, chunk_size=chunk_size, data_size=data_size, data_size_query=data_size_query)
972 outfile.close()
973 return result
974
975 -def bytea2file_object(data_query=None, file_obj=None, chunk_size=0, data_size=None, data_size_query=None):
976 """Store data from a bytea field into a file.
977
978 <data_query>
979 - dict {'cmd': ..., 'args': ...}
980 - 'cmd' must be unicode containing "... substring(data from %(start)s for %(size)s) ..."
981 - 'args' must be a dict
982 - must return one row with one field of type bytea
983 <file>
984 - must be a file like Python object
985 <data_size>
986 - integer of the total size of the expected data or None
987 <data_size_query>
988 - dict {'cmd': ..., 'args': ...}
989 - cmd must be unicode
990 - must return one row with one field with the octet_length() of the data field
991 - used only when <data_size> is None
992 """
993 if data_size == 0:
994 return True
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007 conn = get_raw_connection(readonly=True)
1008
1009 if data_size is None:
1010 rows, idx = run_ro_queries(link_obj = conn, queries = [data_size_query])
1011 data_size = rows[0][0]
1012 if data_size in [None, 0]:
1013 conn.rollback()
1014 return True
1015
1016 max_chunk_size = 1024 * 1024 * 20
1017 if chunk_size == 0:
1018 chunk_size = min(data_size, max_chunk_size)
1019
1020 _log.debug('expecting %s bytes of BYTEA data in chunks of %s bytes', data_size, chunk_size)
1021
1022
1023
1024
1025 needed_chunks, remainder = divmod(data_size, chunk_size)
1026 _log.debug('# of chunks: %s; remainder: %s bytes', needed_chunks, remainder)
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043 for chunk_id in range(needed_chunks):
1044 chunk_start = (chunk_id * chunk_size) + 1
1045 data_query['args']['start'] = chunk_start
1046 data_query['args']['size'] = chunk_size
1047 try:
1048 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query])
1049 except:
1050 _log.error('cannot retrieve chunk [%s/%s], size [%s], try decreasing chunk size' % (chunk_id+1, needed_chunks, chunk_size))
1051 conn.rollback()
1052 raise
1053
1054 file_obj.write(str(rows[0][0]))
1055
1056
1057 if remainder > 0:
1058 chunk_start = (needed_chunks * chunk_size) + 1
1059 data_query['args']['start'] = chunk_start
1060 data_query['args']['size'] = remainder
1061 try:
1062 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query])
1063 except:
1064 _log.error('cannot retrieve remaining [%s] bytes' % remainder)
1065 conn.rollback()
1066 raise
1067
1068 file_obj.write(str(rows[0][0]))
1069
1070 conn.rollback()
1071 return True
1072
1073 -def file2bytea(query=None, filename=None, args=None, conn=None, file_md5=None):
1074 """Store data from a file into a bytea field.
1075
1076 The query must:
1077 - be in unicode
1078 - contain a format spec identifying the row (eg a primary key)
1079 matching <args> if it is an UPDATE
1080 - contain a format spec " <field> = %(data)s::bytea"
1081
1082 The query CAN return the MD5 of the inserted data:
1083 RETURNING md5(<field>) AS md5
1084 in which case it will compare it to the md5
1085 of the file.
1086 """
1087
1088 infile = file(filename, "rb")
1089 data_as_byte_string = infile.read()
1090 infile.close()
1091 if args is None:
1092 args = {}
1093 args['data'] = buffer(data_as_byte_string)
1094 del(data_as_byte_string)
1095
1096
1097 if conn is None:
1098 conn = get_raw_connection(readonly=False)
1099 close_conn = True
1100 else:
1101 close_conn = False
1102
1103 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = (file_md5 is not None))
1104
1105 success_status = True
1106 if file_md5 is None:
1107 conn.commit()
1108 else:
1109 db_md5 = rows[0]['md5']
1110 if file_md5 != db_md5:
1111 conn.rollback()
1112 success_status = False
1113 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5)
1114 else:
1115 conn.commit()
1116 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] <> [DB::%s]', file_md5, db_md5)
1117
1118 if close_conn:
1119 conn.close()
1120
1121 return success_status
1122
1124 """Escape input for use in a PostgreSQL regular expression.
1125
1126 If a fragment comes from user input and is to be used
1127 as a regular expression we need to make sure it doesn't
1128 contain invalid regex patterns such as unbalanced ('s.
1129
1130 <escape_all>
1131 True: try to escape *all* metacharacters
1132 False: only escape those which render the regex invalid
1133 """
1134 return expression.replace (
1135 '(', '\('
1136 ).replace (
1137 ')', '\)'
1138 ).replace (
1139 '[', '\['
1140 ).replace (
1141 '+', '\+'
1142 ).replace (
1143 '.', '\.'
1144 ).replace (
1145 '*', '\*'
1146 )
1147
1148
1149 -def run_ro_queries(link_obj=None, queries=None, verbose=False, return_data=True, get_col_idx=False):
1150 """Run read-only queries.
1151
1152 <queries> must be a list of dicts:
1153 [
1154 {'cmd': <string>, 'args': <dict> or <tuple>},
1155 {...},
1156 ...
1157 ]
1158 """
1159 if isinstance(link_obj, dbapi._psycopg.cursor):
1160 curs = link_obj
1161 curs_close = __noop
1162 tx_rollback = __noop
1163 elif isinstance(link_obj, dbapi._psycopg.connection):
1164 curs = link_obj.cursor()
1165 curs_close = curs.close
1166 tx_rollback = link_obj.rollback
1167 elif link_obj is None:
1168 conn = get_connection(readonly=True, verbose=verbose)
1169 curs = conn.cursor()
1170 curs_close = curs.close
1171 tx_rollback = conn.rollback
1172 else:
1173 raise ValueError('link_obj must be cursor, connection or None but not [%s]' % link_obj)
1174
1175 if verbose:
1176 _log.debug('cursor: %s', curs)
1177
1178 for query in queries:
1179 if type(query['cmd']) is not types.UnicodeType:
1180 print "run_ro_queries(): non-unicode query"
1181 print query['cmd']
1182 try:
1183 args = query['args']
1184 except KeyError:
1185 args = None
1186 try:
1187 curs.execute(query['cmd'], args)
1188 if verbose:
1189 _log.debug('ran query: [%s]', curs.query)
1190 if curs.statusmessage != u'':
1191 _log.debug('PG status message: %s', curs.statusmessage)
1192 _log.debug('cursor description: %s', str(curs.description))
1193 except dbapi.Error as pg_exc:
1194 _log.error('query failed: [%s]', curs.query)
1195 if curs.statusmessage != u'':
1196 _log.error('PG status message: %s', curs.statusmessage)
1197 _log.error('PG error code: %s', pg_exc.pgcode)
1198 if pg_exc.pgerror is not None:
1199 _log.error('PG error message: %s', pg_exc.pgerror.strip().strip(u'\n').strip().strip(u'\n'))
1200 try:
1201 curs_close()
1202 except dbapi.InterfaceError:
1203 _log.exception('cannot close cursor')
1204 tx_rollback()
1205 if pg_exc.pgcode == sql_error_codes.INSUFFICIENT_PRIVILEGE:
1206 details = u'Query: [%s]' % curs.query.strip().strip(u'\n').strip().strip(u'\n')
1207 if curs.statusmessage != u'':
1208 details = u'Status: %s\n%s' % (
1209 curs.statusmessage.strip().strip(u'\n').strip().strip(u'\n'),
1210 details
1211 )
1212 if pg_exc.pgerror is None:
1213 msg = u'[%s]: %s' % (pg_exc.pgcode, pg_exc.pgerror)
1214 else:
1215 msg = u'[%s]: %s' % (pg_exc.pgcode, pg_exc.pgerror.strip().strip(u'\n').strip().strip(u'\n'))
1216 raise gmExceptions.AccessDenied (
1217 msg,
1218 source = u'PostgreSQL',
1219 code = pg_exc.pgcode,
1220 details = details
1221 )
1222 raise
1223 except:
1224 _log.error('query failed: [%s]', curs.query)
1225 if curs.statusmessage != u'':
1226 _log.error('PG status message: %s', curs.statusmessage)
1227 try:
1228 curs_close()
1229 except dbapi.InterfaceError:
1230 _log.exception('cannot close cursor')
1231 tx_rollback()
1232 raise
1233
1234 data = None
1235 col_idx = None
1236 if return_data:
1237 data = curs.fetchall()
1238 if verbose:
1239 _log.debug('last query returned [%s (%s)] rows', curs.rowcount, len(data))
1240 _log.debug('cursor description: %s', str(curs.description))
1241 if get_col_idx:
1242 col_idx = get_col_indices(curs)
1243
1244 curs_close()
1245 tx_rollback()
1246 return (data, col_idx)
1247
1248 -def run_rw_queries(link_obj=None, queries=None, end_tx=False, return_data=None, get_col_idx=False, verbose=False):
1249 """Convenience function for running a transaction
1250 that is supposed to get committed.
1251
1252 <link_obj>
1253 can be either:
1254 - a cursor
1255 - a connection
1256
1257 <queries>
1258 is a list of dicts [{'cmd': <string>, 'args': <dict> or <tuple>)
1259 to be executed as a single transaction, the last
1260 query may usefully return rows (such as a
1261 "SELECT currval('some_sequence')" statement)
1262
1263 <end_tx>
1264 - controls whether the transaction is finalized (eg.
1265 committed/rolled back) or not, this allows the
1266 call to run_rw_queries() to be part of a framing
1267 transaction
1268 - if link_obj is a connection then <end_tx> will
1269 default to False unless it is explicitly set to
1270 True which is taken to mean "yes, you do have full
1271 control over the transaction" in which case the
1272 transaction is properly finalized
1273 - if link_obj is a cursor we CANNOT finalize the
1274 transaction because we would need the connection for that
1275 - if link_obj is None <end_tx> will, of course, always be True
1276
1277 <return_data>
1278 - if true, the returned data will include the rows
1279 the last query selected
1280 - if false, it returns None instead
1281
1282 <get_col_idx>
1283 - if true, the returned data will include a dictionary
1284 mapping field names to column positions
1285 - if false, the returned data returns None instead
1286
1287 method result:
1288 - returns a tuple (data, idx)
1289 - <data>:
1290 * (None, None) if last query did not return rows
1291 * ("fetchall() result", <index>) if last query returned any rows
1292 * for <index> see <get_col_idx>
1293 """
1294 if isinstance(link_obj, dbapi._psycopg.cursor):
1295 conn_close = __noop
1296 conn_commit = __noop
1297 tx_rollback = __noop
1298 curs = link_obj
1299 curs_close = __noop
1300 elif isinstance(link_obj, dbapi._psycopg.connection):
1301 conn_close = __noop
1302 if end_tx:
1303 conn_commit = link_obj.commit
1304 tx_rollback = link_obj.rollback
1305 else:
1306 conn_commit = __noop
1307 tx_rollback = __noop
1308 curs = link_obj.cursor()
1309 curs_close = curs.close
1310 elif link_obj is None:
1311 conn = get_connection(readonly=False)
1312 conn_close = conn.close
1313 conn_commit = conn.commit
1314 tx_rollback = conn.rollback
1315 curs = conn.cursor()
1316 curs_close = curs.close
1317 else:
1318 raise ValueError('link_obj must be cursor, connection or None and not [%s]' % link_obj)
1319
1320 for query in queries:
1321 if type(query['cmd']) is not types.UnicodeType:
1322 print "run_rw_queries(): non-unicode query"
1323 print query['cmd']
1324 try:
1325 args = query['args']
1326 except KeyError:
1327 args = None
1328 try:
1329 curs.execute(query['cmd'], args)
1330 except dbapi.Error as pg_exc:
1331 _log.error('RW query failed: [%s]', curs.query)
1332 if curs.statusmessage != u'':
1333 _log.error('PG status message: %s', curs.statusmessage)
1334 _log.error('PG error code: %s', pg_exc.pgcode)
1335 if pg_exc.pgerror is not None:
1336 _log.error('PG error message: %s', pg_exc.pgerror.strip().strip(u'\n').strip().strip(u'\n'))
1337 try:
1338 curs_close()
1339 tx_rollback()
1340 conn_close()
1341 except dbapi.InterfaceError:
1342 _log.exception('cannot cleanup')
1343 if pg_exc.pgcode == sql_error_codes.INSUFFICIENT_PRIVILEGE:
1344 details = u'Query: [%s]' % curs.query.strip().strip(u'\n').strip().strip(u'\n')
1345 if curs.statusmessage != u'':
1346 details = u'Status: %s\n%s' % (
1347 curs.statusmessage.strip().strip(u'\n').strip().strip(u'\n'),
1348 details
1349 )
1350 if pg_exc.pgerror is None:
1351 msg = u'[%s]: %s' % (pg_exc.pgcode, pg_exc.pgerror)
1352 else:
1353 msg = u'[%s]: %s' % (pg_exc.pgcode, pg_exc.pgerror.strip().strip(u'\n').strip().strip(u'\n'))
1354 raise gmExceptions.AccessDenied (
1355 msg,
1356 source = u'PostgreSQL',
1357 code = pg_exc.pgcode,
1358 details = details
1359 )
1360 raise
1361 except:
1362 _log.exception('error running RW query')
1363 gmLog2.log_stack_trace()
1364 try:
1365 curs_close()
1366 tx_rollback()
1367 conn_close()
1368 except dbapi.InterfaceError:
1369 _log.exception('cannot cleanup')
1370 raise
1371 raise
1372
1373 data = None
1374 col_idx = None
1375 if return_data:
1376 try:
1377 data = curs.fetchall()
1378 except:
1379 _log.exception('error fetching data from RW query')
1380 gmLog2.log_stack_trace()
1381 try:
1382 curs_close()
1383 tx_rollback()
1384 conn_close()
1385 except dbapi.InterfaceError:
1386 _log.exception('cannot cleanup')
1387 raise
1388 raise
1389 if get_col_idx:
1390 col_idx = get_col_indices(curs)
1391
1392 curs_close()
1393 conn_commit()
1394 conn_close()
1395
1396 return (data, col_idx)
1397
1398 -def run_insert(link_obj=None, schema=None, table=None, values=None, returning=None, end_tx=False, get_col_idx=False, verbose=False):
1399 """Generates SQL for an INSERT query.
1400
1401 values: dict of values keyed by field to insert them into
1402 """
1403 if schema is None:
1404 schema = u'public'
1405
1406 fields = values.keys()
1407 val_snippets = []
1408 for field in fields:
1409 val_snippets.append(u'%%(%s)s' % field)
1410
1411 if returning is None:
1412 returning = u''
1413 return_data = False
1414 else:
1415 returning = u'\n\tRETURNING\n\t\t%s' % u', '.join(returning)
1416 return_data = True
1417
1418 cmd = u"""\nINSERT INTO %s.%s (
1419 %s
1420 ) VALUES (
1421 %s
1422 )%s""" % (
1423 schema,
1424 table,
1425 u',\n\t\t'.join(fields),
1426 u',\n\t\t'.join(val_snippets),
1427 returning
1428 )
1429
1430 _log.debug(u'running SQL: >>>%s<<<', cmd)
1431
1432 return run_rw_queries (
1433 link_obj = link_obj,
1434 queries = [{'cmd': cmd, 'args': values}],
1435 end_tx = end_tx,
1436 return_data = return_data,
1437 get_col_idx = get_col_idx,
1438 verbose = verbose
1439 )
1440
1441
1442
1444 """
1445 GNUmed database connection pool.
1446
1447 Extends psycopg2's PersistentConnectionPool with
1448 a custom _connect() function. Supports one connection
1449 per thread - which also ties it to one particular DSN.
1450 """
1451
1453
1454 conn = get_raw_connection(dsn = self._kwargs['dsn'], verbose = self._kwargs['verbose'], readonly=True)
1455
1456 conn.original_close = conn.close
1457 conn.close = _raise_exception_on_ro_conn_close
1458
1459 if key is not None:
1460 self._used[key] = conn
1461 self._rused[id(conn)] = key
1462 else:
1463 self._pool.append(conn)
1464
1465 return conn
1466
1468 for conn_key in self._used.keys():
1469 _log.debug('closing pooled database connection, pool key: %s, backend PID: %s', conn_key, self._used[conn_key].get_backend_pid())
1470 self._used[conn_key].original_close()
1471
1473 """Get a raw, unadorned connection.
1474
1475 - this will not set any parameters such as encoding, timezone, datestyle
1476 - the only requirement is a valid DSN
1477 - hence it can be used for "service" connections
1478 for verifying encodings etc
1479 """
1480
1481 if dsn is None:
1482 dsn = get_default_dsn()
1483
1484 if u'host=salaam.homeunix' in dsn:
1485 raise ValueError('The public database is not hosted by <salaam.homeunix.com> anymore.\n\nPlease point your configuration files to <publicdb.gnumed.de>.')
1486
1487 try:
1488 conn = dbapi.connect(dsn=dsn, connection_factory=psycopg2.extras.DictConnection)
1489 except dbapi.OperationalError, e:
1490
1491 t, v, tb = sys.exc_info()
1492 try:
1493 msg = e.args[0]
1494 except (AttributeError, IndexError, TypeError):
1495 raise
1496
1497 msg = unicode(msg, gmI18N.get_encoding(), 'replace')
1498
1499 if msg.find('fe_sendauth') != -1:
1500 raise cAuthenticationError, (dsn, msg), tb
1501
1502 if regex.search('user ".*" does not exist', msg) is not None:
1503 raise cAuthenticationError, (dsn, msg), tb
1504
1505 if msg.find('uthenti') != -1:
1506 raise cAuthenticationError, (dsn, msg), tb
1507
1508 raise
1509
1510 _log.debug('new database connection, backend PID: %s, readonly: %s', conn.get_backend_pid(), readonly)
1511
1512
1513 global postgresql_version
1514 if postgresql_version is None:
1515 curs = conn.cursor()
1516 curs.execute("""
1517 SELECT
1518 substring(setting, E'^\\\\d{1,2}\\\\.\\\\d{1,2}')::numeric AS version
1519 FROM
1520 pg_settings
1521 WHERE
1522 name = 'server_version'
1523 """)
1524 postgresql_version = curs.fetchone()['version']
1525 _log.info('PostgreSQL version (numeric): %s' % postgresql_version)
1526 try:
1527 curs.execute("SELECT pg_size_pretty(pg_database_size(current_database()))")
1528 _log.info('database size: %s', curs.fetchone()[0])
1529 except:
1530 pass
1531 if verbose:
1532 __log_PG_settings(curs=curs)
1533 curs.close()
1534 conn.commit()
1535
1536 if _default_client_timezone is None:
1537 __detect_client_timezone(conn = conn)
1538
1539 curs = conn.cursor()
1540
1541
1542 if readonly:
1543 _log.debug('access mode [READ ONLY]')
1544 cmd = 'set session characteristics as transaction READ ONLY'
1545 curs.execute(cmd)
1546 cmd = 'set default_transaction_read_only to on'
1547 curs.execute(cmd)
1548 else:
1549 _log.debug('access mode [READ WRITE]')
1550 cmd = 'set session characteristics as transaction READ WRITE'
1551 curs.execute(cmd)
1552 cmd = 'set default_transaction_read_only to off'
1553 curs.execute(cmd)
1554
1555 curs.close()
1556 conn.commit()
1557
1558 conn.is_decorated = False
1559
1560 return conn
1561
1562 -def get_connection(dsn=None, readonly=True, encoding=None, verbose=False, pooled=True):
1563 """Get a new connection.
1564
1565 This assumes the locale system has been initialized
1566 unless an encoding is specified.
1567 """
1568
1569
1570 if pooled and readonly and (dsn is None):
1571 global __ro_conn_pool
1572 if __ro_conn_pool is None:
1573 __ro_conn_pool = cConnectionPool (
1574 minconn = 1,
1575 maxconn = 2,
1576 dsn = dsn,
1577 verbose = verbose
1578 )
1579 conn = __ro_conn_pool.getconn()
1580 else:
1581 conn = get_raw_connection(dsn=dsn, verbose=verbose, readonly=False)
1582
1583 if conn.is_decorated:
1584 return conn
1585
1586 if encoding is None:
1587 encoding = _default_client_encoding
1588 if encoding is None:
1589 encoding = gmI18N.get_encoding()
1590 _log.warning('client encoding not specified')
1591 _log.warning('the string encoding currently set in the active locale is used: [%s]' % encoding)
1592 _log.warning('for this to work properly the application MUST have called locale.setlocale() before')
1593
1594
1595
1596 try:
1597 conn.set_client_encoding(encoding)
1598 except dbapi.OperationalError:
1599 t, v, tb = sys.exc_info()
1600 if str(v).find("can't set encoding to") != -1:
1601 raise cEncodingError, (encoding, v), tb
1602 raise
1603
1604
1605 if readonly:
1606
1607 iso_level = u'read committed'
1608 else:
1609 conn.set_isolation_level(psycopg2.extensions.ISOLATION_LEVEL_SERIALIZABLE)
1610 iso_level = u'serializable'
1611
1612 _log.debug('client string encoding [%s], isolation level [%s], time zone [%s]', encoding, iso_level, _default_client_timezone)
1613
1614 curs = conn.cursor()
1615
1616
1617 curs.execute(_sql_set_timezone, [_default_client_timezone])
1618
1619 conn.commit()
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638 curs.close()
1639 conn.commit()
1640
1641 conn.is_decorated = True
1642
1643 return conn
1644
1649
1650
1651
1654
1656 raise TypeError(u'close() called on read-only connection')
1657
1659 run_insert (
1660 schema = u'gm',
1661 table = u'access_log',
1662 values = {u'user_action': action},
1663 end_tx = True
1664 )
1665
1667 """Check server time and local time to be within
1668 the given tolerance of each other.
1669
1670 tolerance: seconds
1671 """
1672 _log.debug('maximum skew tolerance (seconds): %s', tolerance)
1673
1674 cmd = u"SELECT now() at time zone 'UTC'"
1675 conn = get_raw_connection(readonly=True)
1676 curs = conn.cursor()
1677
1678 start = time.time()
1679 rows, idx = run_ro_queries(link_obj = curs, queries = [{'cmd': cmd}])
1680 end = time.time()
1681 client_now_as_utc = pydt.datetime.utcnow()
1682
1683 curs.close()
1684 conn.commit()
1685
1686 server_now_as_utc = rows[0][0]
1687 query_duration = end - start
1688 _log.info('server "now" (UTC): %s', server_now_as_utc)
1689 _log.info('client "now" (UTC): %s', client_now_as_utc)
1690 _log.debug('wire roundtrip (seconds): %s', query_duration)
1691
1692 if query_duration > tolerance:
1693 _log.error('useless to check client/server time skew, wire roundtrip > tolerance')
1694 return False
1695
1696 if server_now_as_utc > client_now_as_utc:
1697 real_skew = server_now_as_utc - client_now_as_utc
1698 else:
1699 real_skew = client_now_as_utc - server_now_as_utc
1700
1701 _log.debug('client/server time skew: %s', real_skew)
1702
1703 if real_skew > pydt.timedelta(seconds = tolerance):
1704 _log.error('client/server time skew > tolerance')
1705 return False
1706
1707 return True
1708
1710 """Checks database settings.
1711
1712 returns (status, message)
1713 status:
1714 0: no problem
1715 1: non-fatal problem
1716 2: fatal problem
1717 """
1718 _log.debug('checking database settings')
1719
1720 conn = get_connection()
1721
1722
1723 global postgresql_version_string
1724 if postgresql_version_string is None:
1725 curs = conn.cursor()
1726 curs.execute('SELECT version()')
1727 postgresql_version_string = curs.fetchone()['version']
1728 curs.close()
1729 _log.info('PostgreSQL version (string): "%s"' % postgresql_version_string)
1730
1731 options2check = {
1732
1733 u'allow_system_table_mods': [u'off', u'system breakage', False],
1734 u'check_function_bodies': [u'on', u'suboptimal error detection', False],
1735 u'datestyle': [u'ISO', u'faulty timestamp parsing', True],
1736 u'default_transaction_isolation': [u'read committed', u'faulty database reads', True],
1737 u'default_transaction_read_only': [u'on', u'accidental database writes', False],
1738 u'fsync': [u'on', u'data loss/corruption', True],
1739 u'full_page_writes': [u'on', u'data loss/corruption', False],
1740 u'lc_messages': [u'C', u'suboptimal error detection', False],
1741 u'password_encryption': [u'on', u'breach of confidentiality', False],
1742
1743 u'synchronous_commit': [u'on', u'data loss/corruption', False],
1744 u'sql_inheritance': [u'on', u'query breakage, data loss/corruption', True],
1745 u'ignore_checksum_failure': [u'off', u'data loss/corruption', False]
1746 }
1747
1748 from Gnumed.pycommon import gmCfg2
1749 _cfg = gmCfg2.gmCfgData()
1750 if _cfg.get(option = u'hipaa'):
1751 options2check[u'log_connections'] = [u'on', u'non-compliance with HIPAA', True]
1752 options2check[u'log_disconnections'] = [u'on', u'non-compliance with HIPAA', True]
1753 else:
1754 options2check[u'log_connections'] = [u'on', u'non-compliance with HIPAA', None]
1755 options2check[u'log_disconnections'] = [u'on', u'non-compliance with HIPAA', None]
1756
1757 cmd = u"SELECT name, setting from pg_settings where name in %(settings)s"
1758 rows, idx = run_ro_queries (
1759 link_obj = conn,
1760 queries = [{'cmd': cmd, 'args': {'settings': tuple(options2check.keys())}}],
1761 get_col_idx = False
1762 )
1763
1764 found_error = False
1765 found_problem = False
1766 msg = []
1767 for row in rows:
1768 option = row['name']
1769 value_found = row['setting']
1770 value_expected = options2check[option][0]
1771 risk = options2check[option][1]
1772 fatal_setting = options2check[option][2]
1773 if value_found != value_expected:
1774 if fatal_setting is True:
1775 found_error = True
1776 elif fatal_setting is False:
1777 found_problem = True
1778 elif fatal_setting is None:
1779 pass
1780 else:
1781 _log.error(options2check[option])
1782 raise ValueError(u'invalid database configuration sanity check')
1783 msg.append(_(' option [%s]: %s') % (option, value_found))
1784 msg.append(_(' risk: %s') % risk)
1785 _log.warning('PG option [%s] set to [%s], expected [%s], risk: <%s>' % (option, value_found, value_expected, risk))
1786
1787 if found_error:
1788 return 2, u'\n'.join(msg)
1789
1790 if found_problem:
1791 return 1, u'\n'.join(msg)
1792
1793 return 0, u''
1794
1796
1797
1798
1799 try:
1800 curs.execute(u'show all')
1801 except:
1802 _log.exception(u'cannot log PG settings (>>>show all<<< failed)')
1803 return False
1804 settings = curs.fetchall()
1805 if settings is None:
1806 _log.error(u'cannot log PG settings (>>>show all<<< did not return rows)')
1807 return False
1808 for setting in settings:
1809 _log.debug(u'PG option [%s]: %s', setting[0], setting[1])
1810 return True
1811
1813
1814 try:
1815 msg = exc.args[0]
1816 except (AttributeError, IndexError, TypeError):
1817 return u'cannot extract message from exception'
1818
1819 return unicode(msg, gmI18N.get_encoding(), 'replace')
1820
1822
1823 - def __init__(self, dsn=None, prev_val=None):
1824 self.dsn = dsn
1825 self.prev_val = prev_val
1826
1828 _log.warning('%s.__str__() called', self.__class__.__name__)
1829 tmp = u'PostgreSQL: %sDSN: %s' % (self.prev_val, self.dsn)
1830 _log.error(tmp)
1831 return tmp.encode(gmI18N.get_encoding(), 'replace')
1832
1834 return u'PostgreSQL: %sDSN: %s' % (self.prev_val, self.dsn)
1835
1836
1837
1838
1840
1841 - def __init__(self, encoding=None, prev_val=None):
1842 self.encoding = encoding
1843 self.prev_val = prev_val
1844
1846 _log.warning('%s.__str__() called', self.__class__.__name__)
1847 return 'PostgreSQL: %s\nencoding: %s' % (self.prev_val.encode(gmI18N.get_encoding(), 'replace'), self.encoding.encode(gmI18N.get_encoding(), 'replace'))
1848
1850 return u'PostgreSQL: %s\nencoding: %s' % (self.prev_val, self.encoding)
1851
1852
1853
1854
1855
1857
1859 if dt.tzinfo is None:
1860 raise ValueError(u'datetime.datetime instance is lacking a time zone: [%s]' % _timestamp_template % dt.isoformat())
1861 self.__dt = dt
1862
1865
1866
1867
1868
1869
1870
1871
1872
1873
1874
1875
1876
1877
1878
1879
1880
1881
1882
1883
1884
1885
1886
1887
1888
1889
1890
1891
1892
1893
1894 psycopg2.extensions.register_type(psycopg2.extensions.UNICODE)
1895 psycopg2.extensions.register_type(psycopg2._psycopg.UNICODEARRAY)
1896
1897
1898
1899 psycopg2.extensions.register_adapter(pydt.datetime, cAdapterPyDateTime)
1900
1901
1902
1903
1904
1905 if __name__ == "__main__":
1906
1907 if len(sys.argv) < 2:
1908 sys.exit()
1909
1910 if sys.argv[1] != 'test':
1911 sys.exit()
1912
1913 logging.basicConfig(level=logging.DEBUG)
1914
1916 run_rw_queries(queries = [
1917 {'cmd': u'create table test_bytea (data bytea)'}
1918 ])
1919
1920 cmd = u'insert into test_bytea values (%(data)s::bytea)'
1921 try:
1922 file2bytea(query = cmd, filename = sys.argv[2])
1923 except:
1924 _log.exception('error')
1925
1926 run_rw_queries(queries = [
1927 {'cmd': u'drop table test_bytea'}
1928 ])
1929
1931 print "testing get_connection()"
1932
1933 dsn = 'foo'
1934 try:
1935 conn = get_connection(dsn=dsn)
1936 except dbapi.OperationalError, e:
1937 print "SUCCESS: get_connection(%s) failed as expected" % dsn
1938 t, v = sys.exc_info()[:2]
1939 print ' ', t
1940 print ' ', v
1941
1942 dsn = 'dbname=gnumed_v9'
1943 try:
1944 conn = get_connection(dsn=dsn)
1945 except cAuthenticationError:
1946 print "SUCCESS: get_connection(%s) failed as expected" % dsn
1947 t, v = sys.exc_info()[:2]
1948 print ' ', t
1949 print ' ', v
1950
1951 dsn = 'dbname=gnumed_v9 user=abc'
1952 try:
1953 conn = get_connection(dsn=dsn)
1954 except cAuthenticationError:
1955 print "SUCCESS: get_connection(%s) failed as expected" % dsn
1956 t, v = sys.exc_info()[:2]
1957 print ' ', t
1958 print ' ', v
1959
1960 dsn = 'dbname=gnumed_v9 user=any-doc'
1961 try:
1962 conn = get_connection(dsn=dsn)
1963 except cAuthenticationError:
1964 print "SUCCESS: get_connection(%s) failed as expected" % dsn
1965 t, v = sys.exc_info()[:2]
1966 print ' ', t
1967 print ' ', v
1968
1969 dsn = 'dbname=gnumed_v9 user=any-doc password=abc'
1970 try:
1971 conn = get_connection(dsn=dsn)
1972 except cAuthenticationError:
1973 print "SUCCESS: get_connection(%s) failed as expected" % dsn
1974 t, v = sys.exc_info()[:2]
1975 print ' ', t
1976 print ' ', v
1977
1978 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc'
1979 conn = get_connection(dsn=dsn, readonly=True)
1980
1981 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc'
1982 conn = get_connection(dsn=dsn, readonly=False)
1983
1984 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc'
1985 encoding = 'foo'
1986 try:
1987 conn = get_connection(dsn=dsn, encoding=encoding)
1988 except cEncodingError:
1989 print "SUCCESS: get_connection(%s, %s) failed as expected" % (dsn, encoding)
1990 t, v = sys.exc_info()[:2]
1991 print ' ', t
1992 print ' ', v
1993
1995 print "testing exceptions"
1996
1997 try:
1998 raise cAuthenticationError('no dsn', 'no previous exception')
1999 except cAuthenticationError:
2000 t, v, tb = sys.exc_info()
2001 print t
2002 print v
2003 print tb
2004
2005 try:
2006 raise cEncodingError('no dsn', 'no previous exception')
2007 except cEncodingError:
2008 t, v, tb = sys.exc_info()
2009 print t
2010 print v
2011 print tb
2012
2014 print "testing run_ro_queries()"
2015
2016 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc'
2017 conn = get_connection(dsn, readonly=True)
2018
2019 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': u'SELECT version()'}], return_data=True, get_col_idx=True, verbose=True)
2020 print data
2021 print idx
2022 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': u'SELECT 1'}], return_data=True, get_col_idx=True)
2023 print data
2024 print idx
2025
2026 curs = conn.cursor()
2027
2028 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': u'SELECT version()'}], return_data=True, get_col_idx=True, verbose=True)
2029 print data
2030 print idx
2031
2032 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': u'SELECT 1'}], return_data=True, get_col_idx=True, verbose=True)
2033 print data
2034 print idx
2035
2036 try:
2037 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': u'selec 1'}], return_data=True, get_col_idx=True, verbose=True)
2038 print data
2039 print idx
2040 except psycopg2.ProgrammingError:
2041 print 'SUCCESS: run_ro_queries("selec 1") failed as expected'
2042 t, v = sys.exc_info()[:2]
2043 print ' ', t
2044 print ' ', v
2045
2046 curs.close()
2047
2052
2054 print "testing set_default_client_encoding()"
2055
2056 enc = 'foo'
2057 try:
2058 set_default_client_encoding(enc)
2059 print "SUCCESS: encoding [%s] worked" % enc
2060 except ValueError:
2061 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc
2062 t, v = sys.exc_info()[:2]
2063 print ' ', t
2064 print ' ', v
2065
2066 enc = ''
2067 try:
2068 set_default_client_encoding(enc)
2069 print "SUCCESS: encoding [%s] worked" % enc
2070 except ValueError:
2071 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc
2072 t, v = sys.exc_info()[:2]
2073 print ' ', t
2074 print ' ', v
2075
2076 enc = 'latin1'
2077 try:
2078 set_default_client_encoding(enc)
2079 print "SUCCESS: encoding [%s] worked" % enc
2080 except ValueError:
2081 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc
2082 t, v = sys.exc_info()[:2]
2083 print ' ', t
2084 print ' ', v
2085
2086 enc = 'utf8'
2087 try:
2088 set_default_client_encoding(enc)
2089 print "SUCCESS: encoding [%s] worked" % enc
2090 except ValueError:
2091 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc
2092 t, v = sys.exc_info()[:2]
2093 print ' ', t
2094 print ' ', v
2095
2096 enc = 'unicode'
2097 try:
2098 set_default_client_encoding(enc)
2099 print "SUCCESS: encoding [%s] worked" % enc
2100 except ValueError:
2101 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc
2102 t, v = sys.exc_info()[:2]
2103 print ' ', t
2104 print ' ', v
2105
2106 enc = 'UNICODE'
2107 try:
2108 set_default_client_encoding(enc)
2109 print "SUCCESS: encoding [%s] worked" % enc
2110 except ValueError:
2111 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc
2112 t, v = sys.exc_info()[:2]
2113 print ' ', t
2114 print ' ', v
2115
2124
2126 dsn = get_default_dsn()
2127 conn = get_connection(dsn, readonly=True)
2128 curs = conn.cursor()
2129 curs.execute('SELECT * from clin.clin_narrative where narrative = %s', ['a'])
2130
2132 tests = [
2133 ['(', '\\(']
2134 , ['[', '\\[']
2135 , [')', '\\)']
2136 ]
2137 for test in tests:
2138 result = sanitize_pg_regex(test[0])
2139 if result != test[1]:
2140 print 'ERROR: sanitize_pg_regex(%s) returned "%s", expected "%s"' % (test[0], result, test[1])
2141
2143 status = True
2144 tests = [
2145 [None, True],
2146 [1, True],
2147 ['1', True],
2148 ['abc', False]
2149 ]
2150
2151 if not is_pg_interval():
2152 print 'ERROR: is_pg_interval() returned "False", expected "True"'
2153 status = False
2154
2155 for test in tests:
2156 result = is_pg_interval(test[0])
2157 if result != test[1]:
2158 print 'ERROR: is_pg_interval(%s) returned "%s", expected "%s"' % (test[0], result, test[1])
2159 status = False
2160
2161 return status
2162
2165
2167 for row in get_foreign_keys2column (
2168 schema = u'dem',
2169 table = u'identity',
2170 column = u'pk'
2171 ):
2172 print '%s.%s references %s.%s.%s' % (
2173 row['referencing_table'],
2174 row['referencing_column'],
2175 row['referenced_schema'],
2176 row['referenced_table'],
2177 row['referenced_column']
2178 )
2179
2181
2182 tests = [
2183
2184 [None, 'de_DE', True],
2185 [None, 'lang_w/o_tx', False],
2186 [None, None, True],
2187
2188 ['any-doc', 'de_DE', True],
2189 ['any-doc', 'lang_w/o_tx', False],
2190 ['any-doc', None, True],
2191
2192 ['invalid user', 'de_DE', None],
2193 ['invalid user', 'lang_w/o_tx', False],
2194 ['invalid user', None, True]
2195 ]
2196 for test in tests:
2197 try:
2198 result = set_user_language(user = test[0], language = test[1])
2199 if result != test[2]:
2200 print "test:", test
2201 print "result:", result, "expected:", test[2]
2202 except psycopg2.IntegrityError, e:
2203 if test[2] is None:
2204 continue
2205 print "test:", test
2206 print "expected exception"
2207 print "result:", e
2208
2210 for line in get_schema_revision_history():
2211 print u' - '.join(line)
2212
2214 gmDateTime.init()
2215 args = {'dt': gmDateTime.pydt_max_here()}
2216 cmd = u"SELECT %(dt)s"
2217
2218
2219
2220 cmd = u"""
2221 SELECT to_timestamp (foofoo,'YYMMDD.HH24MI') FROM (
2222 SELECT REGEXP_REPLACE (
2223 't1.130729.0902.tif', -- string
2224 E'(.1)\.([0-9\.]+)(\.tif)', -- pattern
2225 E'\\\\2' -- replacement
2226 ) AS foofoo
2227 ) AS foo"""
2228 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False)
2229 print rows
2230 print rows[0]
2231 print rows[0][0]
2232
2235
2237 row_is_locked(table = 'dem.identity', pk = 12)
2238
2239 print "1st connection:"
2240 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2241 print " 1st shared lock succeeded:", lock_row(table = 'dem.identity', pk = 12, exclusive = False)
2242 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2243
2244 print " 2nd shared lock should succeed:", lock_row(table = 'dem.identity', pk = 12, exclusive = False)
2245 print " `-> unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = False)
2246 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2247 print " exclusive lock should succeed:", lock_row(table = 'dem.identity', pk = 12, exclusive = True)
2248 print " `-> unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = True)
2249 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2250
2251 print "2nd connection:"
2252 conn = get_raw_connection(readonly=True)
2253 print " shared lock should succeed:", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)
2254 print " `-> unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)
2255 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2256 print " exclusive lock succeeded ?", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = True), "(should fail)"
2257 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2258
2259 print "1st connection:"
2260 print " unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = False)
2261 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2262
2263 print "2nd connection:"
2264 print " exclusive lock should succeed", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = True)
2265 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2266 print " shared lock should succeed:", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)
2267 print " `-> unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)
2268 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2269 print " unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)
2270 print " locked:", row_is_locked(table = 'dem.identity', pk = 12)
2271
2272 conn.close()
2273
2275 print get_foreign_key_names (
2276 src_schema = 'dem',
2277 src_table = 'names',
2278 src_column = 'id_identity',
2279 target_schema = 'dem',
2280 target_table = 'identity',
2281 target_column = 'pk'
2282 )
2283
2284
2285
2286
2287
2288
2289
2290
2291
2292
2293
2294
2295
2296
2297
2298
2299
2300
2301
2302
2303 test_row_locks()
2304
2305
2306