Package Gnumed :: Package pycommon :: Module gmPG2
[frames] | no frames]

Source Code for Module Gnumed.pycommon.gmPG2

   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  __version__ = "$Revision: 1.127 $" 
  15  __author__  = "K.Hilbert <Karsten.Hilbert@gmx.net>" 
  16  __license__ = 'GPL (details at http://www.gnu.org)' 
  17   
  18  ### imports ### 
  19  # stdlib 
  20  import time, locale, sys, re as regex, os, codecs, types, datetime as pydt, logging 
  21   
  22  # GNUmed 
  23  if __name__ == '__main__': 
  24          sys.path.insert(0, '../../') 
  25  from Gnumed.pycommon import gmLoginInfo, gmExceptions, gmDateTime, gmBorg, gmI18N, gmLog2 
  26   
  27  _log = logging.getLogger('gm.db') 
  28  _log.info(__version__) 
  29   
  30  # 3rd party 
  31  try: 
  32          import psycopg2 as dbapi 
  33  except ImportError: 
  34          _log.exception("Python database adapter psycopg2 not found.") 
  35          print "CRITICAL ERROR: Cannot find module psycopg2 for connecting to the database server." 
  36          raise 
  37  ### imports ### 
  38   
  39   
  40  _log.info('psycopg2 version: %s' % dbapi.__version__) 
  41  _log.info('PostgreSQL via DB-API module "%s": API level %s, thread safety %s, parameter style "%s"' % (dbapi, dbapi.apilevel, dbapi.threadsafety, dbapi.paramstyle)) 
  42  if not (float(dbapi.apilevel) >= 2.0): 
  43          raise ImportError('gmPG2: supported DB-API level too low') 
  44  if not (dbapi.threadsafety > 0): 
  45          raise ImportError('gmPG2: lacking minimum thread safety in psycopg2') 
  46  if not (dbapi.paramstyle == 'pyformat'): 
  47          raise ImportError('gmPG2: lacking pyformat (%%(<name>)s style) placeholder support in psycopg2') 
  48  try: 
  49          dbapi.__version__.index('dt') 
  50  except ValueError: 
  51          raise ImportError('gmPG2: lacking datetime support in psycopg2') 
  52  try: 
  53          dbapi.__version__.index('ext') 
  54  except ValueError: 
  55          raise ImportError('gmPG2: lacking extensions support in psycopg2') 
  56  try: 
  57          dbapi.__version__.index('pq3') 
  58  except ValueError: 
  59          raise ImportError('gmPG2: lacking v3 backend protocol support in psycopg2') 
  60   
  61  import psycopg2.extras 
  62  import psycopg2.extensions 
  63  import psycopg2.pool 
  64  import psycopg2.errorcodes as sql_error_codes 
  65   
  66  # ======================================================================= 
  67  _default_client_encoding = 'UTF8' 
  68  _log.info('assuming default client encoding of [%s]' % _default_client_encoding) 
  69   
  70  # things timezone 
  71  _default_client_timezone = None                 # default time zone for connections 
  72  _sql_set_timezone = None 
  73  _timestamp_template = "cast('%s' as timestamp with time zone)"          # MUST NOT be uniocde or else getquoted will not work 
  74  FixedOffsetTimezone = dbapi.tz.FixedOffsetTimezone 
  75   
  76  _default_dsn = None 
  77  _default_login = None 
  78   
  79  postgresql_version_string = None 
  80  postgresql_version = None                       # accuracy: major.minor 
  81   
  82  __ro_conn_pool = None 
  83   
  84  # ======================================================================= 
  85  # global data 
  86  # ======================================================================= 
  87   
  88  known_schema_hashes = { 
  89          'devel': 'not released, testing only', 
  90          'v2': 'b09d50d7ed3f91ddf4c4ddb8ea507720', 
  91          'v3': 'e73718eaf230d8f1d2d01afa8462e176', 
  92          'v4': '4428ccf2e54c289136819e701bb095ea', 
  93          'v5': '7e7b093af57aea48c288e76632a382e5',       # ... old (v1) style hashes 
  94          'v6': '90e2026ac2efd236da9c8608b8685b2d',       # new (v2) style hashes ... 
  95          'v7': '6c9f6d3981483f8e9433df99d1947b27', 
  96          'v8': '89b13a7af83337c3aad153b717e52360', 
  97          'v9': '641a9b2be3c378ffc2bb2f0b1c9f051d', 
  98          'v10': '7ef42a8fb2bd929a2cdd0c63864b4e8a', 
  99          'v11': '03042ae24f3f92877d986fb0a6184d76', 
 100          'v12': '06183a6616db62257e22814007a8ed07', 
 101          'v13': 'fab7c1ae408a6530c47f9b5111a0841e' 
 102  } 
 103   
 104  map_schema_hash2version = { 
 105          'b09d50d7ed3f91ddf4c4ddb8ea507720': 'v2', 
 106          'e73718eaf230d8f1d2d01afa8462e176': 'v3', 
 107          '4428ccf2e54c289136819e701bb095ea': 'v4', 
 108          '7e7b093af57aea48c288e76632a382e5': 'v5', 
 109          '90e2026ac2efd236da9c8608b8685b2d': 'v6', 
 110          '6c9f6d3981483f8e9433df99d1947b27': 'v7', 
 111          '89b13a7af83337c3aad153b717e52360': 'v8', 
 112          '641a9b2be3c378ffc2bb2f0b1c9f051d': 'v9', 
 113          '7ef42a8fb2bd929a2cdd0c63864b4e8a': 'v10', 
 114          '03042ae24f3f92877d986fb0a6184d76': 'v11', 
 115          '06183a6616db62257e22814007a8ed07': 'v12', 
 116          'fab7c1ae408a6530c47f9b5111a0841e': 'v13' 
 117  } 
 118   
 119  map_client_branch2required_db_version = { 
 120          u'GIT tree': u'devel', 
 121          u'0.3': u'v9', 
 122          u'0.4': u'v10', 
 123          u'0.5': u'v11', 
 124          u'0.6': u'v12', 
 125          u'0.7': u'v13' 
 126  } 
 127   
 128  # get columns and data types for a given table 
 129  query_table_col_defs = u"""select 
 130          cols.column_name, 
 131          cols.udt_name 
 132  from 
 133          information_schema.columns cols 
 134  where 
 135          cols.table_schema = %s 
 136                  and 
 137          cols.table_name = %s 
 138  order by 
 139          cols.ordinal_position""" 
 140   
 141  query_table_attributes = u"""select 
 142          cols.column_name 
 143  from 
 144          information_schema.columns cols 
 145  where 
 146          cols.table_schema = %s 
 147                  and 
 148          cols.table_name = %s 
 149  order by 
 150          cols.ordinal_position""" 
 151   
 152  # ======================================================================= 
 153  # module globals API 
 154  # ======================================================================= 
