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