155 -def set_default_client_encoding(encoding = None):
156 # check whether psycopg2 can handle this encoding 157 if encoding not in psycopg2.extensions.encodings: 158 raise ValueError('psycopg2 does not know how to handle client (wire) encoding [%s]' % encoding) 159 # check whether Python can handle this encoding 160 py_enc = psycopg2.extensions.encodings[encoding] 161 try: 162 codecs.lookup(py_enc) 163 except LookupError: 164 _log.warning('<codecs> module can NOT handle encoding [psycopg2::<%s> -> Python::<%s>]' % (encoding, py_enc)) 165 raise 166 # FIXME: check encoding against the database 167 # FIXME: - but we may not yet have access 168 # FIXME: - psycopg2 will pull its encodings from the database eventually 169 # it seems save to set it 170 global _default_client_encoding 171 _log.info('setting default client encoding from [%s] to [%s]' % (_default_client_encoding, str(encoding))) 172 _default_client_encoding = encoding 173 return True
174 #---------------------------------------------------
175 -def set_default_client_timezone(timezone = None):
176 177 # FIXME: use __validate 178 global _default_client_timezone 179 _log.info('setting default client time zone from [%s] to [%s]' % (_default_client_timezone, timezone)) 180 _default_client_timezone = timezone 181 182 global _sql_set_timezone 183 _sql_set_timezone = u'set timezone to %s' 184 185 return True
186 #---------------------------------------------------
187 -def __validate_timezone(conn=None, timezone=None):
188 189 _log.debug(u'validating time zone [%s]', timezone) 190 191 cmd = u'set timezone to %(tz)s' 192 args = {u'tz': timezone} 193 194 conn.commit() 195 curs = conn.cursor() 196 is_valid = False 197 try: 198 curs.execute(cmd, args) 199 _log.info(u'time zone [%s] is settable', timezone) 200 # can we actually use it, though ? 201 cmd = u"""select '1920-01-19 23:00:00+01'::timestamp with time zone""" 202 try: 203 curs.execute(cmd) 204 curs.fetchone() 205 _log.info(u'time zone [%s] is usable', timezone) 206 is_valid = True 207 except: 208 _log.error('error using time zone [%s]', timezone) 209 except dbapi.DataError: 210 _log.warning(u'time zone [%s] is not settable', timezone) 211 except: 212 _log.error(u'failed to set time zone to [%s]', timezone) 213 _log.exception(u'') 214 215 curs.close() 216 conn.rollback() 217 218 return is_valid
219 #---------------------------------------------------
220 -def __expand_timezone(conn=None, timezone=None):
221 """some timezone defs are abbreviations so try to expand 222 them because "set time zone" doesn't take abbreviations""" 223 224 cmd = u""" 225 select distinct on (abbrev) name 226 from pg_timezone_names 227 where 228 abbrev = %(tz)s and 229 name ~ '^[^/]+/[^/]+$' and 230 name !~ '^Etc/' 231 """ 232 args = {u'tz': timezone} 233 234 conn.commit() 235 curs = conn.cursor() 236 237 result = timezone 238 try: 239 curs.execute(cmd, args) 240 rows = curs.fetchall() 241 if len(rows) > 0: 242 result = rows[0][0] 243 _log.debug(u'[%s] maps to [%s]', timezone, result) 244 except: 245 _log.exception(u'cannot expand timezone abbreviation [%s]', timezone) 246 247 curs.close() 248 conn.rollback() 249 250 return result
251 #---------------------------------------------------
252 -def __detect_client_timezone(conn=None):
253 """This is run on the very first connection.""" 254 255 # FIXME: check whether server.timezone is the same 256 # FIXME: value as what we eventually detect 257 258 # we need gmDateTime to be initialized 259 if gmDateTime.current_local_iso_numeric_timezone_string is None: 260 gmDateTime.init() 261 262 _log.debug('trying to detect timezone from system') 263 264 tz_candidates = [] 265 try: 266 tz = os.environ['TZ'].decode(gmI18N.get_encoding(), 'replace') 267 tz_candidates.append(tz) 268 expanded = __expand_timezone(conn = conn, timezone = tz) 269 if expanded != tz: 270 tz_candidates.append(expanded) 271 except KeyError: 272 pass 273 274 tz_candidates.append(gmDateTime.current_local_timezone_name) 275 expanded = __expand_timezone(conn = conn, timezone = gmDateTime.current_local_timezone_name) 276 if expanded != gmDateTime.current_local_timezone_name: 277 tz_candidates.append(expanded) 278 279 _log.debug('candidates: %s', str(tz_candidates)) 280 281 # find best among candidates 282 global _default_client_timezone 283 global _sql_set_timezone 284 found = False 285 for tz in tz_candidates: 286 if __validate_timezone(conn = conn, timezone = tz): 287 _default_client_timezone = tz 288 _sql_set_timezone = u'set timezone to %s' 289 found = True 290 break 291 292 if not found: 293 _default_client_timezone = gmDateTime.current_local_iso_numeric_timezone_string 294 _sql_set_timezone = u"set time zone interval %s hour to minute" 295 296 _log.info('client system time zone detected as equivalent to [%s]', _default_client_timezone)
297 # ======================================================================= 298 # login API 299 # =======================================================================
300 -def __prompted_input(prompt, default=None):
301 usr_input = raw_input(prompt) 302 if usr_input == '': 303 return default 304 return usr_input
305 #---------------------------------------------------
306 -def __request_login_params_tui():
307 """Text mode request of database login parameters""" 308 import getpass 309 login = gmLoginInfo.LoginInfo() 310 311 print "\nPlease enter the required login parameters:" 312 try: 313 login.host = __prompted_input("host ['' = non-TCP/IP]: ", '') 314 login.database = __prompted_input("database [gnumed_v14]: ", 'gnumed_v14') 315 login.user = __prompted_input("user name: ", '') 316 tmp = 'password for "%s" (not shown): ' % login.user 317 login.password = getpass.getpass(tmp) 318 login.port = __prompted_input("port [5432]: ", 5432) 319 except KeyboardInterrupt: 320 _log.warning("user cancelled text mode login dialog") 321 print "user cancelled text mode login dialog" 322 raise gmExceptions.ConnectionError(_("Cannot connect to database without login information!")) 323 324 return login
325 #---------------------------------------------------
326 -def __request_login_params_gui_wx():
327 """GUI (wx) input request for database login parameters. 328 329 Returns gmLoginInfo.LoginInfo object 330 """ 331 import wx 332 # OK, wxPython was already loaded. But has the main Application instance 333 # been initialized yet ? if not, the exception will kick us out 334 if wx.GetApp() is None: 335 raise gmExceptions.NoGuiError(_("The wxPython GUI framework hasn't been initialized yet!")) 336 337 # Let's launch the login dialog 338 # if wx was not initialized /no main App loop, an exception should be raised anyway 339 import gmAuthWidgets 340 dlg = gmAuthWidgets.cLoginDialog(None, -1) 341 dlg.ShowModal() 342 login = dlg.panel.GetLoginInfo() 343 dlg.Destroy() 344 345 #if user cancelled or something else went wrong, raise an exception 346 if login is None: 347 raise gmExceptions.ConnectionError(_("Can't connect to database without login information!")) 348 349 return login
350 #---------------------------------------------------
351 -def request_login_params():
352 """Request login parameters for database connection. 353 """ 354 # are we inside X ? 355 # (if we aren't wxGTK will crash hard at 356 # C-level with "can't open Display") 357 if os.environ.has_key('DISPLAY'): 358 # try GUI 359 try: 360 return __request_login_params_gui_wx() 361 except: 362 pass 363 # well, either we are on the console or 364 # wxPython does not work, use text mode 365 return __request_login_params_tui()
366 367 # ======================================================================= 368 # DSN API 369 # -----------------------------------------------------------------------
370 -def make_psycopg2_dsn(database=None, host=None, port=5432, user=None, password=None):
371 dsn_parts = [] 372 373 if (database is not None) and (database.strip() != ''): 374 dsn_parts.append('dbname=%s' % database) 375 376 if (host is not None) and (host.strip() != ''): 377 dsn_parts.append('host=%s' % host) 378 379 if (port is not None) and (str(port).strip() != ''): 380 dsn_parts.append('port=%s' % port) 381 382 if (user is not None) and (user.strip() != ''): 383 dsn_parts.append('user=%s' % user) 384 385 if (password is not None) and (password.strip() != ''): 386 dsn_parts.append('password=%s' % password) 387 388 dsn_parts.append('sslmode=prefer') 389 390 return ' '.join(dsn_parts)
391 # ------------------------------------------------------
392 -def get_default_login():
393 # make sure we do have a login 394 get_default_dsn() 395 return _default_login
396 # ------------------------------------------------------
397 -def get_default_dsn():
398 global _default_dsn 399 if _default_dsn is not None: 400 return _default_dsn 401 402 login = request_login_params() 403 set_default_login(login=login) 404 405 return _default_dsn
406 # ------------------------------------------------------
407 -def set_default_login(login=None):
408 if login is None: 409 return False 410 411 if login.host is not None: 412 if login.host.strip() == u'': 413 login.host = None 414 415 global _default_login 416 _default_login = login 417 _log.info('setting default login from [%s] to [%s]' % (_default_login, login)) 418 419 dsn = make_psycopg2_dsn(login.database, login.host, login.port, login.user, login.password) 420 421 global _default_dsn 422 _default_dsn = dsn 423 _log.info('setting default DSN from [%s] to [%s]' % (_default_dsn, dsn)) 424 425 return True
426 # ======================================================================= 427 # netadata API 428 # =======================================================================
429 -def database_schema_compatible(link_obj=None, version=None, verbose=True):
430 expected_hash = known_schema_hashes[version] 431 if version == 'devel': 432 args = {'ver': '9999'} 433 else: 434 args = {'ver': version.strip('v')} 435 rows, idx = run_ro_queries ( 436 link_obj = link_obj, 437 queries = [{ 438 'cmd': u'select md5(gm.concat_table_structure(%(ver)s::integer)) as md5', 439 'args': args 440 }] 441 ) 442 if rows[0]['md5'] != expected_hash: 443 _log.error('database schema version mismatch') 444 _log.error('expected: %s (%s)' % (version, expected_hash)) 445 _log.error('detected: %s (%s)' % (get_schema_version(link_obj=link_obj), rows[0]['md5'])) 446 if verbose: 447 _log.debug('schema dump follows:') 448 for line in get_schema_structure(link_obj=link_obj).split(): 449 _log.debug(line) 450 _log.debug('schema revision history dump follows:') 451 for line in get_schema_revision_history(link_obj=link_obj): 452 _log.debug(u' - '.join(line)) 453 return False 454 _log.info('detected schema version [%s], hash [%s]' % (map_schema_hash2version[rows[0]['md5']], rows[0]['md5'])) 455 return True
456 #------------------------------------------------------------------------
457 -def get_schema_version(link_obj=None):
458 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': u'select md5(gm.concat_table_structure()) as md5'}]) 459 try: 460 return map_schema_hash2version[rows[0]['md5']] 461 except KeyError: 462 return u'unknown database schema version, MD5 hash is [%s]' % rows[0]['md5']
463 #------------------------------------------------------------------------
464 -def get_schema_structure(link_obj=None):
465 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': u'select gm.concat_table_structure()'}]) 466 return rows[0][0]
467 #------------------------------------------------------------------------
468 -def get_schema_revision_history(link_obj=None):
469 cmd = u""" 470 select 471 imported::text, 472 version, 473 filename 474 from gm.schema_revision 475 order by imported 476 """ 477 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': cmd}]) 478 return rows
479 #------------------------------------------------------------------------
480 -def get_current_user():
481 rows, idx = run_ro_queries(queries = [{'cmd': u'select CURRENT_USER'}]) 482 return rows[0][0]
483 #------------------------------------------------------------------------
484 -def get_foreign_keys2column(schema='public', table=None, column=None, link_obj=None):
485 """Get the foreign keys pointing to schema.table.column. 486 487 Does not properly work with multi-column FKs. 488 GNUmed doesn't use any, however. 489 """ 490 cmd = u""" 491 select 492 %(schema)s as referenced_schema, 493 %(tbl)s as referenced_table, 494 %(col)s as referenced_column, 495 pgc.confkey as referenced_column_list, 496 pgc.conrelid::regclass as referencing_table, 497 pgc.conkey as referencing_column_list, 498 (select attname from pg_attribute where attnum = pgc.conkey[1] and attrelid = pgc.conrelid) as referencing_column 499 from 500 pg_constraint pgc 501 where 502 pgc.contype = 'f' 503 and 504 pgc.confrelid = ( 505 select oid from pg_class where relname = %(tbl)s and relnamespace = ( 506 select oid from pg_namespace where nspname = %(schema)s 507 ) 508 ) and 509 ( 510 select attnum 511 from pg_attribute 512 where 513 attrelid = (select oid from pg_class where relname = %(tbl)s and relnamespace = ( 514 select oid from pg_namespace where nspname = %(schema)s 515 )) 516 and 517 attname = %(col)s 518 ) = any(pgc.confkey) 519 """ 520 521 args = { 522 'schema': schema, 523 'tbl': table, 524 'col': column 525 } 526 527 rows, idx = run_ro_queries ( 528 link_obj = link_obj, 529 queries = [ 530 {'cmd': cmd, 'args': args} 531 ] 532 ) 533 534 return rows
535 #------------------------------------------------------------------------
536 -def get_child_tables(schema='public', table=None, link_obj=None):
537 """Return child tables of <table>.""" 538 cmd = u""" 539 select 540 pgn.nspname as namespace, 541 pgc.relname as table 542 from 543 pg_namespace pgn, 544 pg_class pgc 545 where 546 pgc.relnamespace = pgn.oid 547 and 548 pgc.oid in ( 549 select inhrelid from pg_inherits where inhparent = ( 550 select oid from pg_class where 551 relnamespace = (select oid from pg_namespace where nspname = %(schema)s) and 552 relname = %(table)s 553 ) 554 )""" 555 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': {'schema': schema, 'table': table}}]) 556 return rows
557 #------------------------------------------------------------------------
558 -def table_exists(link_obj=None, schema=None, table=None):
559 """Returns false, true.""" 560 cmd = u""" 561 select exists ( 562 select 1 from information_schema.tables 563 where 564 table_schema = %s and 565 table_name = %s and 566 table_type = 'BASE TABLE' 567 )""" 568 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': (schema, table)}]) 569 return rows[0][0]
570 #------------------------------------------------------------------------
571 -def get_col_indices(cursor = None):
572 if cursor.description is None: 573 _log.error('no result description available: unused cursor or last query did not select rows') 574 return None 575 col_indices = {} 576 col_index = 0 577 for col_desc in cursor.description: 578 col_name = col_desc[0] 579 # a query like "select 1,2;" will return two columns of the same name ! 580 # hence adjust to that, note, however, that dict-style access won't work 581 # on results of such queries ... 582 if col_indices.has_key(col_name): 583 col_name = '%s_%s' % (col_name, col_index) 584 col_indices[col_name] = col_index 585 col_index += 1 586 587 return col_indices
588 #------------------------------------------------------------------------
589 -def get_col_defs(link_obj=None, schema='public', table=None):
590 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_col_defs, 'args': (schema, table)}]) 591 col_names = [] 592 col_type = {} 593 for row in rows: 594 col_names.append(row[0]) 595 # map array types 596 if row[1].startswith('_'): 597 col_type[row[0]] = row[1][1:] + '[]' 598 else: 599 col_type[row[0]] = row[1] 600 col_defs = [] 601 col_defs.append(col_names) 602 col_defs.append(col_type) 603 return col_defs
604 #------------------------------------------------------------------------
605 -def get_col_names(link_obj=None, schema='public', table=None):
606 """Return column attributes of table""" 607 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_attributes, 'args': (schema, table)}]) 608 cols = [] 609 for row in rows: 610 cols.append(row[0]) 611 return cols
612 #------------------------------------------------------------------------
613 -def get_translation_languages():
614 rows, idx = run_ro_queries ( 615 queries = [{'cmd': u'select distinct lang from i18n.translations'}] 616 ) 617 return [ r[0] for r in rows ]
618 #------------------------------------------------------------------------
619 -def get_current_user_language():
620 cmd = u'select i18n.get_curr_lang()' 621 rows, idx = run_ro_queries(queries = [{'cmd': cmd}]) 622 return rows[0][0]
623 #------------------------------------------------------------------------
624 -def set_user_language(user=None, language=None):
625 """Set the user language in the database. 626 627 user = None: current db user 628 language = None: unset 629 """ 630 _log.info('setting database language for user [%s] to [%s]', user, language) 631 632 args = { 633 'usr': user, 634 'lang': language 635 } 636 637 if language is None: 638 if user is None: 639 queries = [{'cmd': u'select i18n.unset_curr_lang()'}] 640 else: 641 queries = [{'cmd': u'select i18n.unset_curr_lang(%(usr)s)', 'args': args}] 642 queries.append({'cmd': u'select True'}) 643 else: 644 if user is None: 645 queries = [{'cmd': u'select i18n.set_curr_lang(%(lang)s)', 'args': args}] 646 else: 647 queries = [{'cmd': u'select i18n.set_curr_lang(%(lang)s, %(usr)s)', 'args': args}] 648 649 rows, idx = run_rw_queries(queries = queries, return_data = True) 650 651 if not rows[0][0]: 652 _log.error('cannot set database language to [%s] for user [%s]', language, user) 653 654 return rows[0][0]
655 #------------------------------------------------------------------------
656 -def force_user_language(language=None):
657 """Set the user language in the database. 658 659 - regardless of whether there is any translation available. 660 - only for the current user 661 """ 662 _log.info('forcing database language for current db user to [%s]', language) 663 664 run_rw_queries(queries = [{ 665 'cmd': u'select i18n.force_curr_lang(%(lang)s)', 666 'args': {'lang': language} 667 }])
668 #------------------------------------------------------------------------ 669 #------------------------------------------------------------------------ 670 text_expansion_keywords = None 671
672 -def get_text_expansion_keywords():
673 global text_expansion_keywords 674 if text_expansion_keywords is not None: 675 return text_expansion_keywords 676 677 cmd = u"""select keyword, public_expansion, private_expansion, owner from clin.v_keyword_expansions""" 678 rows, idx = run_ro_queries(queries = [{'cmd': cmd}]) 679 text_expansion_keywords = rows 680 681 _log.info('retrieved %s text expansion keywords', len(text_expansion_keywords)) 682 683 return text_expansion_keywords
684 #------------------------------------------------------------------------
685 -def expand_keyword(keyword = None):
686 687 # Easter Egg ;-) 688 if keyword == u'$$steffi': 689 return u'Hai, play ! Versucht das ! (Keks dazu ?) :-)' 690 691 cmd = u"""select expansion from clin.v_your_keyword_expansions where keyword = %(kwd)s""" 692 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'kwd': keyword}}]) 693 694 if len(rows) == 0: 695 return None 696 697 return rows[0]['expansion']
698 #------------------------------------------------------------------------
699 -def get_keyword_expansion_candidates(keyword = None):
700 701 if keyword is None: 702 return [] 703 704 get_text_expansion_keywords() 705 706 candidates = [] 707 for kwd in text_expansion_keywords: 708 if kwd['keyword'].startswith(keyword): 709 candidates.append(kwd['keyword']) 710 711 return candidates
712 #------------------------------------------------------------------------
713 -def add_text_expansion(keyword=None, expansion=None, public=None):
714 715 if public: 716 cmd = u"select 1 from clin.v_keyword_expansions where public_expansion is true and keyword = %(kwd)s" 717 else: 718 cmd = u"select 1 from clin.v_your_keyword_expansions where private_expansion is true and keyword = %(kwd)s" 719 720 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'kwd': keyword}}]) 721 if len(rows) != 0: 722 return False 723 724 if public: 725 cmd = u""" 726 insert into clin.keyword_expansion (keyword, expansion, fk_staff) 727 values (%(kwd)s, %(exp)s, null)""" 728 else: 729 cmd = u""" 730 insert into clin.keyword_expansion (keyword, expansion, fk_staff) 731 values (%(kwd)s, %(exp)s, (select pk from dem.staff where db_user = current_user))""" 732 733 rows, idx = run_rw_queries(queries = [{'cmd': cmd, 'args': {'kwd': keyword, 'exp': expansion}}]) 734 735 global text_expansion_keywords 736 text_expansion_keywords = None 737 738 return True
739 #------------------------------------------------------------------------
740 -def delete_text_expansion(keyword):
741 cmd = u""" 742 delete from clin.keyword_expansion where 743 keyword = %(kwd)s and ( 744 (fk_staff = (select pk from dem.staff where db_user = current_user)) 745 or 746 (fk_staff is null and owner = current_user) 747 )""" 748 rows, idx = run_rw_queries(queries = [{'cmd': cmd, 'args': {'kwd': keyword}}]) 749 750 global text_expansion_keywords 751 text_expansion_keywords = None
752 #------------------------------------------------------------------------
753 -def edit_text_expansion(keyword, expansion):
754 755 cmd1 = u""" 756 delete from clin.keyword_expansion where 757 keyword = %(kwd)s and 758 fk_staff = (select pk from dem.staff where db_user = current_user)""" 759 760 cmd2 = u""" 761 insert into clin.keyword_expansion (keyword, expansion, fk_staff) 762 values (%(kwd)s, %(exp)s, (select pk from dem.staff where db_user = current_user))""" 763 764 rows, idx = run_rw_queries(queries = [ 765 {'cmd': cmd1, 'args': {'kwd': keyword}}, 766 {'cmd': cmd2, 'args': {'kwd': keyword, 'exp': expansion}}, 767 ]) 768 769 global text_expansion_keywords 770 text_expansion_keywords = None
771 # ======================================================================= 772 # query runners and helpers 773 # =======================================================================
774 -def send_maintenance_notification():
775 cmd = u'notify "db_maintenance_warning:"' 776 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
777 #------------------------------------------------------------------------
778 -def send_maintenance_shutdown():
779 cmd = u'notify "db_maintenance_disconnect:"' 780 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
781 #------------------------------------------------------------------------
782 -def is_pg_interval(candidate=None):
783 cmd = u'select %(candidate)s::interval' 784 try: 785 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}]) 786 return True 787 except: 788 cmd = u'select %(candidate)s::text::interval' 789 try: 790 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}]) 791 return True 792 except: 793 return False
794 #------------------------------------------------------------------------
795 -def bytea2file(data_query=None, filename=None, chunk_size=0, data_size=None, data_size_query=None):
796 outfile = file(filename, 'wb') 797 result = bytea2file_object(data_query=data_query, file_obj=outfile, chunk_size=chunk_size, data_size=data_size, data_size_query=data_size_query) 798 outfile.close() 799 return result
800 #------------------------------------------------------------------------
801 -def bytea2file_object(data_query=None, file_obj=None, chunk_size=0, data_size=None, data_size_query=None):
802 """Store data from a bytea field into a file. 803 804 <data_query> 805 - dict {'cmd': ..., 'args': ...} 806 - 'cmd' must be unicode containing "... substring(data from %(start)s for %(size)s) ..." 807 - 'args' must be a dict 808 - must return one row with one field of type bytea 809 <file> 810 - must be a file like Python object 811 <data_size> 812 - integer of the total size of the expected data or None 813 <data_size_query> 814 - dict {'cmd': ..., 'args': ...} 815 - cmd must be unicode 816 - must return one row with one field with the octet_length() of the data field 817 - used only when <data_size> is None 818 """ 819 if data_size == 0: 820 return True 821 822 # If the client sets an encoding other than the default we 823 # will receive encoding-parsed data which isn't the binary 824 # content we want. Hence we need to get our own connection. 825 # It must be a read-write one so that we don't affect the 826 # encoding for other users of the shared read-only 827 # connections. 828 # Actually, encodings shouldn't be applied to binary data 829 # (eg. bytea types) in the first place but that is only 830 # reported to be fixed > v7.4. 831 # further tests reveal that at least on PG 8.0 this bug still 832 # manifests itself 833 conn = get_raw_connection(readonly=True) 834 835 if data_size is None: 836 rows, idx = run_ro_queries(link_obj = conn, queries = [data_size_query]) 837 data_size = rows[0][0] 838 if data_size in [None, 0]: 839 conn.rollback() 840 return True 841 842 _log.debug('expecting bytea data of size: [%s] bytes' % data_size) 843 _log.debug('using chunk size of: [%s] bytes' % chunk_size) 844 845 # chunk size of 0 means "retrieve whole field at once" 846 if chunk_size == 0: 847 chunk_size = data_size 848 _log.debug('chunk size [0] bytes: retrieving all data at once') 849 850 # Windoze sucks: it can't transfer objects of arbitrary size, 851 # anyways, we need to split the transfer, 852 # however, only possible if postgres >= 7.2 853 needed_chunks, remainder = divmod(data_size, chunk_size) 854 _log.debug('chunks to retrieve: [%s]' % needed_chunks) 855 _log.debug('remainder to retrieve: [%s] bytes' % remainder) 856 857 # retrieve chunks, skipped if data size < chunk size, 858 # does this not carry the danger of cutting up multi-byte escape sequences ? 859 # no, since bytea is binary, 860 # yes, since in bytea there are *some* escaped values, still 861 # no, since those are only escaped during *transfer*, not on-disk, hence 862 # only complete escape sequences are put on the wire 863 for chunk_id in range(needed_chunks): 864 chunk_start = (chunk_id * chunk_size) + 1 865 data_query['args']['start'] = chunk_start 866 data_query['args']['size'] = chunk_size 867 try: 868 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query]) 869 except: 870 _log.error('cannot retrieve chunk [%s/%s], size [%s], try decreasing chunk size' % (chunk_id+1, needed_chunks, chunk_size)) 871 conn.rollback() 872 raise 873 # it would be a fatal error to see more than one result as ids are supposed to be unique 874 file_obj.write(str(rows[0][0])) 875 876 # retrieve remainder 877 if remainder > 0: 878 chunk_start = (needed_chunks * chunk_size) + 1 879 data_query['args']['start'] = chunk_start 880 data_query['args']['size'] = remainder 881 try: 882 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query]) 883 except: 884 _log.error('cannot retrieve remaining [%s] bytes' % remainder) 885 conn.rollback() 886 raise 887 # it would be a fatal error to see more than one result as ids are supposed to be unique 888 file_obj.write(str(rows[0][0])) 889 890 conn.rollback() 891 return True
892 #------------------------------------------------------------------------
893 -def file2bytea(query=None, filename=None, args=None, conn=None):
894 """Store data from a file into a bytea field. 895 896 The query must: 897 - be in unicode 898 - contain a format spec identifying the row (eg a primary key) 899 matching <args> if it is an UPDATE 900 - contain a format spec %(data)s::bytea 901 """ 902 # read data from file 903 infile = file(filename, "rb") 904 data_as_byte_string = infile.read() 905 infile.close() 906 if args is None: 907 args = {} 908 args['data'] = buffer(data_as_byte_string) 909 del(data_as_byte_string) 910 911 # insert the data 912 if conn is None: 913 conn = get_raw_connection(readonly=False) 914 close_conn = True 915 else: 916 close_conn = False 917 918 run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = True) 919 920 if close_conn: 921 conn.close() 922 923 return
924 #------------------------------------------------------------------------
925 -def sanitize_pg_regex(expression=None, escape_all=False):
926 """Escape input for use in a PostgreSQL regular expression. 927 928 If a fragment comes from user input and is to be used 929 as a regular expression we need to make sure it doesn't 930 contain invalid regex patterns such as unbalanced ('s. 931 932 <escape_all> 933 True: try to escape *all* metacharacters 934 False: only escape those which render the regex invalid 935 """ 936 return expression.replace ( 937 '(', '\(' 938 ).replace ( 939 ')', '\)' 940 ).replace ( 941 '[', '\[' 942 ).replace ( 943 '+', '\+' 944 ).replace ( 945 '.', '\.' 946 ).replace ( 947 '*', '\*' 948 )
949 #']', '\]', # not needed 950 #------------------------------------------------------------------------
951 -def run_ro_queries(link_obj=None, queries=None, verbose=False, return_data=True, get_col_idx=False):
952 """Run read-only queries. 953 954 <queries> must be a list of dicts: 955 [ 956 {'cmd': <string>, 'args': <dict> or <tuple>}, 957 {...}, 958 ... 959 ] 960 """ 961 if isinstance(link_obj, dbapi._psycopg.cursor): 962 curs = link_obj 963 curs_close = __noop 964 tx_rollback = __noop 965 elif isinstance(link_obj, dbapi._psycopg.connection): 966 curs = link_obj.cursor() 967 curs_close = curs.close 968 tx_rollback = link_obj.rollback 969 elif link_obj is None: 970 conn = get_connection(readonly=True, verbose=verbose) 971 curs = conn.cursor() 972 curs_close = curs.close 973 tx_rollback = conn.rollback 974 else: 975 raise ValueError('link_obj must be cursor, connection or None but not [%s]' % link_obj) 976 977 if verbose: 978 _log.debug('cursor: %s', curs) 979 980 for query in queries: 981 if type(query['cmd']) is not types.UnicodeType: 982 print "run_ro_queries(): non-unicode query" 983 print query['cmd'] 984 try: 985 args = query['args'] 986 except KeyError: 987 args = None 988 try: 989 curs.execute(query['cmd'], args) 990 if verbose: 991 _log.debug('ran query: [%s]', curs.query) 992 _log.debug('PG status message: %s', curs.statusmessage) 993 _log.debug('cursor description: %s', str(curs.description)) 994 except: 995 # FIXME: use .pgcode 996 try: 997 curs_close() 998 except dbapi.InterfaceError: 999 _log.exception('cannot close cursor') 1000 tx_rollback() # need to rollback so ABORT state isn't preserved in pooled conns 1001 _log.error('query failed: [%s]', curs.query) 1002 _log.error('PG status message: %s', curs.statusmessage) 1003 raise 1004 1005 data = None 1006 col_idx = None 1007 if return_data: 1008 data = curs.fetchall() 1009 if verbose: 1010 _log.debug('last query returned [%s (%s)] rows', curs.rowcount, len(data)) 1011 _log.debug('cursor description: %s', str(curs.description)) 1012 if get_col_idx: 1013 col_idx = get_col_indices(curs) 1014 1015 curs_close() 1016 tx_rollback() # rollback just so that we don't stay IDLE IN TRANSACTION forever 1017 return (data, col_idx)
1018 #------------------------------------------------------------------------
1019 -def run_rw_queries(link_obj=None, queries=None, end_tx=False, return_data=None, get_col_idx=False, verbose=False):
1020 """Convenience function for running a transaction 1021 that is supposed to get committed. 1022 1023 <link_obj> 1024 can be either: 1025 - a cursor 1026 - a connection 1027 1028 <queries> 1029 is a list of dicts [{'cmd': <string>, 'args': <dict> or <tuple>) 1030 to be executed as a single transaction, the last 1031 query may usefully return rows (such as a 1032 "select currval('some_sequence')" statement) 1033 1034 <end_tx> 1035 - controls whether the transaction is finalized (eg. 1036 committed/rolled back) or not, this allows the 1037 call to run_rw_queries() to be part of a framing 1038 transaction 1039 - if link_obj is a connection then <end_tx> will 1040 default to False unless it is explicitly set to 1041 True which is taken to mean "yes, you do have full 1042 control over the transaction" in which case the 1043 transaction is properly finalized 1044 - if link_obj is a cursor we CANNOT finalize the 1045 transaction because we would need the connection for that 1046 - if link_obj is None <end_tx> will, of course, always be True 1047 1048 <return_data> 1049 - if true, the returned data will include the rows 1050 the last query selected 1051 - if false, it returns None instead 1052 1053 <get_col_idx> 1054 - if true, the returned data will include a dictionary 1055 mapping field names to column positions 1056 - if false, the returned data returns None instead 1057 1058 method result: 1059 - returns a tuple (data, idx) 1060 - <data>: 1061 * (None, None) if last query did not return rows 1062 * ("fetchall() result", <index>) if last query returned any rows 1063 * for <index> see <get_col_idx> 1064 """ 1065 if isinstance(link_obj, dbapi._psycopg.cursor): 1066 conn_close = __noop 1067 conn_commit = __noop 1068 conn_rollback = __noop 1069 curs = link_obj 1070 curs_close = __noop 1071 elif isinstance(link_obj, dbapi._psycopg.connection): 1072 conn_close = __noop 1073 if end_tx: 1074 conn_commit = link_obj.commit 1075 conn_rollback = link_obj.rollback 1076 else: 1077 conn_commit = __noop 1078 conn_rollback = __noop 1079 curs = link_obj.cursor() 1080 curs_close = curs.close 1081 elif link_obj is None: 1082 conn = get_connection(readonly=False) 1083 conn_close = conn.close 1084 conn_commit = conn.commit 1085 conn_rollback = conn.rollback 1086 curs = conn.cursor() 1087 curs_close = curs.close 1088 else: 1089 raise ValueError('link_obj must be cursor, connection or None and not [%s]' % link_obj) 1090 1091 for query in queries: 1092 if type(query['cmd']) is not types.UnicodeType: 1093 print "run_rw_queries(): non-unicode query" 1094 print query['cmd'] 1095 try: 1096 args = query['args'] 1097 except KeyError: 1098 args = None 1099 try: 1100 curs.execute(query['cmd'], args) 1101 except: 1102 _log.exception('error running RW query') 1103 gmLog2.log_stack_trace() 1104 try: 1105 curs_close() 1106 conn_rollback() 1107 conn_close() 1108 except dbapi.InterfaceError: 1109 _log.exception('cannot cleanup') 1110 raise 1111 raise 1112 1113 data = None 1114 col_idx = None 1115 if return_data: 1116 try: 1117 data = curs.fetchall() 1118 except: 1119 _log.exception('error fetching data from RW query') 1120 gmLog2.log_stack_trace() 1121 try: 1122 curs_close() 1123 conn_rollback() 1124 conn_close() 1125 except dbapi.InterfaceError: 1126 _log.exception('cannot cleanup') 1127 raise 1128 raise 1129 if get_col_idx: 1130 col_idx = get_col_indices(curs) 1131 1132 curs_close() 1133 conn_commit() 1134 conn_close() 1135 1136 return (data, col_idx)
1137 # ======================================================================= 1138 # connection handling API 1139 # -----------------------------------------------------------------------
1140 -class cConnectionPool(psycopg2.pool.PersistentConnectionPool):
1141 """ 1142 GNUmed database connection pool. 1143 1144 Extends psycopg2's PersistentConnectionPool with 1145 a custom _connect() function. Supports one connection 1146 per thread - which also ties it to one particular DSN. 1147 """ 1148 #--------------------------------------------------
1149 - def _connect(self, key=None):
1150 1151 conn = get_raw_connection(dsn = self._kwargs['dsn'], verbose = self._kwargs['verbose'], readonly=True) 1152 1153 conn.original_close = conn.close 1154 conn.close = _raise_exception_on_ro_conn_close 1155 1156 if key is not None: 1157 self._used[key] = conn 1158 self._rused[id(conn)] = key 1159 else: 1160 self._pool.append(conn) 1161 1162 return conn
1163 #--------------------------------------------------
1164 - def shutdown(self):
1165 for conn_key in self._used.keys(): 1166 _log.debug('closing pooled database connection, pool key: %s, backend PID: %s', conn_key, self._used[conn_key].get_backend_pid()) 1167 self._used[conn_key].original_close()
1168 # -----------------------------------------------------------------------
1169 -def get_raw_connection(dsn=None, verbose=False, readonly=True):
1170 """Get a raw, unadorned connection. 1171 1172 - this will not set any parameters such as encoding, timezone, datestyle 1173 - the only requirement is a valid DSN 1174 - hence it can be used for "service" connections 1175 for verifying encodings etc 1176 """ 1177 # FIXME: support verbose 1178 if dsn is None: 1179 dsn = get_default_dsn() 1180 1181 try: 1182 conn = dbapi.connect(dsn=dsn, connection_factory=psycopg2.extras.DictConnection) 1183 except dbapi.OperationalError, e: 1184 1185 t, v, tb = sys.exc_info() 1186 try: 1187 msg = e.args[0] 1188 except (AttributeError, IndexError, TypeError): 1189 raise 1190 1191 msg = unicode(msg, gmI18N.get_encoding(), 'replace') 1192 1193 if msg.find('fe_sendauth') != -1: 1194 raise cAuthenticationError, (dsn, msg), tb 1195 1196 if regex.search('user ".*" does not exist', msg) is not None: 1197 raise cAuthenticationError, (dsn, msg), tb 1198 1199 if msg.find('uthenti') != -1: 1200 raise cAuthenticationError, (dsn, msg), tb 1201 1202 raise 1203 1204 _log.debug('new database connection, backend PID: %s, readonly: %s', conn.get_backend_pid(), readonly) 1205 1206 # do first-time stuff 1207 global postgresql_version 1208 if postgresql_version is None: 1209 curs = conn.cursor() 1210 curs.execute (""" 1211 select 1212 (split_part(setting, '.', 1) || '.' || split_part(setting, '.', 2))::numeric as version 1213 from pg_settings 1214 where name='server_version'""" 1215 ) 1216 postgresql_version = curs.fetchone()['version'] 1217 _log.info('PostgreSQL version (numeric): %s' % postgresql_version) 1218 try: 1219 curs.execute("select pg_size_pretty(pg_database_size(current_database()))") 1220 _log.info('database size: %s', curs.fetchone()[0]) 1221 except: 1222 pass 1223 if verbose: 1224 __log_PG_settings(curs=curs) 1225 curs.close() 1226 conn.commit() 1227 1228 if _default_client_timezone is None: 1229 __detect_client_timezone(conn = conn) 1230 1231 curs = conn.cursor() 1232 1233 # set access mode 1234 if readonly: 1235 _log.debug('access mode [READ ONLY]') 1236 cmd = 'set session characteristics as transaction READ ONLY' 1237 curs.execute(cmd) 1238 cmd = 'set default_transaction_read_only to on' 1239 curs.execute(cmd) 1240 else: 1241 _log.debug('access mode [READ WRITE]') 1242 cmd = 'set session characteristics as transaction READ WRITE' 1243 curs.execute(cmd) 1244 cmd = 'set default_transaction_read_only to off' 1245 curs.execute(cmd) 1246 1247 curs.close() 1248 conn.commit() 1249 1250 conn.is_decorated = False 1251 1252 return conn
1253 # =======================================================================
1254 -def get_connection(dsn=None, readonly=True, encoding=None, verbose=False, pooled=True):
1255 """Get a new connection. 1256 1257 This assumes the locale system has been initialzied 1258 unless an encoding is specified. 1259 """ 1260 # FIXME: support pooled on RW, too 1261 # FIXME: for now, support the default DSN only 1262 if pooled and readonly and (dsn is None): 1263 global __ro_conn_pool 1264 if __ro_conn_pool is None: 1265 __ro_conn_pool = cConnectionPool ( 1266 minconn = 1, 1267 maxconn = 2, 1268 dsn = dsn, 1269 verbose = verbose 1270 ) 1271 conn = __ro_conn_pool.getconn() 1272 else: 1273 conn = get_raw_connection(dsn=dsn, verbose=verbose, readonly=False) 1274 1275 if conn.is_decorated: 1276 return conn 1277 1278 if encoding is None: 1279 encoding = _default_client_encoding 1280 if encoding is None: 1281 encoding = gmI18N.get_encoding() 1282 _log.warning('client encoding not specified') 1283 _log.warning('the string encoding currently set in the active locale is used: [%s]' % encoding) 1284 _log.warning('for this to work properly the application MUST have called locale.setlocale() before') 1285 1286 # set connection properties 1287 # 1) client encoding 1288 try: 1289 conn.set_client_encoding(encoding) 1290 except dbapi.OperationalError: 1291 t, v, tb = sys.exc_info() 1292 if str(v).find("can't set encoding to") != -1: 1293 raise cEncodingError, (encoding, v), tb 1294 raise 1295 1296 # 2) transaction isolation level 1297 if readonly: 1298 conn.set_isolation_level(psycopg2.extensions.ISOLATION_LEVEL_READ_COMMITTED) 1299 iso_level = u'read committed' 1300 else: 1301 conn.set_isolation_level(psycopg2.extensions.ISOLATION_LEVEL_SERIALIZABLE) 1302 iso_level = u'serializable' 1303 1304 _log.debug('client string encoding [%s], isolation level [%s], time zone [%s], datestyle [ISO], sql_inheritance [ON]', encoding, iso_level, _default_client_timezone) 1305 1306 curs = conn.cursor() 1307 1308 # client time zone 1309 curs.execute(_sql_set_timezone, [_default_client_timezone]) 1310 1311 # datestyle 1312 # regarding DMY/YMD handling: since we force *input* to 1313 # ISO, too, the DMY/YMD setting is not needed 1314 cmd = "set datestyle to 'ISO'" 1315 curs.execute(cmd) 1316 1317 # SQL inheritance mode 1318 cmd = 'set sql_inheritance to on' 1319 curs.execute(cmd) 1320 1321 # version string 1322 global postgresql_version_string 1323 if postgresql_version_string is None: 1324 curs.execute('select version()') 1325 postgresql_version_string = curs.fetchone()['version'] 1326 _log.info('PostgreSQL version (string): "%s"' % postgresql_version_string) 1327 1328 curs.close() 1329 conn.commit() 1330 1331 conn.is_decorated = True 1332 1333 return conn
1334 #-----------------------------------------------------------------------
1335 -def shutdown():
1336 if __ro_conn_pool is None: 1337 return 1338 __ro_conn_pool.shutdown()
1339 # ====================================================================== 1340 # internal helpers 1341 #-----------------------------------------------------------------------
1342 -def __noop():
1343 pass
1344 #-----------------------------------------------------------------------
1345 -def _raise_exception_on_ro_conn_close():
1346 raise TypeError(u'close() called on read-only connection')
1347 #-----------------------------------------------------------------------
1348 -def sanity_check_time_skew(tolerance=60):
1349 """Check server time and local time to be within 1350 the given tolerance of each other. 1351 1352 tolerance: seconds 1353 """ 1354 _log.debug('maximum skew tolerance (seconds): %s', tolerance) 1355 1356 cmd = u"select now() at time zone 'UTC'" 1357 conn = get_raw_connection(readonly=True) 1358 curs = conn.cursor() 1359 1360 start = time.time() 1361 rows, idx = run_ro_queries(link_obj = curs, queries = [{'cmd': cmd}]) 1362 end = time.time() 1363 client_now_as_utc = pydt.datetime.utcnow() 1364 1365 curs.close() 1366 conn.commit() 1367 1368 server_now_as_utc = rows[0][0] 1369 query_duration = end - start 1370 _log.info('server "now" (UTC): %s', server_now_as_utc) 1371 _log.info('client "now" (UTC): %s', client_now_as_utc) 1372 _log.debug('wire roundtrip (seconds): %s', query_duration) 1373 1374 if query_duration > tolerance: 1375 _log.error('useless to check client/server time skew, wire roundtrip > tolerance') 1376 return False 1377 1378 if server_now_as_utc > client_now_as_utc: 1379 real_skew = server_now_as_utc - client_now_as_utc 1380 else: 1381 real_skew = client_now_as_utc - server_now_as_utc 1382 1383 _log.debug('client/server time skew: %s', real_skew) 1384 1385 if real_skew > pydt.timedelta(seconds = tolerance): 1386 _log.error('client/server time skew > tolerance') 1387 return False 1388 1389 return True
1390 #-----------------------------------------------------------------------
1391 -def sanity_check_database_settings():
1392 """Checks database settings. 1393 1394 returns (status, message) 1395 status: 1396 0: no problem 1397 1: non-fatal problem 1398 2: fatal problem 1399 """ 1400 _log.debug('checking database settings') 1401 settings = { 1402 # setting: [expected value, risk, fatal?] 1403 u'allow_system_table_mods': [u'off', u'system breakage', False], 1404 u'check_function_bodies': [u'on', u'suboptimal error detection', False], 1405 u'default_transaction_read_only': [u'on', u'accidental database writes', False], 1406 u'fsync': [u'on', u'data loss/corruption', True], 1407 u'full_page_writes': [u'on', u'data loss/corruption', False], 1408 u'lc_messages': [u'C', u'suboptimal error detection', False], 1409 u'password_encryption': [u'on', u'breach of confidentiality', False], 1410 u'regex_flavor': [u'advanced', u'query breakage', False], 1411 u'synchronous_commit': [u'on', u'data loss/corruption', False], 1412 u'sql_inheritance': [u'on', u'query breakage, data loss/corruption', True] 1413 } 1414 1415 from Gnumed.pycommon import gmCfg2 1416 _cfg = gmCfg2.gmCfgData() 1417 if _cfg.get(option = u'hipaa'): 1418 settings[u'log_connections'] = [u'on', u'non-compliance with HIPAA', True] 1419 settings[u'log_disconnections'] = [u'on', u'non-compliance with HIPAA', True] 1420 else: 1421 settings[u'log_connections'] = [u'on', u'non-compliance with HIPAA', None] 1422 settings[u'log_disconnections'] = [u'on', u'non-compliance with HIPAA', None] 1423 1424 cmd = u"select name, setting from pg_settings where name in %(settings)s" 1425 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'settings': tuple(settings.keys())}}]) 1426 1427 found_error = False 1428 found_problem = False 1429 msg = [] 1430 for row in rows: 1431 if row[1] != settings[row[0]][0]: 1432 if settings[row[0]][2] is True: 1433 found_error = True 1434 elif settings[row[0]][2] is False: 1435 found_problem = True 1436 elif settings[row[0]][2] is None: 1437 pass 1438 else: 1439 _log.error(settings[row[0]]) 1440 raise ValueError(u'invalid database configuration sanity check') 1441 msg.append(_(' option [%s]: %s') % (row[0], row[1])) 1442 msg.append(_(' risk: %s') % settings[row[0]][1]) 1443 _log.warning('PG option [%s] set to [%s], expected [%s], risk: <%s>' % (row[0], row[1], settings[row[0]][0], settings[row[0]][1])) 1444 1445 if found_error: 1446 return 2, u'\n'.join(msg) 1447 1448 if found_problem: 1449 return 1, u'\n'.join(msg) 1450 1451 return 0, u''
1452 #------------------------------------------------------------------------
1453 -def __log_PG_settings(curs=None):
1454 # don't use any of the run_*()s since that might 1455 # create a loop if we fail here 1456 # FIXME: use pg_settings 1457 try: 1458 curs.execute(u'show all') 1459 except: 1460 _log.exception(u'cannot log PG settings (>>>show all<<< failed)') 1461 return False 1462 settings = curs.fetchall() 1463 if settings is None: 1464 _log.error(u'cannot log PG settings (>>>show all<<< did not return rows)') 1465 return False 1466 for setting in settings: 1467 _log.debug(u'PG option [%s]: %s', setting[0], setting[1]) 1468 return True
1469 # =======================================================================
1470 -def extract_msg_from_pg_exception(exc=None):
1471 1472 try: 1473 msg = exc.args[0] 1474 except (AttributeError, IndexError, TypeError): 1475 return u'cannot extract message from exception' 1476 1477 return unicode(msg, gmI18N.get_encoding(), 'replace')
1478 # =======================================================================
1479 -class cAuthenticationError(dbapi.OperationalError):
1480
1481 - def __init__(self, dsn=None, prev_val=None):
1482 self.dsn = dsn 1483 self.prev_val = prev_val
1484
1485 - def __str__(self):
1486 _log.warning('%s.__str__() called', self.__class__.__name__) 1487 tmp = u'PostgreSQL: %sDSN: %s' % (self.prev_val, self.dsn) 1488 _log.error(tmp) 1489 return tmp.encode(gmI18N.get_encoding(), 'replace')
1490
1491 - def __unicode__(self):
1492 return u'PostgreSQL: %sDSN: %s' % (self.prev_val, self.dsn)
1493 1494 # ======================================================================= 1495 # custom psycopg2 extensions 1496 # =======================================================================
1497 -class cEncodingError(dbapi.OperationalError):
1498
1499 - def __init__(self, encoding=None, prev_val=None):
1500 self.encoding = encoding 1501 self.prev_val = prev_val
1502
1503 - def __str__(self):
1504 _log.warning('%s.__str__() called', self.__class__.__name__) 1505 return 'PostgreSQL: %s\nencoding: %s' % (self.prev_val.encode(gmI18N.get_encoding(), 'replace'), self.encoding.encode(gmI18N.get_encoding(), 'replace'))
1506
1507 - def __unicode__(self):
1508 return u'PostgreSQL: %s\nencoding: %s' % (self.prev_val, self.encoding)
1509 1510 # ----------------------------------------------------------------------- 1511 # Python -> PostgreSQL 1512 # -----------------------------------------------------------------------
1513 -class cAdapterPyDateTime(object):
1514
1515 - def __init__(self, dt):
1516 if dt.tzinfo is None: 1517 raise ValueError(u'datetime.datetime instance is lacking a time zone: [%s]' % _timestamp_template % dt.isoformat()) 1518 self.__dt = dt
1519
1520 - def getquoted(self):
1521 return _timestamp_template % self.__dt.isoformat()
1522 1523 # ----------------------------------------------------------------------
1524 -class cAdapterMxDateTime(object):
1525
1526 - def __init__(self, dt):
1527 if dt.tz == '???': 1528 _log.info('[%s]: no time zone string available in (%s), assuming local time zone', self.__class__.__name__, dt) 1529 self.__dt = dt
1530
1531 - def getquoted(self):
1532 # under some locale settings the mx.DateTime ISO formatter 1533 # will insert "," into the ISO string, 1534 # while this is allowed per the ISO8601 spec PostgreSQL 1535 # cannot currently handle that, 1536 # so map those "," to "." to make things work: 1537 return mxDT.ISO.str(self.__dt).replace(',', '.')
1538 1539 # ---------------------------------------------------------------------- 1540 # PostgreSQL -> Python 1541 # ---------------------------------------------------------------------- 1542 1543 #======================================================================= 1544 # main 1545 #----------------------------------------------------------------------- 1546 1547 # make sure psycopg2 knows how to handle unicode ... 1548 # intended to become standard 1549 psycopg2.extensions.register_type(psycopg2.extensions.UNICODE) 1550 psycopg2.extensions.register_type(psycopg2._psycopg.UNICODEARRAY) 1551 1552 # tell psycopg2 how to adapt datetime types with timestamps when locales are in use 1553 psycopg2.extensions.register_adapter(pydt.datetime, cAdapterPyDateTime) 1554 try: 1555 import mx.DateTime as mxDT 1556 psycopg2.extensions.register_adapter(mxDT.DateTimeType, cAdapterMxDateTime) 1557 except ImportError: 1558 _log.warning('cannot import mx.DateTime') 1559 1560 # do NOT adapt *lists* to "... IN (*) ..." syntax because we want 1561 # them adapted to "... ARRAY()..." so we can support PG arrays 1562 1563 #======================================================================= 1564 if __name__ == "__main__": 1565 1566 if len(sys.argv) < 2: 1567 sys.exit() 1568 1569 if sys.argv[1] != 'test': 1570 sys.exit() 1571 1572 logging.basicConfig(level=logging.DEBUG) 1573 #--------------------------------------------------------------------
1574 - def test_file2bytea():
1575 run_rw_queries(queries = [ 1576 {'cmd': u'create table test_bytea (data bytea)'} 1577 ]) 1578 1579 cmd = u'insert into test_bytea values (%(data)s::bytea)' 1580 try: 1581 file2bytea(query = cmd, filename = sys.argv[2]) 1582 except: 1583 _log.exception('error') 1584 1585 run_rw_queries(queries = [ 1586 {'cmd': u'drop table test_bytea'} 1587 ])
1588 #--------------------------------------------------------------------
1589 - def test_get_connection():
1590 print "testing get_connection()" 1591 1592 dsn = 'foo' 1593 try: 1594 conn = get_connection(dsn=dsn) 1595 except dbapi.OperationalError, e: 1596 print "SUCCESS: get_connection(%s) failed as expected" % dsn 1597 t, v = sys.exc_info()[:2] 1598 print ' ', t 1599 print ' ', v 1600 1601 dsn = 'dbname=gnumed_v9' 1602 try: 1603 conn = get_connection(dsn=dsn) 1604 except cAuthenticationError: 1605 print "SUCCESS: get_connection(%s) failed as expected" % dsn 1606 t, v = sys.exc_info()[:2] 1607 print ' ', t 1608 print ' ', v 1609 1610 dsn = 'dbname=gnumed_v9 user=abc' 1611 try: 1612 conn = get_connection(dsn=dsn) 1613 except cAuthenticationError: 1614 print "SUCCESS: get_connection(%s) failed as expected" % dsn 1615 t, v = sys.exc_info()[:2] 1616 print ' ', t 1617 print ' ', v 1618 1619 dsn = 'dbname=gnumed_v9 user=any-doc' 1620 try: 1621 conn = get_connection(dsn=dsn) 1622 except cAuthenticationError: 1623 print "SUCCESS: get_connection(%s) failed as expected" % dsn 1624 t, v = sys.exc_info()[:2] 1625 print ' ', t 1626 print ' ', v 1627 1628 dsn = 'dbname=gnumed_v9 user=any-doc password=abc' 1629 try: 1630 conn = get_connection(dsn=dsn) 1631 except cAuthenticationError: 1632 print "SUCCESS: get_connection(%s) failed as expected" % dsn 1633 t, v = sys.exc_info()[:2] 1634 print ' ', t 1635 print ' ', v 1636 1637 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc' 1638 conn = get_connection(dsn=dsn, readonly=True) 1639 1640 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc' 1641 conn = get_connection(dsn=dsn, readonly=False) 1642 1643 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc' 1644 encoding = 'foo' 1645 try: 1646 conn = get_connection(dsn=dsn, encoding=encoding) 1647 except cEncodingError: 1648 print "SUCCESS: get_connection(%s, %s) failed as expected" % (dsn, encoding) 1649 t, v = sys.exc_info()[:2] 1650 print ' ', t 1651 print ' ', v
1652 #--------------------------------------------------------------------
1653 - def test_exceptions():
1654 print "testing exceptions" 1655 1656 try: 1657 raise cAuthenticationError('no dsn', 'no previous exception') 1658 except cAuthenticationError: 1659 t, v, tb = sys.exc_info() 1660 print t 1661 print v 1662 print tb 1663 1664 try: 1665 raise cEncodingError('no dsn', 'no previous exception') 1666 except cEncodingError: 1667 t, v, tb = sys.exc_info() 1668 print t 1669 print v 1670 print tb
1671 #--------------------------------------------------------------------
1672 - def test_ro_queries():
1673 print "testing run_ro_queries()" 1674 1675 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc' 1676 conn = get_connection(dsn, readonly=True) 1677 1678 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': u'select version()'}], return_data=True, get_col_idx=True, verbose=True) 1679 print data 1680 print idx 1681 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': u'select 1'}], return_data=True, get_col_idx=True) 1682 print data 1683 print idx 1684 1685 curs = conn.cursor() 1686 1687 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': u'select version()'}], return_data=True, get_col_idx=True, verbose=True) 1688 print data 1689 print idx 1690 1691 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': u'select 1'}], return_data=True, get_col_idx=True, verbose=True) 1692 print data 1693 print idx 1694 1695 try: 1696 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': u'selec 1'}], return_data=True, get_col_idx=True, verbose=True) 1697 print data 1698 print idx 1699 except psycopg2.ProgrammingError: 1700 print 'SUCCESS: run_ro_queries("selec 1") failed as expected' 1701 t, v = sys.exc_info()[:2] 1702 print ' ', t 1703 print ' ', v 1704 1705 curs.close()
1706 #--------------------------------------------------------------------
1707 - def test_request_dsn():
1708 conn = get_connection() 1709 print conn 1710 conn.close()
1711 #--------------------------------------------------------------------
1712 - def test_set_encoding():
1713 print "testing set_default_client_encoding()" 1714 1715 enc = 'foo' 1716 try: 1717 set_default_client_encoding(enc) 1718 print "SUCCESS: encoding [%s] worked" % enc 1719 except ValueError: 1720 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc 1721 t, v = sys.exc_info()[:2] 1722 print ' ', t 1723 print ' ', v 1724 1725 enc = '' 1726 try: 1727 set_default_client_encoding(enc) 1728 print "SUCCESS: encoding [%s] worked" % enc 1729 except ValueError: 1730 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc 1731 t, v = sys.exc_info()[:2] 1732 print ' ', t 1733 print ' ', v 1734 1735 enc = 'latin1' 1736 try: 1737 set_default_client_encoding(enc) 1738 print "SUCCESS: encoding [%s] worked" % enc 1739 except ValueError: 1740 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc 1741 t, v = sys.exc_info()[:2] 1742 print ' ', t 1743 print ' ', v 1744 1745 enc = 'utf8' 1746 try: 1747 set_default_client_encoding(enc) 1748 print "SUCCESS: encoding [%s] worked" % enc 1749 except ValueError: 1750 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc 1751 t, v = sys.exc_info()[:2] 1752 print ' ', t 1753 print ' ', v 1754 1755 enc = 'unicode' 1756 try: 1757 set_default_client_encoding(enc) 1758 print "SUCCESS: encoding [%s] worked" % enc 1759 except ValueError: 1760 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc 1761 t, v = sys.exc_info()[:2] 1762 print ' ', t 1763 print ' ', v 1764 1765 enc = 'UNICODE' 1766 try: 1767 set_default_client_encoding(enc) 1768 print "SUCCESS: encoding [%s] worked" % enc 1769 except ValueError: 1770 print "SUCCESS: set_default_client_encoding(%s) failed as expected" % enc 1771 t, v = sys.exc_info()[:2] 1772 print ' ', t 1773 print ' ', v
1774 #--------------------------------------------------------------------
1775 - def test_connection_pool():
1776 dsn = get_default_dsn() 1777 pool = cConnectionPool(minconn=1, maxconn=2, dsn=None, verbose=False) 1778 print pool 1779 print pool.getconn() 1780 print pool.getconn() 1781 print pool.getconn() 1782 print type(pool.getconn())
1783 #--------------------------------------------------------------------
1784 - def test_list_args():
1785 dsn = get_default_dsn() 1786 conn = get_connection(dsn, readonly=True) 1787 curs = conn.cursor() 1788 curs.execute('select * from clin.clin_narrative where narrative = %s', ['a'])
1789 #--------------------------------------------------------------------
1790 - def test_sanitize_pg_regex():
1791 tests = [ 1792 ['(', '\\('] 1793 , ['[', '\\['] 1794 , [')', '\\)'] 1795 ] 1796 for test in tests: 1797 result = sanitize_pg_regex(test[0]) 1798 if result != test[1]: 1799 print 'ERROR: sanitize_pg_regex(%s) returned "%s", expected "%s"' % (test[0], result, test[1])
1800 #--------------------------------------------------------------------
1801 - def test_is_pg_interval():
1802 status = True 1803 tests = [ 1804 [None, True], # None == NULL == succeeds ! 1805 [1, True], 1806 ['1', True], 1807 ['abc', False] 1808 ] 1809 1810 if not is_pg_interval(): 1811 print 'ERROR: is_pg_interval() returned "False", expected "True"' 1812 status = False 1813 1814 for test in tests: 1815 result = is_pg_interval(test[0]) 1816 if result != test[1]: 1817 print 'ERROR: is_pg_interval(%s) returned "%s", expected "%s"' % (test[0], result, test[1]) 1818 status = False 1819 1820 return status
1821 #--------------------------------------------------------------------
1822 - def test_sanity_check_time_skew():
1823 sanity_check_time_skew()
1824 #--------------------------------------------------------------------
1825 - def test_keyword_expansion():
1826 print "keywords, from database:" 1827 print get_text_expansion_keywords() 1828 print "keywords, cached:" 1829 print get_text_expansion_keywords() 1830 print "'$keyword' expands to:" 1831 print expand_keyword(keyword = u'$dvt')
1832 #--------------------------------------------------------------------
1833 - def test_get_foreign_key_details():
1834 for row in get_foreign_keys2column ( 1835 schema = u'dem', 1836 table = u'identity', 1837 column = u'pk' 1838 ): 1839 print '%s.%s references %s.%s.%s' % ( 1840 row['referencing_table'], 1841 row['referencing_column'], 1842 row['referenced_schema'], 1843 row['referenced_table'], 1844 row['referenced_column'] 1845 )
1846 #--------------------------------------------------------------------
1847 - def test_set_user_language():
1848 # (user, language, result, exception type) 1849 tests = [ 1850 # current user 1851 [None, 'de_DE', True], 1852 [None, 'lang_w/o_tx', False], 1853 [None, None, True], 1854 # valid user 1855 ['any-doc', 'de_DE', True], 1856 ['any-doc', 'lang_w/o_tx', False], 1857 ['any-doc', None, True], 1858 # invalid user 1859 ['invalid user', 'de_DE', None], 1860 ['invalid user', 'lang_w/o_tx', False], # lang checking happens before user checking 1861 ['invalid user', None, True] 1862 ] 1863 for test in tests: 1864 try: 1865 result = set_user_language(user = test[0], language = test[1]) 1866 if result != test[2]: 1867 print "test:", test 1868 print "result:", result, "expected:", test[2] 1869 except psycopg2.IntegrityError, e: 1870 if test[2] is None: 1871 continue 1872 print "test:", test 1873 print "expected exception" 1874 print "result:", e
1875 #--------------------------------------------------------------------
1876 - def test_get_schema_revision_history():
1877 for line in get_schema_revision_history(): 1878 print u' - '.join(line)
1879 #-------------------------------------------------------------------- 1880 # run tests 1881 #test_file2bytea() 1882 #test_get_connection() 1883 #test_exceptions() 1884 #test_ro_queries() 1885 #test_request_dsn() 1886 #test_set_encoding() 1887 #test_connection_pool() 1888 #test_list_args() 1889 #test_sanitize_pg_regex() 1890 #test_is_pg_interval() 1891 #test_sanity_check_time_skew() 1892 #test_keyword_expansion() 1893 #test_get_foreign_key_details() 1894 #test_set_user_language() 1895 test_get_schema_revision_history() 1896 1897 # ====================================================================== 1898