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  __author__  = "K.Hilbert <Karsten.Hilbert@gmx.net>" 
  15  __license__ = 'GPL v2 or later (details at http://www.gnu.org)' 
  16   
  17   
  18  # stdlib 
  19  import time 
  20  import sys 
  21  import os 
  22  import stat 
  23  import codecs 
  24  import logging 
  25  import datetime as pydt 
  26  import re as regex 
  27  import threading 
  28  import hashlib 
  29  import shutil 
  30   
  31   
  32  # GNUmed 
  33  if __name__ == '__main__': 
  34          sys.path.insert(0, '../../') 
  35  from Gnumed.pycommon import gmLoginInfo 
  36  from Gnumed.pycommon import gmExceptions 
  37  from Gnumed.pycommon import gmDateTime 
  38  from Gnumed.pycommon import gmI18N 
  39  from Gnumed.pycommon import gmLog2 
  40  from Gnumed.pycommon import gmTools 
  41  from Gnumed.pycommon import gmConnectionPool 
  42  from Gnumed.pycommon.gmTools import prompted_input, u_replacement_character, format_dict_like 
  43   
  44   
  45  _log = logging.getLogger('gm.db') 
  46   
  47   
  48  # 3rd party 
  49  try: 
  50          import psycopg2 as dbapi 
  51  except ImportError: 
  52          _log.exception("Python database adapter psycopg2 not found.") 
  53          print("CRITICAL ERROR: Cannot find module psycopg2 for connecting to the database server.") 
  54          raise 
  55   
  56  import psycopg2.errorcodes as sql_error_codes 
  57  import psycopg2.sql as psysql 
  58   
  59  PG_ERROR_EXCEPTION = dbapi.Error 
  60   
  61  # ======================================================================= 
  62  default_database = 'gnumed_v22' 
  63   
  64  postgresql_version_string = None 
  65   
  66  # ======================================================================= 
  67  # global data 
  68  # ======================================================================= 
  69   
  70  known_schema_hashes = { 
  71          0: 'not released, testing only', 
  72          2: 'b09d50d7ed3f91ddf4c4ddb8ea507720', 
  73          3: 'e73718eaf230d8f1d2d01afa8462e176', 
  74          4: '4428ccf2e54c289136819e701bb095ea', 
  75          5: '7e7b093af57aea48c288e76632a382e5',  # ... old (v1) style hashes 
  76          6: '90e2026ac2efd236da9c8608b8685b2d',  # new (v2) style hashes ... 
  77          7: '6c9f6d3981483f8e9433df99d1947b27', 
  78          8: '89b13a7af83337c3aad153b717e52360', 
  79          9: '641a9b2be3c378ffc2bb2f0b1c9f051d', 
  80          10: '7ef42a8fb2bd929a2cdd0c63864b4e8a', 
  81          11: '03042ae24f3f92877d986fb0a6184d76', 
  82          12: '06183a6616db62257e22814007a8ed07', 
  83          13: 'fab7c1ae408a6530c47f9b5111a0841e', 
  84          14: 'e170d543f067d1ea60bfe9076b1560cf', 
  85          15: '70012ff960b77ecdff4981c94b5b55b6', 
  86          16: '0bcf44ca22c479b52976e5eda1de8161', 
  87          17: '161428ee97a00e3bf56168c3a15b7b50', 
  88          18: 'a0f9efcabdecfb4ddb6d8c0b69c02092', 
  89          #19: '419e5225259c53dd36ad80d82066ff02' # 19.0 only 
  90          #19: '9765373098b03fb208332498f34cd4b5' # until 19.11 
  91          19: '57f009a159f55f77525cc0291e0c8b60', # starting with 19.12 
  92          20: 'baed1901ed4c2f272b56c8cb2c6d88e8', 
  93          21: 'e6a51a89dd22b75b61ead8f7083f251f', 
  94          22: 'bf45f01327fb5feb2f5d3c06ba4a6792' 
  95  } 
  96   
  97  map_schema_hash2version = { 
  98          'b09d50d7ed3f91ddf4c4ddb8ea507720': 2, 
  99          'e73718eaf230d8f1d2d01afa8462e176': 3, 
 100          '4428ccf2e54c289136819e701bb095ea': 4, 
 101          '7e7b093af57aea48c288e76632a382e5': 5, 
 102          '90e2026ac2efd236da9c8608b8685b2d': 6, 
 103          '6c9f6d3981483f8e9433df99d1947b27': 7, 
 104          '89b13a7af83337c3aad153b717e52360': 8, 
 105          '641a9b2be3c378ffc2bb2f0b1c9f051d': 9, 
 106          '7ef42a8fb2bd929a2cdd0c63864b4e8a': 10, 
 107          '03042ae24f3f92877d986fb0a6184d76': 11, 
 108          '06183a6616db62257e22814007a8ed07': 12, 
 109          'fab7c1ae408a6530c47f9b5111a0841e': 13, 
 110          'e170d543f067d1ea60bfe9076b1560cf': 14, 
 111          '70012ff960b77ecdff4981c94b5b55b6': 15, 
 112          '0bcf44ca22c479b52976e5eda1de8161': 16, 
 113          '161428ee97a00e3bf56168c3a15b7b50': 17, 
 114          'a0f9efcabdecfb4ddb6d8c0b69c02092': 18, 
 115          #'419e5225259c53dd36ad80d82066ff02': 19 # 19.0 only 
 116          #'9765373098b03fb208332498f34cd4b5': 19 # until 19.11 
 117          '57f009a159f55f77525cc0291e0c8b60': 19, # starting with 19.12 
 118          'baed1901ed4c2f272b56c8cb2c6d88e8': 20, 
 119          'e6a51a89dd22b75b61ead8f7083f251f': 21, 
 120          'bf45f01327fb5feb2f5d3c06ba4a6792': 22 
 121  } 
 122   
 123  map_client_branch2required_db_version = { 
 124          'GIT tree': 0, 
 125          'master': 0, 
 126          '0.3': 9, 
 127          '0.4': 10, 
 128          '0.5': 11, 
 129          '0.6': 12, 
 130          '0.7': 13, 
 131          '0.8': 14, 
 132          '0.9': 15, 
 133          '1.0': 16,              # intentional duplicate with 1.1 
 134          '1.1': 16, 
 135          '1.2': 17, 
 136          '1.3': 18, 
 137          '1.4': 19, 
 138          '1.5': 20, 
 139          '1.6': 21, 
 140          '1.7': 22, 
 141          '1.8': 22               # Yes, SAME as 1.7, no DB change. 
 142  } 
 143   
 144  # get columns and data types for a given table 
 145  query_table_col_defs = """select 
 146          cols.column_name, 
 147          cols.udt_name 
 148  from 
 149          information_schema.columns cols 
 150  where 
 151          cols.table_schema = %s 
 152                  and 
 153          cols.table_name = %s 
 154  order by 
 155          cols.ordinal_position""" 
 156   
 157  query_table_attributes = """select 
 158          cols.column_name 
 159  from 
 160          information_schema.columns cols 
 161  where 
 162          cols.table_schema = %s 
 163                  and 
 164          cols.table_name = %s 
 165  order by 
 166          cols.ordinal_position""" 
 167   
 168  # only works for single-column FKs but that's fine 
 169  # needs gm-dbo, any-doc won't work 
 170  SQL_foreign_key_name = """SELECT 
 171          fk_tbl.*, 
 172          (SELECT nspname FROM pg_catalog.pg_namespace WHERE oid = fk_tbl.connamespace) AS constraint_schema, 
 173          fk_tbl.conname AS constraint_name, 
 174          (SELECT nspname FROM pg_catalog.pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class where oid = fk_tbl.conrelid)) AS source_schema, 
 175          (SELECT relname FROM pg_catalog.pg_class where oid = fk_tbl.conrelid) AS source_table, 
 176          (SELECT attname FROM pg_catalog.pg_attribute WHERE attnum = fk_tbl.conkey[1] AND attrelid = (%(src_schema)s || '.' || %(src_tbl)s)::regclass) AS source_column, 
 177          (SELECT nspname FROM pg_catalog.pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class where oid = fk_tbl.confrelid)) AS target_schema, 
 178          (SELECT relname FROM pg_catalog.pg_class where oid = fk_tbl.confrelid) AS target_table, 
 179          (SELECT attname FROM pg_catalog.pg_attribute WHERE attnum = fk_tbl.confkey[1] AND attrelid = (%(target_schema)s || '.' || %(target_tbl)s)::regclass) AS target_column 
 180  FROM 
 181          pg_catalog.pg_constraint fk_tbl 
 182  WHERE 
 183          fk_tbl.contype = 'f' 
 184                  AND 
 185          fk_tbl.conrelid = (%(src_schema)s || '.' || %(src_tbl)s)::regclass 
 186                  AND 
 187          fk_tbl.conkey[1] = ( 
 188                  SELECT 
 189                          col_tbl1.attnum 
 190                  FROM 
 191                          pg_catalog.pg_attribute col_tbl1 
 192                  WHERE 
 193                          col_tbl1.attname = %(src_col)s 
 194                                  AND 
 195                          col_tbl1.attrelid = (%(src_schema)s || '.' || %(src_tbl)s)::regclass 
 196          ) 
 197                  AND 
 198          fk_tbl.confrelid = (%(target_schema)s || '.' || %(target_tbl)s)::regclass 
 199                  AND 
 200          fk_tbl.confkey[1] = ( 
 201                  SELECT 
 202                          col_tbl2.attnum 
 203                  FROM 
 204                          pg_catalog.pg_attribute col_tbl2 
 205                  WHERE 
 206                          col_tbl2.attname = %(target_col)s 
 207                                  AND 
 208                          col_tbl2.attrelid = (%(target_schema)s || '.' || %(target_tbl)s)::regclass 
 209          ) 
 210  """ 
 211   
 212  SQL_get_index_name = """ 
 213  SELECT 
 214          (SELECT nspname FROM pg_namespace WHERE pg_namespace.oid = pg_class.relnamespace) 
 215                  AS index_schema, 
 216          pg_class.relname 
 217                  AS index_name 
 218  FROM 
 219          pg_class 
 220  WHERE 
 221          pg_class.oid IN ( 
 222                  SELECT 
 223                          indexrelid 
 224                  FROM 
 225                          pg_index 
 226                  WHERE 
 227                          pg_index.indrelid = %(idx_tbl)s::regclass 
 228                                  AND 
 229                          pg_index.indnatts = 1           -- only one column in index 
 230                                  AND 
 231                          pg_index.indkey[0] IN ( 
 232                                  SELECT 
 233                                          pg_attribute.attnum 
 234                                  FROM 
 235                                          pg_attribute 
 236                                  WHERE 
 237                                          pg_attribute.attrelid = %(idx_tbl)s::regclass 
 238                                                  AND 
 239                                          pg_attribute.attname = %(idx_col)s 
 240                                  ) 
 241          ) 
 242  """ 
 243   
 244  SQL_get_pk_col_def = """ 
 245  SELECT 
 246          pg_attribute.attname 
 247                  AS pk_col, 
 248          format_type(pg_attribute.atttypid, pg_attribute.atttypmod) 
 249                  AS pk_type 
 250  FROM pg_index, pg_class, pg_attribute, pg_namespace 
 251  WHERE 
 252          pg_class.oid = %(table)s::regclass 
 253                  AND 
 254          indrelid = pg_class.oid 
 255                  AND 
 256  --      nspname = %%(schema)s 
 257  --              AND 
 258          pg_class.relnamespace = pg_namespace.oid 
 259                  AND 
 260          pg_attribute.attrelid = pg_class.oid 
 261                  AND 
 262          pg_attribute.attnum = any(pg_index.indkey) 
 263                  AND 
 264          indisprimary 
 265  """ 
 266   
 267  SQL_get_primary_key_name = """ 
 268  SELECT 
 269          is_kcu.column_name, 
 270          is_kcu.ordinal_position 
 271  FROM 
 272          information_schema.key_column_usage AS is_kcu 
 273                  LEFT JOIN information_schema.table_constraints AS is_tc ON is_tc.constraint_name = is_kcu.constraint_name 
 274  WHERE 
 275          -- constrain to current database 
 276          is_tc.table_catalog = current_database() 
 277                  AND 
 278          is_tc.table_schema = %(schema)s 
 279                  AND 
 280          is_tc.table_name = %(table)s 
 281                  AND 
 282          is_tc.constraint_type = 'PRIMARY KEY'; 
 283  """ 
 284   
 285  # ======================================================================= 
 286  # login API 
 287  # ======================================================================= 
288 -def __request_login_params_tui():
289 """Text mode request of database login parameters""" 290 291 import getpass 292 login = gmLoginInfo.LoginInfo() 293 294 print("\nPlease enter the required login parameters:") 295 try: 296 login.host = prompted_input(prompt = "host ('' = non-TCP/IP)", default = '') 297 login.database = prompted_input(prompt = "database", default = default_database) 298 login.user = prompted_input(prompt = "user name", default = '') 299 tmp = 'password for "%s" (not shown): ' % login.user 300 login.password = getpass.getpass(tmp) 301 gmLog2.add_word2hide(login.password) 302 login.port = prompted_input(prompt = "port", default = 5432) 303 except KeyboardInterrupt: 304 _log.warning("user cancelled text mode login dialog") 305 print("user cancelled text mode login dialog") 306 raise gmExceptions.ConnectionError(_("Cannot connect to database without login information!")) 307 308 creds = gmConnectionPool.cPGCredentials() 309 creds.database = login.database 310 creds.host = login.host 311 creds.port = login.port 312 creds.user = login.user 313 creds.password = login.password 314 315 return login, creds
316 317 #---------------------------------------------------
318 -def __request_login_params_gui_wx():
319 """GUI (wx) input request for database login parameters. 320 321 Returns gmLoginInfo.LoginInfo object 322 """ 323 import wx 324 # OK, wxPython was already loaded. But has the main Application instance 325 # been initialized yet ? if not, the exception will kick us out 326 if wx.GetApp() is None: 327 raise AssertionError(_("The wxPython GUI framework hasn't been initialized yet!")) 328 329 # Let's launch the login dialog 330 # if wx was not initialized /no main App loop, an exception should be raised anyway 331 import gmAuthWidgets 332 dlg = gmAuthWidgets.cLoginDialog(None, -1) 333 dlg.ShowModal() 334 login = dlg.panel.GetLoginInfo() 335 dlg.DestroyLater() 336 #if user cancelled or something else went wrong, raise an exception 337 if login is None: 338 raise gmExceptions.ConnectionError(_("Can't connect to database without login information!")) 339 340 gmLog2.add_word2hide(login.password) 341 creds = gmConnectionPool.cPGCredentials() 342 creds.database = login.database 343 creds.host = login.host 344 creds.port = login.port 345 creds.user = login.user 346 creds.password = login.password 347 return login, creds
348 349 #---------------------------------------------------
350 -def request_login_params():
351 """Request login parameters for database connection.""" 352 353 # are we inside X ? 354 # if we aren't wxGTK will crash hard at the C-level with "can't open Display" 355 if 'DISPLAY' in os.environ: 356 # try wxPython GUI 357 try: 358 return __request_login_params_gui_wx() 359 except Exception: 360 pass 361 362 # well, either we are on the console or 363 # wxPython does not work, use text mode 364 return __request_login_params_tui()
365 366 # ======================================================================= 367 # netadata API 368 # =======================================================================
369 -def database_schema_compatible(link_obj=None, version=None, verbose=True):
370 expected_hash = known_schema_hashes[version] 371 if version == 0: 372 args = {'ver': 9999} 373 else: 374 args = {'ver': version} 375 rows, idx = run_ro_queries ( 376 link_obj = link_obj, 377 queries = [{ 378 'cmd': 'select md5(gm.concat_table_structure(%(ver)s::integer)) as md5', 379 'args': args 380 }] 381 ) 382 if rows[0]['md5'] != expected_hash: 383 _log.error('database schema version mismatch') 384 _log.error('expected: %s (%s)' % (version, expected_hash)) 385 _log.error('detected: %s (%s)' % (get_schema_version(link_obj=link_obj), rows[0]['md5'])) 386 if verbose: 387 _log.debug('schema dump follows:') 388 for line in get_schema_structure(link_obj = link_obj).split(): 389 _log.debug(line) 390 _log.debug('schema revision history dump follows:') 391 for line in get_schema_revision_history(link_obj = link_obj): 392 _log.debug(' - '.join(line)) 393 return False 394 _log.info('detected schema version [%s], hash [%s]' % (map_schema_hash2version[rows[0]['md5']], rows[0]['md5'])) 395 return True
396 397 #------------------------------------------------------------------------
398 -def get_schema_version(link_obj=None):
399 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select md5(gm.concat_table_structure()) as md5'}]) 400 try: 401 return map_schema_hash2version[rows[0]['md5']] 402 except KeyError: 403 return 'unknown database schema version, MD5 hash is [%s]' % rows[0]['md5']
404 405 #------------------------------------------------------------------------
406 -def get_schema_structure(link_obj=None):
407 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select gm.concat_table_structure()'}]) 408 return rows[0][0]
409 410 #------------------------------------------------------------------------
411 -def get_schema_hash(link_obj=None):
412 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select md5(gm.concat_table_structure()) as md5'}]) 413 return rows[0]['md5']
414 415 #------------------------------------------------------------------------
416 -def get_schema_revision_history(link_obj=None):
417 418 if table_exists(link_obj = link_obj, schema = 'gm', table = 'schema_revision'): 419 cmd = """ 420 SELECT 421 imported::text, 422 version, 423 filename 424 FROM gm.schema_revision 425 ORDER BY imported""" 426 elif table_exists(link_obj = link_obj, schema = 'public', table = 'gm_schema_revision'): 427 cmd = """ 428 SELECT 429 imported::text, 430 version, 431 filename 432 FROM public.gm_schema_revision 433 ORDER BY imported""" 434 else: 435 return [] 436 437 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd}]) 438 return rows
439 #------------------------------------------------------------------------
440 -def get_current_user():
441 rows, idx = run_ro_queries(queries = [{'cmd': 'select CURRENT_USER'}]) 442 return rows[0][0]
443 444 #------------------------------------------------------------------------
445 -def get_foreign_keys2column(schema='public', table=None, column=None, link_obj=None):
446 """Get the foreign keys pointing to schema.table.column. 447 448 Does not properly work with multi-column FKs. 449 GNUmed doesn't use any, however. 450 """ 451 args = { 452 'schema': schema, 453 'tbl': table, 454 'col': column 455 } 456 cmd = """ 457 SELECT 458 %(schema)s AS referenced_schema, 459 %(tbl)s AS referenced_table, 460 %(col)s AS referenced_column, 461 pgc.confkey AS referenced_column_list, 462 463 pgc.conrelid::regclass AS referencing_table, 464 pgc.conkey AS referencing_column_list, 465 (select attname from pg_attribute where attnum = pgc.conkey[1] and attrelid = pgc.conrelid) AS referencing_column 466 FROM 467 pg_constraint pgc 468 WHERE 469 pgc.contype = 'f' 470 AND 471 pgc.confrelid = ( 472 select oid from pg_class where relname = %(tbl)s and relnamespace = ( 473 select oid from pg_namespace where nspname = %(schema)s 474 ) 475 ) and 476 ( 477 select attnum 478 from pg_attribute 479 where 480 attrelid = (select oid from pg_class where relname = %(tbl)s and relnamespace = ( 481 select oid from pg_namespace where nspname = %(schema)s 482 )) 483 and 484 attname = %(col)s 485 ) = any(pgc.confkey) 486 """ 487 rows, idx = run_ro_queries ( 488 link_obj = link_obj, 489 queries = [ 490 {'cmd': cmd, 'args': args} 491 ] 492 ) 493 494 return rows
495 496 #------------------------------------------------------------------------
497 -def get_index_name(indexed_table=None, indexed_column=None, link_obj=None):
498 499 args = { 500 'idx_tbl': indexed_table, 501 'idx_col': indexed_column 502 } 503 rows, idx = run_ro_queries ( 504 link_obj = link_obj, 505 queries = [{'cmd': SQL_get_index_name, 'args': args}], 506 get_col_idx = False 507 ) 508 509 return rows
510 511 #------------------------------------------------------------------------
512 -def get_foreign_key_names(src_schema=None, src_table=None, src_column=None, target_schema=None, target_table=None, target_column=None, link_obj=None):
513 514 args = { 515 'src_schema': src_schema, 516 'src_tbl': src_table, 517 'src_col': src_column, 518 'target_schema': target_schema, 519 'target_tbl': target_table, 520 'target_col': target_column 521 } 522 523 rows, idx = run_ro_queries ( 524 link_obj = link_obj, 525 queries = [{'cmd': SQL_foreign_key_name, 'args': args}], 526 get_col_idx = False 527 ) 528 529 return rows
530 531 #------------------------------------------------------------------------
532 -def get_child_tables(schema='public', table=None, link_obj=None):
533 """Return child tables of <table>.""" 534 cmd = """ 535 select 536 pgn.nspname as namespace, 537 pgc.relname as table 538 from 539 pg_namespace pgn, 540 pg_class pgc 541 where 542 pgc.relnamespace = pgn.oid 543 and 544 pgc.oid in ( 545 select inhrelid from pg_inherits where inhparent = ( 546 select oid from pg_class where 547 relnamespace = (select oid from pg_namespace where nspname = %(schema)s) and 548 relname = %(table)s 549 ) 550 )""" 551 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': {'schema': schema, 'table': table}}]) 552 return rows
553 554 #------------------------------------------------------------------------
555 -def schema_exists(link_obj=None, schema='gm'):
556 cmd = """SELECT EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = %(schema)s)""" 557 args = {'schema': schema} 558 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}]) 559 return rows[0][0]
560 561 #------------------------------------------------------------------------
562 -def table_exists(link_obj=None, schema=None, table=None):
563 """Returns false, true.""" 564 cmd = """ 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 #------------------------------------------------------------------------
576 -def function_exists(link_obj=None, schema=None, function=None):
577 578 cmd = """ 579 SELECT EXISTS ( 580 SELECT 1 FROM pg_proc 581 WHERE proname = %(func)s AND pronamespace = (SELECT oid FROM pg_namespace WHERE nspname = %(schema)s) 582 ) 583 """ 584 args = { 585 'func': function, 586 'schema': schema 587 } 588 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}]) 589 return rows[0][0]
590 591 #------------------------------------------------------------------------
592 -def get_col_indices(cursor = None):
593 if cursor.description is None: 594 _log.error('no result description available: unused cursor or last query did not select rows') 595 return None 596 col_indices = {} 597 col_index = 0 598 for col_desc in cursor.description: 599 col_name = col_desc[0] 600 # a query like "select 1,2;" will return two columns of the same name ! 601 # hence adjust to that, note, however, that dict-style access won't work 602 # on results of such queries ... 603 if col_name in col_indices: 604 col_name = '%s_%s' % (col_name, col_index) 605 col_indices[col_name] = col_index 606 col_index += 1 607 608 return col_indices
609 #------------------------------------------------------------------------
610 -def get_col_defs(link_obj=None, schema='public', table=None):
611 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_col_defs, 'args': (schema, table)}]) 612 col_names = [] 613 col_type = {} 614 for row in rows: 615 col_names.append(row[0]) 616 # map array types 617 if row[1].startswith('_'): 618 col_type[row[0]] = row[1][1:] + '[]' 619 else: 620 col_type[row[0]] = row[1] 621 col_defs = [] 622 col_defs.append(col_names) 623 col_defs.append(col_type) 624 return col_defs
625 #------------------------------------------------------------------------
626 -def get_col_names(link_obj=None, schema='public', table=None):
627 """Return column attributes of table""" 628 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_attributes, 'args': (schema, table)}]) 629 cols = [] 630 for row in rows: 631 cols.append(row[0]) 632 return cols
633 634 #------------------------------------------------------------------------ 635 # i18n functions 636 #------------------------------------------------------------------------
637 -def export_translations_from_database(filename=None):
638 tx_file = open(filename, mode = 'wt', encoding = 'utf8') 639 tx_file.write('-- GNUmed database string translations exported %s\n' % gmDateTime.pydt_now_here().strftime('%Y-%m-%d %H:%M')) 640 tx_file.write('-- - contains translations for each of [%s]\n' % ', '.join(get_translation_languages())) 641 tx_file.write('-- - user database language is set to [%s]\n\n' % get_current_user_language()) 642 tx_file.write('-- Please email this file to <gnumed-devel@gnu.org>.\n') 643 tx_file.write('-- ----------------------------------------------------------------------------------------------\n\n') 644 tx_file.write('set default_transaction_read_only to off;\n\n') 645 tx_file.write("set client_encoding to 'utf-8';\n\n") 646 tx_file.write('\\unset ON_ERROR_STOP\n\n') 647 648 cmd = 'SELECT lang, orig, trans FROM i18n.translations ORDER BY lang, orig' 649 rows, idx = run_ro_queries(queries = [{'cmd': cmd}], get_col_idx = False) 650 for row in rows: 651 line = "select i18n.upd_tx(E'%s', E'%s', E'%s');\n" % ( 652 row['lang'].replace("'", "\\'"), 653 row['orig'].replace("'", "\\'"), 654 row['trans'].replace("'", "\\'") 655 ) 656 tx_file.write(line) 657 tx_file.write('\n') 658 659 tx_file.write('\set ON_ERROR_STOP 1\n') 660 tx_file.close() 661 662 return True
663 664 #------------------------------------------------------------------------
665 -def delete_translation_from_database(link_obj=None, language=None, original=None):
666 cmd = 'DELETE FROM i18n.translations WHERE lang = %(lang)s AND orig = %(orig)s' 667 args = {'lang': language, 'orig': original} 668 run_rw_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}], return_data = False, end_tx = True) 669 return True
670 671 #------------------------------------------------------------------------
672 -def update_translation_in_database(language=None, original=None, translation=None, link_obj=None):
673 if language is None: 674 cmd = 'SELECT i18n.upd_tx(%(orig)s, %(trans)s)' 675 else: 676 cmd = 'SELECT i18n.upd_tx(%(lang)s, %(orig)s, %(trans)s)' 677 args = {'lang': language, 'orig': original, 'trans': translation} 678 run_rw_queries(queries = [{'cmd': cmd, 'args': args}], return_data = False, link_obj = link_obj) 679 return args
680 681 #------------------------------------------------------------------------
682 -def get_translation_languages():
683 rows, idx = run_ro_queries ( 684 queries = [{'cmd': 'select distinct lang from i18n.translations'}] 685 ) 686 return [ r[0] for r in rows ]
687 688 #------------------------------------------------------------------------
689 -def get_database_translations(language=None, order_by=None):
690 691 args = {'lang': language} 692 _log.debug('language [%s]', language) 693 694 if order_by is None: 695 order_by = 'ORDER BY %s' % order_by 696 else: 697 order_by = 'ORDER BY lang, orig' 698 699 if language is None: 700 cmd = """ 701 SELECT DISTINCT ON (orig, lang) 702 lang, orig, trans 703 FROM (( 704 705 -- strings stored as translation keys whether translated or not 706 SELECT 707 NULL as lang, 708 ik.orig, 709 NULL AS trans 710 FROM 711 i18n.keys ik 712 713 ) UNION ALL ( 714 715 -- already translated strings 716 SELECT 717 it.lang, 718 it.orig, 719 it.trans 720 FROM 721 i18n.translations it 722 723 )) as translatable_strings 724 %s""" % order_by 725 else: 726 cmd = """ 727 SELECT DISTINCT ON (orig, lang) 728 lang, orig, trans 729 FROM (( 730 731 -- strings stored as translation keys whether translated or not 732 SELECT 733 %%(lang)s as lang, 734 ik.orig, 735 i18n._(ik.orig, %%(lang)s) AS trans 736 FROM 737 i18n.keys ik 738 739 ) UNION ALL ( 740 741 -- already translated strings 742 SELECT 743 %%(lang)s as lang, 744 it.orig, 745 i18n._(it.orig, %%(lang)s) AS trans 746 FROM 747 i18n.translations it 748 749 )) AS translatable_strings 750 %s""" % order_by 751 752 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False) 753 754 if rows is None: 755 _log.error('no translatable strings found') 756 else: 757 _log.debug('%s translatable strings found', len(rows)) 758 759 return rows
760 761 #------------------------------------------------------------------------
762 -def get_current_user_language():
763 cmd = 'select i18n.get_curr_lang()' 764 rows, idx = run_ro_queries(queries = [{'cmd': cmd}]) 765 return rows[0][0]
766 767 #------------------------------------------------------------------------
768 -def set_user_language(user=None, language=None):
769 """Set the user language in the database. 770 771 user = None: current db user 772 language = None: unset 773 """ 774 _log.info('setting database language for user [%s] to [%s]', user, language) 775 args = {'usr': user, 'lang': language} 776 if language is None: 777 if user is None: 778 queries = [{'cmd': 'select i18n.unset_curr_lang()'}] 779 else: 780 queries = [{'cmd': 'select i18n.unset_curr_lang(%(usr)s)', 'args': args}] 781 queries.append({'cmd': 'select True'}) 782 else: 783 if user is None: 784 queries = [{'cmd': 'select i18n.set_curr_lang(%(lang)s)', 'args': args}] 785 else: 786 queries = [{'cmd': 'select i18n.set_curr_lang(%(lang)s, %(usr)s)', 'args': args}] 787 rows, idx = run_rw_queries(queries = queries, return_data = True) 788 if not rows[0][0]: 789 _log.error('cannot set database language to [%s] for user [%s]', language, user) 790 return rows[0][0]
791 792 #------------------------------------------------------------------------
793 -def force_user_language(language=None):
794 """Set the user language in the database. 795 796 - regardless of whether there is any translation available. 797 - only for the current user 798 """ 799 _log.info('forcing database language for current db user to [%s]', language) 800 801 run_rw_queries(queries = [{ 802 'cmd': 'select i18n.force_curr_lang(%(lang)s)', 803 'args': {'lang': language} 804 }])
805 806 # ======================================================================= 807 # query runners and helpers 808 # =======================================================================
809 -def send_maintenance_notification():
810 cmd = 'notify "db_maintenance_warning"' 811 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
812 813 #------------------------------------------------------------------------
814 -def send_maintenance_shutdown():
815 cmd = 'notify "db_maintenance_disconnect"' 816 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
817 818 #------------------------------------------------------------------------
819 -def is_pg_interval(candidate=None):
820 cmd = 'SELECT %(candidate)s::interval' 821 try: 822 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}]) 823 return True 824 except Exception: 825 cmd = 'SELECT %(candidate)s::text::interval' 826 try: 827 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}]) 828 return True 829 except Exception: 830 return False
831 832 #------------------------------------------------------------------------
833 -def lock_row(link_obj=None, table=None, pk=None, exclusive=False):
834 """Uses pg_advisory(_shared). 835 836 - locks stack upon each other and need one unlock per lock 837 - same connection: 838 - all locks succeed 839 - different connections: 840 - shared + shared succeed 841 - shared + exclusive fail 842 """ 843 _log.debug('locking row: [%s] [%s] (exclusive: %s)', table, pk, exclusive) 844 if exclusive: 845 cmd = """SELECT pg_try_advisory_lock('%s'::regclass::oid::int, %s)""" % (table, pk) 846 else: 847 cmd = """SELECT pg_try_advisory_lock_shared('%s'::regclass::oid::int, %s)""" % (table, pk) 848 rows, idx = run_rw_queries(link_obj = link_obj, queries = [{'cmd': cmd}], get_col_idx = False, return_data = True) 849 if rows[0][0]: 850 return True 851 852 _log.warning('cannot lock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive) 853 return False
854 855 #------------------------------------------------------------------------
856 -def unlock_row(link_obj=None, table=None, pk=None, exclusive=False):
857 """Uses pg_advisory_unlock(_shared). 858 859 - each lock needs one unlock 860 """ 861 _log.debug('trying to unlock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive) 862 if exclusive: 863 cmd = "SELECT pg_advisory_unlock('%s'::regclass::oid::int, %s)" % (table, pk) 864 else: 865 cmd = "SELECT pg_advisory_unlock_shared('%s'::regclass::oid::int, %s)" % (table, pk) 866 rows, idx = run_rw_queries(link_obj = link_obj, queries = [{'cmd': cmd}], get_col_idx = False, return_data = True) 867 if rows[0][0]: 868 return True 869 870 _log.warning('cannot unlock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive) 871 return False
872 873 #------------------------------------------------------------------------
874 -def row_is_locked(table=None, pk=None):
875 """Looks at pk_locks 876 877 - does not take into account locks other than 'advisory', however 878 """ 879 cmd = """SELECT EXISTS ( 880 SELECT 1 FROM pg_locks WHERE 881 classid = '%s'::regclass::oid::int 882 AND 883 objid = %s 884 AND 885 locktype = 'advisory' 886 )""" % (table, pk) 887 rows, idx = run_ro_queries(queries = [{'cmd': cmd}], get_col_idx = False) 888 if rows[0][0]: 889 _log.debug('row is locked: [%s] [%s]', table, pk) 890 return True 891 _log.debug('row is NOT locked: [%s] [%s]', table, pk) 892 return False
893 894 #------------------------------------------------------------------------ 895 # BYTEA cache handling 896 #------------------------------------------------------------------------
897 -def __generate_cached_filename(cache_key_data):
898 md5 = hashlib.md5() 899 md5.update(('%s' % cache_key_data).encode('utf8')) 900 return os.path.join(gmTools.gmPaths().bytea_cache_dir, md5.hexdigest())
901 902 #------------------------------------------------------------------------
903 -def __store_file_in_cache(filename, cache_key_data):
904 cached_name = __generate_cached_filename(cache_key_data) 905 _log.debug('[%s] -> [%s] -> [%s]', filename, cache_key_data, cached_name) 906 if not gmTools.remove_file(cached_name, log_error = True, force = True): 907 _log.error('cannot remove existing file [%s] for key [%s] from cache', filename, cached_name) 908 return None 909 910 PERMS_owner_only = 0o0660 911 try: 912 shutil.copyfile(filename, cached_name, follow_symlinks = True) 913 os.chmod(cached_name, PERMS_owner_only) 914 except shutil.SameFileError: 915 _log.exception('file seems to exist in cache, despite having checked and possible removed it just before') 916 # don't use that file, it is unsafe, it might have come from 917 # a race being exploited to make us use the wrong data, this 918 # then constitutes a DOS attack against the cache but that's 919 # far less problematic than using the wrong data for care 920 return None 921 except OSError: 922 _log.exception('cannot copy file into cache: [%s] -> [%s]', filename, cached_name) 923 return None 924 except PermissionError: 925 _log.exception('cannot set cache file [%s] permissions to [%s]', cached_name, stat.filemode(PERMS_owner_only)) 926 return None 927 928 return cached_name
929 930 #------------------------------------------------------------------------
931 -def __get_filename_in_cache(cache_key_data=None, data_size=None):
932 """Calculate and verify filename in cache given cache key details.""" 933 cached_name = __generate_cached_filename(cache_key_data) 934 try: 935 stat = os.stat(cached_name) 936 except FileNotFoundError: 937 return None 938 939 _log.debug('cache hit: [%s] -> [%s] (%s)', cache_key_data, cached_name, stat) 940 if os.path.islink(cached_name) or (not os.path.isfile(cached_name)): 941 _log.error('object in cache is not a regular file: %s', cached_name) 942 _log.error('possibly an attack, removing') 943 if gmTools.remove_file(cached_name, log_error = True): 944 return None 945 946 raise Exception('cannot delete suspicious object in cache dir: %s', cached_name) 947 948 if stat.st_size == data_size: 949 return cached_name 950 951 _log.debug('size in cache [%s] <> expected size [%s], removing cached file', stat.st_size, data_size) 952 if gmTools.remove_file(cached_name, log_error = True): 953 return None 954 955 raise Exception('cannot remove suspicious object from cache dir: %s', cached_name)
956 957 #------------------------------------------------------------------------
958 -def __get_file_from_cache(filename, cache_key_data=None, data_size=None, link2cached=True):
959 """Get file from cache if available.""" 960 cached_filename = __get_filename_in_cache(cache_key_data = cache_key_data, data_size = data_size) 961 if cached_filename is None: 962 return False 963 964 if link2cached: 965 try: 966 # (hard)link as desired name, quite a few security 967 # and archival tools refuse to handle softlinks 968 os.link(cached_filename, filename) 969 _log.debug('hardlinked [%s] as [%s]', cached_filename, filename) 970 return True 971 972 except Exception: 973 pass 974 _log.debug('cannot hardlink to cache, trying copy-from-cache') 975 try: 976 shutil.copyfile(cached_filename, filename, follow_symlinks = True) 977 return True 978 979 except shutil.SameFileError: 980 # flaky - might be same name but different content 981 pass 982 except OSError: 983 _log.exception('cannot copy cached file [%s] into [%s]', cached_filename, filename) 984 # if cache fails entirely -> fall through to new file 985 _log.debug('downloading new copy of file, despite found in cache') 986 return False
987 988 #------------------------------------------------------------------------
989 -def bytea2file(data_query=None, filename=None, chunk_size=0, data_size=None, data_size_query=None, conn=None, link2cached=True):
990 991 if data_size == 0: 992 open(filename, 'wb').close() 993 return True 994 995 if data_size is None: 996 rows, idx = run_ro_queries(link_obj = conn, queries = [data_size_query]) 997 data_size = rows[0][0] 998 if data_size == 0: 999 open(filename, 'wb').close() 1000 return True 1001 1002 if data_size is None: 1003 return False 1004 1005 if conn is None: 1006 conn = gmConnectionPool.gmConnectionPool().get_connection() 1007 cache_key_data = '%s::%s' % (conn.dsn, data_query) 1008 found_in_cache = __get_file_from_cache(filename, cache_key_data = cache_key_data, data_size = data_size, link2cached = link2cached) 1009 if found_in_cache: 1010 # FIXME: start thread checking cache staleness on file 1011 return True 1012 1013 outfile = open(filename, 'wb') 1014 result = bytea2file_object ( 1015 data_query = data_query, 1016 file_obj = outfile, 1017 chunk_size = chunk_size, 1018 data_size = data_size, 1019 data_size_query = data_size_query, 1020 conn = conn 1021 ) 1022 outfile.close() 1023 __store_file_in_cache(filename, cache_key_data) 1024 return result
1025 1026 #------------------------------------------------------------------------
1027 -def bytea2file_object(data_query=None, file_obj=None, chunk_size=0, data_size=None, data_size_query=None, conn=None):
1028 """Store data from a bytea field into a file. 1029 1030 <data_query> 1031 - dict {'cmd': ..., 'args': ...} 1032 - 'cmd' must be a string containing "... substring(data from %(start)s for %(size)s) ..." 1033 - 'args' must be a dict 1034 - must return one row with one field of type bytea 1035 <file> 1036 - must be a file like Python object 1037 <data_size> 1038 - integer of the total size of the expected data or None 1039 <data_size_query> 1040 - dict {'cmd': ..., 'args': ...} 1041 - must return one row with one field with the octet_length() of the data field 1042 - used only when <data_size> is None 1043 """ 1044 if data_size == 0: 1045 return True 1046 1047 # If the client sets an encoding other than the default we 1048 # will receive encoding-parsed data which isn't the binary 1049 # content we want. Hence we need to get our own connection. 1050 # It must be a read-write one so that we don't affect the 1051 # encoding for other users of the shared read-only 1052 # connections. 1053 # Actually, encodings shouldn't be applied to binary data 1054 # (eg. bytea types) in the first place but that is only 1055 # reported to be fixed > v7.4. 1056 # further tests reveal that at least on PG 8.0 this bug still 1057 # manifests itself 1058 if conn is None: 1059 conn = get_raw_connection(readonly = True) 1060 1061 if data_size is None: 1062 rows, idx = run_ro_queries(link_obj = conn, queries = [data_size_query]) 1063 data_size = rows[0][0] 1064 if data_size in [None, 0]: 1065 conn.rollback() 1066 return True 1067 1068 max_chunk_size = 1024 * 1024 * 20 # 20 MB, works for typical CR DICOMs 1069 if chunk_size == 0: 1070 chunk_size = min(data_size, max_chunk_size) 1071 1072 _log.debug('expecting %s bytes of BYTEA data in chunks of %s bytes', data_size, chunk_size) 1073 1074 # Windoze sucks: it can't transfer objects of arbitrary size, 1075 # anyways, we need to split the transfer, 1076 # however, only possible if postgres >= 7.2 1077 needed_chunks, remainder = divmod(data_size, chunk_size) 1078 _log.debug('%s chunk(s), %s byte(s) remainder', needed_chunks, remainder) 1079 1080 # retrieve chunks, skipped if data size < chunk size, 1081 # does this not carry the danger of cutting up multi-byte escape sequences ? 1082 # no, since bytea is binary, 1083 # yes, since in bytea there are *some* escaped values, still 1084 # no, since those are only escaped during *transfer*, not on-disk, hence 1085 # only complete escape sequences are put on the wire 1086 for chunk_id in range(needed_chunks): 1087 chunk_start = (chunk_id * chunk_size) + 1 1088 data_query['args']['start'] = chunk_start 1089 data_query['args']['size'] = chunk_size 1090 try: 1091 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query]) 1092 except Exception: 1093 _log.error('cannot retrieve chunk [%s/%s], size [%s], try decreasing chunk size' % (chunk_id+1, needed_chunks, chunk_size)) 1094 conn.rollback() 1095 raise 1096 # it would be a fatal error to see more than one result as ids are supposed to be unique 1097 file_obj.write(rows[0][0]) 1098 1099 # retrieve remainder 1100 if remainder > 0: 1101 chunk_start = (needed_chunks * chunk_size) + 1 1102 data_query['args']['start'] = chunk_start 1103 data_query['args']['size'] = remainder 1104 try: 1105 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query]) 1106 except Exception: 1107 _log.error('cannot retrieve remaining [%s] bytes' % remainder) 1108 conn.rollback() 1109 raise 1110 # it would be a fatal error to see more than one result as ids are supposed to be unique 1111 file_obj.write(rows[0][0]) 1112 1113 conn.rollback() 1114 return True
1115 1116 #------------------------------------------------------------------------
1117 -def file2bytea(query=None, filename=None, args=None, conn=None, file_md5=None):
1118 """Store data from a file into a bytea field. 1119 1120 The query must: 1121 - contain a format spec identifying the row (eg a primary key) 1122 matching <args> if it is an UPDATE 1123 - contain a format spec " <field> = %(data)s::bytea" 1124 1125 The query CAN return the MD5 of the inserted data: 1126 RETURNING md5(<field>) AS md5 1127 in which case the returned hash will compared to the md5 of the file. 1128 """ 1129 retry_delay = 100 # milliseconds 1130 attempt = 0 1131 max_attempts = 3 1132 while attempt < max_attempts: 1133 attempt += 1 1134 try: 1135 infile = open(filename, "rb") 1136 except (BlockingIOError, FileNotFoundError, PermissionError): 1137 _log.exception('#%s: cannot open [%s]', attempt, filename) 1138 _log.error('retrying after %sms', retry_delay) 1139 infile = None 1140 time.sleep(retry_delay / 1000) 1141 if infile is None: 1142 return False 1143 1144 data_as_byte_string = infile.read() 1145 infile.close() 1146 if args is None: 1147 args = {} 1148 # really still needed for BYTEA input ? 1149 args['data'] = memoryview(data_as_byte_string) 1150 del(data_as_byte_string) 1151 # insert the data 1152 if conn is None: 1153 conn = get_raw_connection(readonly = False) 1154 close_conn = True 1155 else: 1156 close_conn = False 1157 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = (file_md5 is not None)) 1158 success_status = True 1159 if file_md5 is None: 1160 conn.commit() 1161 else: 1162 db_md5 = rows[0]['md5'] 1163 if file_md5 != db_md5: 1164 conn.rollback() 1165 success_status = False 1166 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5) 1167 else: 1168 conn.commit() 1169 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5) 1170 if close_conn: 1171 conn.close() 1172 return success_status
1173 1174 #------------------------------------------------------------------------
1175 -def file2lo(filename=None, conn=None, check_md5=False):
1176 # 1 GB limit unless 64 bit Python build ... 1177 file_size = os.path.getsize(filename) 1178 if file_size > (1024 * 1024) * 1024: 1179 _log.debug('file size of [%s] > 1 GB, supposedly not supported by psycopg2 large objects (but seems to work anyway ?)', file_size) 1180 # return -1 1181 1182 if conn is None: 1183 conn = get_raw_connection(readonly = False) 1184 close_conn = conn.close 1185 else: 1186 close_conn = __noop 1187 _log.debug('[%s] -> large object', filename) 1188 1189 # insert the data 1190 lo = conn.lobject(0, 'w', 0, filename) 1191 lo_oid = lo.oid 1192 lo.close() 1193 _log.debug('large object OID: %s', lo_oid) 1194 1195 # verify 1196 if file_md5 is None: 1197 conn.commit() 1198 close_conn() 1199 return lo_oid 1200 cmd = 'SELECT md5(lo_get(%(loid)s::oid))' 1201 args = {'loid': lo_oid} 1202 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': cmd, 'args': args}]) 1203 db_md5 = rows[0][0] 1204 if file_md5 == db_md5: 1205 conn.commit() 1206 close_conn() 1207 _log.debug('MD5 sums of data file and database large object match: [file::%s] = [DB::%s]', file_md5, db_md5) 1208 return lo_oid 1209 conn.rollback() 1210 close_conn() 1211 _log.error('MD5 sums of data file and database large object [%s] do not match: [file::%s] <> [DB::%s]', lo_oid, file_md5, db_md5) 1212 return -1
1213 1214 #------------------------------------------------------------------------
1215 -def file2bytea_lo(filename=None, conn=None, file_md5=None):
1216 # 1 GB limit unless 64 bit Python build ... 1217 file_size = os.path.getsize(filename) 1218 if file_size > (1024 * 1024) * 1024: 1219 _log.debug('file size of [%s] > 1 GB, supposedly not supported by psycopg2 large objects (but seems to work anyway ?)', file_size) 1220 # return -1 1221 1222 if conn is None: 1223 conn = get_raw_connection(readonly = False) 1224 close_conn = conn.close 1225 else: 1226 close_conn = __noop 1227 _log.debug('[%s] -> large object', filename) 1228 1229 # insert the data 1230 lo = conn.lobject(0, 'w', 0, filename) 1231 lo_oid = lo.oid 1232 lo.close() 1233 _log.debug('large object OID: %s', lo_oid) 1234 1235 # verify 1236 if file_md5 is None: 1237 conn.commit() 1238 close_conn() 1239 return lo_oid 1240 cmd = 'SELECT md5(lo_get(%(loid)s::oid))' 1241 args = {'loid': lo_oid} 1242 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': cmd, 'args': args}]) 1243 db_md5 = rows[0][0] 1244 if file_md5 == db_md5: 1245 conn.commit() 1246 close_conn() 1247 _log.debug('MD5 sums of data file and database large object match: [file::%s] = [DB::%s]', file_md5, db_md5) 1248 return lo_oid 1249 conn.rollback() 1250 close_conn() 1251 _log.error('MD5 sums of data file and database large object [%s] do not match: [file::%s] <> [DB::%s]', lo_oid, file_md5, db_md5) 1252 return -1
1253 1254 #------------------------------------------------------------------------
1255 -def file2bytea_copy_from(table=None, columns=None, filename=None, conn=None, md5_query=None, file_md5=None):
1256 # md5_query: dict{'cmd': ..., 'args': ...} 1257 1258 # UNTESTED 1259 1260 chunk_size = 32 * (1024 * 1024) 1261 _log.debug('[%s] (%s bytes) --(%s bytes)-> %s(%s)', filename, os.path.getsize(filename), chunk_size, table, columns) 1262 if conn is None: 1263 conn = get_raw_connection(readonly = False) 1264 close_conn = True 1265 else: 1266 close_conn = False 1267 curs = conn.cursor() 1268 # write 1269 infile = open(filename, "rb") 1270 curs.copy_from(infile, table, size = chunk_size, columns = columns) 1271 infile.close() 1272 curs.close() 1273 if None in [file_md5, md5_query]: 1274 conn.commit() 1275 close_conn() 1276 return True 1277 # verify 1278 rows, idx = run_ro_queries(link_obj = conn, queries = [md5_query]) 1279 db_md5 = rows[0][0] 1280 if file_md5 == db_md5: 1281 conn.commit() 1282 close_conn() 1283 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5) 1284 return True 1285 close_conn() 1286 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5) 1287 return False
1288 1289 #------------------------------------------------------------------------
1290 -def file2bytea_overlay(query=None, args=None, filename=None, conn=None, md5_query=None, file_md5=None):
1291 """Store data from a file into a bytea field. 1292 1293 The query must: 1294 - 'cmd' must be in unicode 1295 - 'cmd' must contain a format spec identifying the row (eg 1296 a primary key) matching <args> if it is an UPDATE 1297 - 'cmd' must contain "... SET ... <some_bytea_field> = OVERLAY(some_bytea_field PLACING %(data)s::bytea FROM %(start)s FOR %(size)s) ..." 1298 - 'args' must be a dict matching 'cmd' 1299 1300 The query CAN return the MD5 of the inserted data: 1301 RETURNING md5(<field>) AS md5 1302 in which case it will compare it to the md5 1303 of the file. 1304 1305 UPDATE 1306 the_table 1307 SET 1308 bytea_field = OVERLAY ( 1309 coalesce(bytea_field, '':bytea), 1310 PLACING 1311 %(data)s::bytea 1312 FROM 1313 %(start)s 1314 FOR 1315 %(size)s 1316 ) 1317 WHERE 1318 primary_key = pk_value 1319 1320 SELECT md5(bytea_field) FROM the_table WHERE primary_key = pk_value 1321 """ 1322 chunk_size = 32 * (1024 * 1024) 1323 file_size = os.path.getsize(filename) 1324 if file_size <= chunk_size: 1325 chunk_size = file_size 1326 needed_chunks, remainder = divmod(file_size, chunk_size) 1327 _log.debug('file data: %s bytes, chunks: %s, chunk size: %s bytes, remainder: %s bytes', file_size, needed_chunks, chunk_size, remainder) 1328 1329 if conn is None: 1330 conn = get_raw_connection(readonly = False) 1331 close_conn = conn.close 1332 else: 1333 close_conn = __noop 1334 1335 infile = open(filename, "rb") 1336 # write chunks 1337 for chunk_id in range(needed_chunks): 1338 chunk_start = (chunk_id * chunk_size) + 1 1339 args['start'] = chunk_start 1340 args['size'] = chunk_size 1341 data_as_byte_string = infile.read(chunk_size) 1342 # really still needed for BYTEA input ? 1343 args['data'] = memoryview(data_as_byte_string) 1344 del(data_as_byte_string) 1345 try: 1346 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = False) 1347 except Exception: 1348 _log.exception('cannot write chunk [%s/%s] of size [%s], try decreasing chunk size', chunk_id+1, needed_chunks, chunk_size) 1349 conn.rollback() 1350 close_conn() 1351 infile.close() 1352 raise 1353 # write remainder 1354 if remainder > 0: 1355 chunk_start = (needed_chunks * chunk_size) + 1 1356 args['start'] = chunk_start 1357 args['size'] = remainder 1358 data_as_byte_string = infile.read(remainder) 1359 # really still needed for BYTEA input ? 1360 args['data'] = memoryview(data_as_byte_string) 1361 del(data_as_byte_string) 1362 try: 1363 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = False) 1364 except Exception: 1365 _log.error('cannot retrieve remaining [%s] bytes' % remainder) 1366 conn.rollback() 1367 close_conn() 1368 infile.close() 1369 raise 1370 infile.close() 1371 if None in [file_md5, md5_query]: 1372 conn.commit() 1373 close_conn() 1374 return True 1375 # verify 1376 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': md5_query, 'args': args}]) 1377 db_md5 = rows[0][0] 1378 if file_md5 == db_md5: 1379 conn.commit() 1380 close_conn() 1381 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5) 1382 return True 1383 close_conn() 1384 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5) 1385 return False
1386 1387 #------------------------------------------------------------------------
1388 -def read_all_rows_of_table(schema=None, table=None):
1389 if schema is None: 1390 schema = prompted_input(prompt = 'schema for table to dump', default = None) 1391 if schema is None: 1392 _log.debug('aborted by user (no schema entered)') 1393 return None 1394 1395 if table is None: 1396 table = prompted_input(prompt = 'table to dump (in schema %s.)' % schema, default = None) 1397 if table is None: 1398 _log.debug('aborted by user (no table entered)') 1399 return None 1400 1401 _log.debug('dumping <%s.%s>', schema, table) 1402 conn = get_connection(readonly=True, verbose = False, pooled = True, connection_name = 'read_all_rows_of_table') 1403 # get pk column name 1404 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': SQL_get_primary_key_name, 'args': {'schema': schema, 'table': table}}]) 1405 if rows: 1406 _log.debug('primary key def: %s', rows) 1407 if len(rows) > 1: 1408 _log.error('cannot handle multi-column primary key') 1409 return False 1410 1411 pk_name = rows[0][0] 1412 else: 1413 _log.debug('cannot determine primary key, asking user') 1414 pk_name = prompted_input(prompt = 'primary key name for %s.%s' % (schema, table), default = None) 1415 if pk_name is None: 1416 _log.debug('aborted by user (no primary key name entered)') 1417 return None 1418 1419 # get PK values 1420 qualified_table = '%s.%s' % (schema, table) 1421 qualified_pk_name = '%s.%s.%s' % (schema, table, pk_name) 1422 cmd = psysql.SQL('SELECT {schema_table_pk} FROM {schema_table} ORDER BY 1'.format ( 1423 schema_table_pk = qualified_pk_name, 1424 schema_table = qualified_table 1425 )) 1426 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': cmd}]) 1427 if not rows: 1428 _log.debug('no rows to dump') 1429 return True 1430 1431 # dump table rows 1432 _log.debug('dumping %s rows', len(rows)) 1433 cmd = psysql.SQL('SELECT * FROM {schema_table} WHERE {schema_table_pk} = %(pk_val)s'.format ( 1434 schema_table = qualified_table, 1435 schema_table_pk = qualified_pk_name 1436 )) 1437 found_errors = False 1438 idx = 0 1439 for row in rows: 1440 idx += 1 1441 args = {'pk_val': row[0]} 1442 _log.debug('dumping row #%s with pk [%s]', idx, row[0]) 1443 try: 1444 run_ro_queries(link_obj = conn, queries = [{'cmd': cmd, 'args': args}]) 1445 except dbapi.InternalError: 1446 found_errors = True 1447 _log.exception('error dumping row') 1448 print('ERROR: cannot dump row %s of %s with pk %s = %s', idx, len(rows), qualified_pk_name, rows[0]) 1449 1450 return found_errors is False
1451 1452 #------------------------------------------------------------------------ 1453 #------------------------------------------------------------------------
1454 -def run_sql_script(sql_script, conn=None):
1455 1456 if conn is None: 1457 conn = get_connection(readonly = False) 1458 1459 from Gnumed.pycommon import gmPsql 1460 psql = gmPsql.Psql(conn) 1461 1462 if psql.run(sql_script) == 0: 1463 query = { 1464 'cmd': 'select gm.log_script_insertion(%(name)s, %(ver)s)', 1465 'args': {'name': sql_script, 'ver': 'current'} 1466 } 1467 run_rw_queries(link_obj = conn, queries = [query]) 1468 conn.commit() 1469 return True 1470 1471 _log.error('error running sql script: %s', sql_script) 1472 return False
1473 1474 #------------------------------------------------------------------------
1475 -def sanitize_pg_regex(expression=None, escape_all=False):
1476 """Escape input for use in a PostgreSQL regular expression. 1477 1478 If a fragment comes from user input and is to be used 1479 as a regular expression we need to make sure it doesn't 1480 contain invalid regex patterns such as unbalanced ('s. 1481 1482 <escape_all> 1483 True: try to escape *all* metacharacters 1484 False: only escape those which render the regex invalid 1485 """ 1486 return expression.replace ( 1487 '(', '\(' 1488 ).replace ( 1489 ')', '\)' 1490 ).replace ( 1491 '[', '\[' 1492 ).replace ( 1493 '+', '\+' 1494 ).replace ( 1495 '.', '\.' 1496 ).replace ( 1497 '*', '\*' 1498 ).replace ( 1499 '?', '\?' 1500 )
1501 #']', '\]', # not needed 1502 1503 #------------------------------------------------------------------------
1504 -def run_ro_queries(link_obj=None, queries=None, verbose=False, return_data=True, get_col_idx=False):
1505 """Run read-only queries. 1506 1507 <queries> must be a list of dicts: 1508 [ 1509 {'cmd': <string>, 'args': <dict> or <tuple>}, 1510 {...}, 1511 ... 1512 ] 1513 """ 1514 if isinstance(link_obj, dbapi._psycopg.cursor): 1515 curs = link_obj 1516 curs_close = lambda *x:None 1517 tx_rollback = lambda *x:None 1518 readonly_rollback_just_in_case = lambda *x:None 1519 elif isinstance(link_obj, dbapi._psycopg.connection): 1520 curs = link_obj.cursor() 1521 curs_close = curs.close 1522 tx_rollback = link_obj.rollback 1523 if link_obj.autocommit is True: # readonly connection ? 1524 readonly_rollback_just_in_case = link_obj.rollback 1525 else: 1526 # do not rollback readonly queries on passed-in readwrite 1527 # connections just in case because they may have already 1528 # seen fully legitimate write action which would get lost 1529 readonly_rollback_just_in_case = lambda *x:None 1530 elif link_obj is None: 1531 conn = get_connection(readonly = True, verbose = verbose) 1532 curs = conn.cursor() 1533 curs_close = curs.close 1534 tx_rollback = conn.rollback 1535 readonly_rollback_just_in_case = conn.rollback 1536 else: 1537 raise ValueError('link_obj must be cursor, connection or None but not [%s]' % link_obj) 1538 1539 if verbose: 1540 _log.debug('cursor: %s', curs) 1541 1542 for query in queries: 1543 try: 1544 args = query['args'] 1545 except KeyError: 1546 args = None 1547 try: 1548 curs.execute(query['cmd'], args) 1549 if verbose: 1550 gmConnectionPool.log_cursor_state(curs) 1551 except PG_ERROR_EXCEPTION as pg_exc: 1552 _log.error('query failed in RO connection') 1553 gmConnectionPool.log_pg_exception_details(pg_exc) 1554 try: 1555 curs_close() 1556 except PG_ERROR_EXCEPTION as pg_exc2: 1557 _log.exception('cannot close cursor') 1558 gmConnectionPool.log_pg_exception_details(pg_exc2) 1559 try: 1560 tx_rollback() # need to rollback so ABORT state isn't preserved in pooled conns 1561 except PG_ERROR_EXCEPTION as pg_exc2: 1562 _log.exception('cannot rollback transaction') 1563 gmConnectionPool.log_pg_exception_details(pg_exc2) 1564 if pg_exc.pgcode == sql_error_codes.INSUFFICIENT_PRIVILEGE: 1565 details = 'Query: [%s]' % curs.query.strip().strip('\n').strip().strip('\n') 1566 if curs.statusmessage != '': 1567 details = 'Status: %s\n%s' % ( 1568 curs.statusmessage.strip().strip('\n').strip().strip('\n'), 1569 details 1570 ) 1571 if pg_exc.pgerror is None: 1572 msg = '[%s]' % pg_exc.pgcode 1573 else: 1574 msg = '[%s]: %s' % (pg_exc.pgcode, pg_exc.pgerror) 1575 raise gmExceptions.AccessDenied ( 1576 msg, 1577 source = 'PostgreSQL', 1578 code = pg_exc.pgcode, 1579 details = details 1580 ) 1581 raise 1582 except Exception: 1583 _log.exception('error during query run in RO connection') 1584 gmConnectionPool.log_cursor_state(curs) 1585 try: 1586 curs_close() 1587 except PG_ERROR_EXCEPTION as pg_exc: 1588 _log.exception('cannot close cursor') 1589 gmConnectionPool.log_pg_exception_details(pg_exc) 1590 try: 1591 tx_rollback() # need to rollback so ABORT state isn't preserved in pooled conns 1592 except PG_ERROR_EXCEPTION as pg_exc: 1593 _log.exception('cannot rollback transation') 1594 gmConnectionPool.log_pg_exception_details(pg_exc) 1595 raise 1596 1597 data = None 1598 col_idx = None 1599 if return_data: 1600 data = curs.fetchall() 1601 if verbose: 1602 _log.debug('last query returned [%s (%s)] rows', curs.rowcount, len(data)) 1603 _log.debug('cursor description: %s', curs.description) 1604 if get_col_idx: 1605 col_idx = get_col_indices(curs) 1606 1607 curs_close() 1608 # so we can see data committed meanwhile if the 1609 # link object had been passed in and thusly might 1610 # be part of a long-running read-only transaction 1611 readonly_rollback_just_in_case() 1612 return (data, col_idx)
1613 1614 #------------------------------------------------------------------------
1615 -def run_rw_queries(link_obj=None, queries=None, end_tx=False, return_data=None, get_col_idx=False, verbose=False):
1616 """Convenience function for running a transaction 1617 that is supposed to get committed. 1618 1619 <link_obj> 1620 can be either: 1621 - a cursor 1622 - a connection 1623 1624 <queries> 1625 is a list of dicts [{'cmd': <string>, 'args': <dict> or <tuple>) 1626 to be executed as a single transaction, the last 1627 query may usefully return rows (such as a 1628 "SELECT currval('some_sequence')" statement) 1629 1630 <end_tx> 1631 - controls whether the transaction is finalized (eg. 1632 COMMITted/ROLLed BACK) or not, this allows the 1633 call to run_rw_queries() to be part of a framing 1634 transaction 1635 - if link_obj is a *connection* then <end_tx> will 1636 default to False unless it is explicitly set to 1637 True which is taken to mean "yes, you do have full 1638 control over the transaction" in which case the 1639 transaction is properly finalized 1640 - if link_obj is a *cursor* we CANNOT finalize the 1641 transaction because we would need the connection for that 1642 - if link_obj is *None* <end_tx> will, of course, always be True 1643 1644 <return_data> 1645 - if true, the returned data will include the rows 1646 the last query selected 1647 - if false, it returns None instead 1648 1649 <get_col_idx> 1650 - if true, the returned data will include a dictionary 1651 mapping field names to column positions 1652 - if false, the returned data returns None instead 1653 1654 method result: 1655 - returns a tuple (data, idx) 1656 - <data>: 1657 * (None, None) if last query did not return rows 1658 * ("fetchall() result", <index>) if last query returned any rows 1659 * for <index> see <get_col_idx> 1660 """ 1661 if isinstance(link_obj, dbapi._psycopg.cursor): 1662 conn_close = lambda *x:None 1663 conn_commit = lambda *x:None 1664 tx_rollback = lambda *x:None 1665 curs = link_obj 1666 curs_close = lambda *x:None 1667 notices_accessor = curs.connection 1668 elif isinstance(link_obj, dbapi._psycopg.connection): 1669 conn_close = lambda *x:None 1670 if end_tx: 1671 conn_commit = link_obj.commit 1672 tx_rollback = link_obj.rollback 1673 else: 1674 conn_commit = lambda *x:None 1675 tx_rollback = lambda *x:None 1676 curs = link_obj.cursor() 1677 curs_close = curs.close 1678 notices_accessor = link_obj 1679 elif link_obj is None: 1680 conn = get_connection(readonly=False) 1681 conn_close = conn.close 1682 conn_commit = conn.commit 1683 tx_rollback = conn.rollback 1684 curs = conn.cursor() 1685 curs_close = curs.close 1686 notices_accessor = conn 1687 else: 1688 raise ValueError('link_obj must be cursor, connection or None but not [%s]' % link_obj) 1689 1690 for query in queries: 1691 try: 1692 args = query['args'] 1693 except KeyError: 1694 args = None 1695 try: 1696 curs.execute(query['cmd'], args) 1697 if verbose: 1698 gmConnectionPool.log_cursor_state(curs) 1699 for notice in notices_accessor.notices: 1700 _log.debug(notice.replace('\n', '/').replace('\n', '/')) 1701 del notices_accessor.notices[:] 1702 # DB related exceptions 1703 except dbapi.Error as pg_exc: 1704 _log.error('query failed in RW connection') 1705 gmConnectionPool.log_pg_exception_details(pg_exc) 1706 for notice in notices_accessor.notices: 1707 _log.debug(notice.replace('\n', '/').replace('\n', '/')) 1708 del notices_accessor.notices[:] 1709 try: 1710 curs_close() 1711 except PG_ERROR_EXCEPTION as pg_exc2: 1712 _log.exception('cannot close cursor') 1713 gmConnectionPool.log_pg_exception_details(pg_exc2) 1714 try: 1715 tx_rollback() # need to rollback so ABORT state isn't preserved in pooled conns 1716 except PG_ERROR_EXCEPTION as pg_exc2: 1717 _log.exception('cannot rollback transaction') 1718 gmConnectionPool.log_pg_exception_details(pg_exc2) 1719 # privilege problem 1720 if pg_exc.pgcode == sql_error_codes.INSUFFICIENT_PRIVILEGE: 1721 details = 'Query: [%s]' % curs.query.strip().strip('\n').strip().strip('\n') 1722 if curs.statusmessage != '': 1723 details = 'Status: %s\n%s' % ( 1724 curs.statusmessage.strip().strip('\n').strip().strip('\n'), 1725 details 1726 ) 1727 if pg_exc.pgerror is None: 1728 msg = '[%s]' % pg_exc.pgcode 1729 else: 1730 msg = '[%s]: %s' % (pg_exc.pgcode, pg_exc.pgerror) 1731 try: 1732 curs_close() 1733 tx_rollback() # just for good measure 1734 conn_close() 1735 except dbapi.InterfaceError: 1736 _log.exception('cannot cleanup') 1737 raise gmExceptions.AccessDenied ( 1738 msg, 1739 source = 'PostgreSQL', 1740 code = pg_exc.pgcode, 1741 details = details 1742 ) 1743 # other problem 1744 gmLog2.log_stack_trace() 1745 try: 1746 curs_close() 1747 tx_rollback() # just for good measure 1748 conn_close() 1749 except dbapi.InterfaceError: 1750 _log.exception('cannot cleanup') 1751 raise 1752 # other exception 1753 except Exception: 1754 _log.exception('error running query in RW connection') 1755 gmConnectionPool.log_cursor_state(curs) 1756 for notice in notices_accessor.notices: 1757 _log.debug(notice.replace('\n', '/').replace('\n', '/')) 1758 del notices_accessor.notices[:] 1759 gmLog2.log_stack_trace() 1760 try: 1761 curs_close() 1762 except PG_ERROR_EXCEPTION as pg_exc: 1763 _log.exception('cannot close cursor') 1764 gmConnectionPool.log_pg_exception_details(pg_exc) 1765 try: 1766 tx_rollback() # need to rollback so ABORT state isn't preserved in pooled conns 1767 conn_close() 1768 except PG_ERROR_EXCEPTION as pg_exc: 1769 _log.exception('cannot rollback transation') 1770 gmConnectionPool.log_pg_exception_details(pg_exc) 1771 raise 1772 1773 data = None 1774 col_idx = None 1775 if return_data: 1776 try: 1777 data = curs.fetchall() 1778 except Exception: 1779 _log.exception('error fetching data from RW query') 1780 gmLog2.log_stack_trace() 1781 try: 1782 curs_close() 1783 tx_rollback() 1784 conn_close() 1785 except dbapi.InterfaceError: 1786 _log.exception('cannot cleanup') 1787 raise 1788 raise 1789 if get_col_idx: 1790 col_idx = get_col_indices(curs) 1791 1792 curs_close() 1793 conn_commit() 1794 conn_close() 1795 1796 return (data, col_idx)
1797 1798 #------------------------------------------------------------------------
1799 -def run_insert(link_obj=None, schema=None, table=None, values=None, returning=None, end_tx=False, get_col_idx=False, verbose=False):
1800 """Generates SQL for an INSERT query. 1801 1802 values: dict of values keyed by field to insert them into 1803 """ 1804 if schema is None: 1805 schema = 'public' 1806 1807 fields = values.keys() # that way val_snippets and fields really should end up in the same order 1808 val_snippets = [] 1809 for field in fields: 1810 val_snippets.append('%%(%s)s' % field) 1811 1812 if returning is None: 1813 returning = '' 1814 return_data = False 1815 else: 1816 returning = '\n\tRETURNING\n\t\t%s' % ', '.join(returning) 1817 return_data = True 1818 1819 cmd = """\nINSERT INTO %s.%s ( 1820 %s 1821 ) VALUES ( 1822 %s 1823 )%s""" % ( 1824 schema, 1825 table, 1826 ',\n\t\t'.join(fields), 1827 ',\n\t\t'.join(val_snippets), 1828 returning 1829 ) 1830 1831 _log.debug('running SQL: >>>%s<<<', cmd) 1832 1833 return run_rw_queries ( 1834 link_obj = link_obj, 1835 queries = [{'cmd': cmd, 'args': values}], 1836 end_tx = end_tx, 1837 return_data = return_data, 1838 get_col_idx = get_col_idx, 1839 verbose = verbose 1840 )
1841 1842 # ======================================================================= 1843 # connection handling API 1844 # -----------------------------------------------------------------------
1845 -def get_raw_connection(dsn=None, verbose=False, readonly=True, connection_name=None, autocommit=False):
1846 """Get a raw, unadorned connection. 1847 1848 - this will not set any parameters such as encoding, timezone, datestyle 1849 - the only requirement is a valid DSN 1850 - hence it can be used for "service" connections 1851 for verifying encodings etc 1852 """ 1853 return gmConnectionPool.gmConnectionPool().get_raw_connection ( 1854 readonly = readonly, 1855 verbose = verbose, 1856 connection_name = connection_name, 1857 autocommit = autocommit 1858 )
1859 1860 # =======================================================================
1861 -def get_connection(dsn=None, readonly=True, verbose=False, pooled=True, connection_name=None, autocommit=False):
1862 return gmConnectionPool.gmConnectionPool().get_connection ( 1863 readonly = readonly, 1864 verbose = verbose, 1865 connection_name = connection_name, 1866 autocommit = autocommit, 1867 pooled = pooled 1868 )
1869 1870 #-----------------------------------------------------------------------
1871 -def discard_pooled_connection_of_thread():
1872 gmConnectionPool.gmConnectionPool().discard_pooled_connection_of_thread()
1873 1874 #-----------------------------------------------------------------------
1875 -def shutdown():
1876 gmConnectionPool.gmConnectionPool().shutdown()
1877 1878 # ====================================================================== 1879 # internal helpers 1880 #-----------------------------------------------------------------------
1881 -def __noop():
1882 pass
1883 1884 #-----------------------------------------------------------------------
1885 -def log_database_access(action=None):
1886 run_insert ( 1887 schema = 'gm', 1888 table = 'access_log', 1889 values = {'user_action': action}, 1890 end_tx = True 1891 )
1892 1893 #-----------------------------------------------------------------------
1894 -def sanity_check_time_skew(tolerance=60):
1895 """Check server time and local time to be within 1896 the given tolerance of each other. 1897 1898 tolerance: seconds 1899 """ 1900 _log.debug('maximum skew tolerance (seconds): %s', tolerance) 1901 1902 cmd = "SELECT now() at time zone 'UTC'" 1903 conn = get_raw_connection(readonly=True) 1904 curs = conn.cursor() 1905 1906 start = time.time() 1907 rows, idx = run_ro_queries(link_obj = curs, queries = [{'cmd': cmd}]) 1908 end = time.time() 1909 client_now_as_utc = pydt.datetime.utcnow() 1910 1911 curs.close() 1912 conn.commit() 1913 1914 server_now_as_utc = rows[0][0] 1915 query_duration = end - start 1916 _log.info('server "now" (UTC): %s', server_now_as_utc) 1917 _log.info('client "now" (UTC): %s', client_now_as_utc) 1918 _log.debug('wire roundtrip (seconds): %s', query_duration) 1919 1920 if query_duration > tolerance: 1921 _log.error('useless to check client/server time skew, wire roundtrip > tolerance') 1922 return False 1923 1924 if server_now_as_utc > client_now_as_utc: 1925 real_skew = server_now_as_utc - client_now_as_utc 1926 else: 1927 real_skew = client_now_as_utc - server_now_as_utc 1928 1929 _log.debug('client/server time skew: %s', real_skew) 1930 1931 if real_skew > pydt.timedelta(seconds = tolerance): 1932 _log.error('client/server time skew > tolerance') 1933 return False 1934 1935 return True
1936 1937 #-----------------------------------------------------------------------
1938 -def sanity_check_database_settings():
1939 """Checks database settings. 1940 1941 returns (status, message) 1942 status: 1943 0: no problem 1944 1: non-fatal problem 1945 2: fatal problem 1946 """ 1947 _log.debug('checking database settings') 1948 1949 conn = get_connection() 1950 1951 # - version string 1952 global postgresql_version_string 1953 if postgresql_version_string is None: 1954 curs = conn.cursor() 1955 curs.execute('SELECT version()') 1956 postgresql_version_string = curs.fetchone()['version'] 1957 curs.close() 1958 _log.info('PostgreSQL version (string): "%s"' % postgresql_version_string) 1959 1960 options2check = { 1961 # setting: [expected value, risk, fatal?] 1962 'allow_system_table_mods': [['off'], 'system breakage', False], 1963 'check_function_bodies': [['on'], 'suboptimal error detection', False], 1964 'datestyle': [['ISO'], 'faulty timestamp parsing', True], 1965 'default_transaction_isolation': [['read committed'], 'faulty database reads', True], 1966 'default_transaction_read_only': [['on'], 'accidental database writes', False], 1967 'fsync': [['on'], 'data loss/corruption', True], 1968 'full_page_writes': [['on'], 'data loss/corruption', False], 1969 'lc_messages': [['C'], 'suboptimal error detection', False], 1970 'password_encryption': [['on', 'md5', 'scram-sha-256'], 'breach of confidentiality', False], 1971 #u'regex_flavor': [[u'advanced'], u'query breakage', False], # 9.0 doesn't support this anymore, default now advanced anyway 1972 'synchronous_commit': [['on'], 'data loss/corruption', False], 1973 'sql_inheritance': [['on'], 'query breakage, data loss/corruption', True], # IF returned (<PG10): better be ON, if NOT returned (PG10): hardwired 1974 'ignore_checksum_failure': [['off'], 'data loss/corruption', False], # starting with PG 9.3 1975 'track_commit_timestamp': [['on'], 'suboptimal auditing', False] # starting with PG 9.3 1976 } 1977 1978 from Gnumed.pycommon import gmCfg2 1979 _cfg = gmCfg2.gmCfgData() 1980 if _cfg.get(option = 'hipaa'): 1981 options2check['log_connections'] = [['on'], 'non-compliance with HIPAA', True] 1982 options2check['log_disconnections'] = [['on'], 'non-compliance with HIPAA', True] 1983 else: 1984 options2check['log_connections'] = [['on'], 'non-compliance with HIPAA', None] 1985 options2check['log_disconnections'] = [['on'], 'non-compliance with HIPAA', None] 1986 1987 cmd = "SELECT name, setting from pg_settings where name in %(settings)s" 1988 rows, idx = run_ro_queries ( 1989 link_obj = conn, 1990 queries = [{'cmd': cmd, 'args': {'settings': tuple(options2check.keys())}}], 1991 get_col_idx = False 1992 ) 1993 1994 found_error = False 1995 found_problem = False 1996 msg = [] 1997 for row in rows: 1998 option = row['name'] 1999 value_found = row['setting'] 2000 values_expected = options2check[option][0] 2001 risk = options2check[option][1] 2002 fatal_setting = options2check[option][2] 2003 if value_found not in values_expected: 2004 if fatal_setting is True: 2005 found_error = True 2006 elif fatal_setting is False: 2007 found_problem = True 2008 elif fatal_setting is None: 2009 pass 2010 else: 2011 _log.error(options2check[option]) 2012 raise ValueError('invalid database configuration sanity check') 2013 msg.append(_(' option [%s]: %s') % (option, value_found)) 2014 msg.append(_(' risk: %s') % risk) 2015 _log.warning('PG option [%s] set to [%s], expected %s, risk: <%s>' % (option, value_found, values_expected, risk)) 2016 2017 if found_error: 2018 return 2, '\n'.join(msg) 2019 2020 if found_problem: 2021 return 1, '\n'.join(msg) 2022 2023 return 0, ''
2024 2025 #======================================================================= 2026 # main 2027 #----------------------------------------------------------------------- 2028 log_pg_settings = gmConnectionPool.log_pg_settings 2029 log_pg_exception_details = gmConnectionPool.log_pg_exception_details 2030 2031 exception_is_connection_loss = gmConnectionPool.exception_is_connection_loss 2032 2033 cAuthenticationError = gmConnectionPool.cAuthenticationError 2034 2035 #----------------------------------------------------------------------- 2036 if __name__ == "__main__": 2037 2038 if len(sys.argv) < 2: 2039 sys.exit() 2040 2041 if sys.argv[1] != 'test': 2042 sys.exit() 2043 2044 from Gnumed.pycommon.gmTools import file2md5 2045 2046 logging.basicConfig(level=logging.DEBUG) 2047 2048 #--------------------------------------------------------------------
2049 - def test_file2bytea():
2050 login, creds = request_login_params() 2051 pool = gmConnectionPool.gmConnectionPool() 2052 pool.credentials = creds 2053 run_rw_queries(queries = [ 2054 {'cmd': 'drop table if exists test_bytea'}, 2055 {'cmd': 'create table test_bytea (data bytea)'} 2056 ]) 2057 try: 2058 #file2bytea(query = 'insert into test_bytea values (%(data)s::bytea) returning md5(data) as md5', filename = sys.argv[2], file_md5 = file2md5(sys.argv[2], True)) 2059 file2bytea(query = 'insert into test_bytea values (%(data)s::bytea)', filename = sys.argv[2]) 2060 except Exception: 2061 _log.exception('error') 2062 2063 run_rw_queries(queries = [ 2064 {'cmd': 'drop table test_bytea'} 2065 ])
2066 2067 #--------------------------------------------------------------------
2068 - def test_file2bytea_lo():
2069 login, creds = request_login_params() 2070 pool = gmConnectionPool.gmConnectionPool() 2071 pool.credentials = creds 2072 2073 lo_oid = file2bytea_lo ( 2074 filename = sys.argv[2] 2075 #, file_md5 = file2md5(sys.argv[2], True) 2076 ) 2077 print(lo_oid)
2078 # if lo_oid != -1: 2079 # run_rw_queries(queries = [ 2080 # {'cmd': u'select lo_unlink(%(loid)s::oid)', 'args': {'loid': lo_oid}} 2081 # ]) 2082 2083 #--------------------------------------------------------------------
2084 - def test_file2bytea_copy_from():
2085 login, creds = request_login_params() 2086 pool = gmConnectionPool.gmConnectionPool() 2087 pool.credentials = creds 2088 2089 run_rw_queries(queries = [ 2090 {'cmd': 'drop table if exists test_bytea'}, 2091 {'cmd': 'create table test_bytea (pk serial primary key, data bytea)'}, 2092 {'cmd': "insert into test_bytea (data) values (NULL::bytea)"} 2093 ]) 2094 2095 md5_query = { 2096 'cmd': 'select md5(data) AS md5 FROM test_bytea WHERE pk = %(pk)s', 2097 'args': {'pk': 1} 2098 } 2099 2100 file2bytea_copy_from ( 2101 table = 'test_bytea', 2102 columns = ['data'], 2103 filename = sys.argv[2], 2104 md5_query = md5_query, 2105 file_md5 = file2md5(sys.argv[2], True) 2106 ) 2107 2108 run_rw_queries(queries = [ 2109 {'cmd': 'drop table if exists test_bytea'} 2110 ])
2111 2112 #--------------------------------------------------------------------
2113 - def test_file2bytea_overlay():
2114 login, creds = request_login_params() 2115 pool = gmConnectionPool.gmConnectionPool() 2116 pool.credentials = creds 2117 2118 run_rw_queries(queries = [ 2119 {'cmd': 'drop table if exists test_bytea'}, 2120 {'cmd': 'create table test_bytea (pk serial primary key, data bytea)'}, 2121 {'cmd': "insert into test_bytea (data) values (NULL::bytea)"} 2122 ]) 2123 2124 cmd = """ 2125 update test_bytea 2126 set data = overlay ( 2127 coalesce(data, ''::bytea) 2128 placing %(data)s::bytea 2129 from %(start)s 2130 for %(size)s 2131 ) 2132 where 2133 pk > %(pk)s 2134 """ 2135 md5_cmd = 'select md5(data) from test_bytea' 2136 args = {'pk': 0} 2137 file2bytea_overlay ( 2138 query = cmd, 2139 args = args, 2140 filename = sys.argv[2], 2141 conn = None, 2142 md5_query = md5_cmd, 2143 file_md5 = file2md5(sys.argv[2], True) 2144 ) 2145 2146 run_rw_queries(queries = [ 2147 {'cmd': 'drop table test_bytea'} 2148 ])
2149 2150 #--------------------------------------------------------------------
2151 - def test_get_connection():
2152 print("testing get_connection()") 2153 2154 login, creds = request_login_params() 2155 pool = gmConnectionPool.gmConnectionPool() 2156 pool.credentials = creds 2157 2158 print('') 2159 dsn = 'foo' 2160 try: 2161 conn = get_connection(dsn=dsn) 2162 except dbapi.ProgrammingError as e: 2163 print("1) SUCCESS: get_connection(%s) failed as expected" % dsn) 2164 t, v = sys.exc_info()[:2] 2165 print (' ', t) 2166 print (' ', v) 2167 2168 print('') 2169 dsn = 'dbname=gnumed_v22' 2170 try: 2171 conn = get_connection(dsn=dsn) 2172 print("2) ERROR: get_connection() did not fail") 2173 except cAuthenticationError: 2174 print("2) SUCCESS: get_connection(%s) failed as expected" % dsn) 2175 t, v = sys.exc_info()[:2] 2176 print(' ', t) 2177 print(' ', v) 2178 2179 print('') 2180 dsn = 'dbname=gnumed_v22 user=abc' 2181 try: 2182 conn = get_connection(dsn=dsn) 2183 print("3) ERROR: get_connection() did not fail") 2184 except cAuthenticationError: 2185 print("3) SUCCESS: get_connection(%s) failed as expected" % dsn) 2186 t, v = sys.exc_info()[:2] 2187 print(' ', t) 2188 print(' ', v) 2189 2190 print('') 2191 dsn = 'dbname=gnumed_v22 user=any-doc password=abc' 2192 try: 2193 conn = get_connection(dsn=dsn) 2194 print("4) ERROR: get_connection() did not fail") 2195 except cAuthenticationError: 2196 print("4) SUCCESS: get_connection(%s) failed as expected" % dsn) 2197 t, v = sys.exc_info()[:2] 2198 print(' ', t) 2199 print(' ', v) 2200 2201 print('') 2202 dsn = 'dbname=gnumed_v22 user=any-doc password=any-doc' 2203 conn = get_connection(dsn=dsn, readonly=True) 2204 print('5) SUCCESS: get_connection(ro)') 2205 2206 dsn = 'dbname=gnumed_v22 user=any-doc password=any-doc' 2207 conn = get_connection(dsn=dsn, readonly=False, verbose=True) 2208 print('6) SUCCESS: get_connection(rw)') 2209 2210 print('') 2211 dsn = 'dbname=gnumed_v22 user=any-doc' 2212 try: 2213 conn = get_connection(dsn=dsn) 2214 print("8) SUCCESS:", dsn) 2215 print('pid:', conn.get_backend_pid()) 2216 except cAuthenticationError: 2217 print("4) SUCCESS: get_connection(%s) failed" % dsn) 2218 t, v = sys.exc_info()[:2] 2219 print(' ', t) 2220 print(' ', v) 2221 2222 try: 2223 curs = conn.cursor() 2224 input('hit enter to run query') 2225 curs.execute('selec 1') 2226 except Exception as exc: 2227 print('ERROR') 2228 _log.exception('exception occurred') 2229 gmConnectionPool.log_pg_exception_details(exc) 2230 if gmConnectionPool.exception_is_connection_loss(exc): 2231 _log.error('lost connection')
2232 2233 #--------------------------------------------------------------------
2234 - def test_ro_queries():
2235 login, creds = request_login_params() 2236 pool = gmConnectionPool.gmConnectionPool() 2237 pool.credentials = creds 2238 2239 print("testing run_ro_queries()") 2240 2241 dsn = 'dbname=gnumed_v22 user=any-doc password=any-doc' 2242 conn = get_connection(dsn, readonly=True) 2243 2244 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': 'SELECT version()'}], return_data=True, get_col_idx=True, verbose=True) 2245 print(data) 2246 print(idx) 2247 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': 'SELECT 1'}], return_data=True, get_col_idx=True) 2248 print(data) 2249 print(idx) 2250 2251 curs = conn.cursor() 2252 2253 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'SELECT version()'}], return_data=True, get_col_idx=True, verbose=True) 2254 print(data) 2255 print(idx) 2256 2257 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'SELECT 1'}], return_data=True, get_col_idx=True, verbose=True) 2258 print(data) 2259 print(idx) 2260 2261 try: 2262 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'selec 1'}], return_data=True, get_col_idx=True, verbose=True) 2263 print(data) 2264 print(idx) 2265 except psycopg2.ProgrammingError: 2266 print('SUCCESS: run_ro_queries("selec 1") failed as expected') 2267 t, v = sys.exc_info()[:2] 2268 print(' ', t) 2269 print(' ', v) 2270 2271 curs.close()
2272 2273 #--------------------------------------------------------------------
2274 - def test_connection_pool():
2275 login, creds = request_login_params() 2276 pool = gmConnectionPool.gmConnectionPool() 2277 pool.credentials = creds 2278 print(pool) 2279 print(pool.get_connection()) 2280 print(pool.get_connection()) 2281 print(pool.get_connection()) 2282 print(type(pool.get_connection()))
2283 2284 #--------------------------------------------------------------------
2285 - def test_list_args():
2286 login, creds = request_login_params() 2287 pool = gmConnectionPool.gmConnectionPool() 2288 pool.credentials = creds 2289 conn = get_connection('', readonly=True) 2290 curs = conn.cursor() 2291 curs.execute('SELECT * from clin.clin_narrative where narrative = %s', ['a'])
2292 2293 #--------------------------------------------------------------------
2294 - def test_sanitize_pg_regex():
2295 tests = [ 2296 ['(', '\\('] 2297 , ['[', '\\['] 2298 , [')', '\\)'] 2299 ] 2300 for test in tests: 2301 result = sanitize_pg_regex(test[0]) 2302 if result != test[1]: 2303 print('ERROR: sanitize_pg_regex(%s) returned "%s", expected "%s"' % (test[0], result, test[1]))
2304 2305 #--------------------------------------------------------------------
2306 - def test_is_pg_interval():
2307 login, creds = request_login_params() 2308 pool = gmConnectionPool.gmConnectionPool() 2309 pool.credentials = creds 2310 status = True 2311 tests = [ 2312 [None, True], # None == NULL == succeeds ! 2313 [1, True], 2314 ['1', True], 2315 ['abc', False] 2316 ] 2317 2318 if not is_pg_interval(): 2319 print('ERROR: is_pg_interval() returned "False", expected "True"') 2320 status = False 2321 2322 for test in tests: 2323 result = is_pg_interval(test[0]) 2324 if result != test[1]: 2325 print('ERROR: is_pg_interval(%s) returned "%s", expected "%s"' % (test[0], result, test[1])) 2326 status = False 2327 2328 return status
2329 2330 #--------------------------------------------------------------------
2331 - def test_sanity_check_time_skew():
2332 login, creds = request_login_params() 2333 pool = gmConnectionPool.gmConnectionPool() 2334 pool.credentials = creds 2335 sanity_check_time_skew()
2336 2337 #--------------------------------------------------------------------
2338 - def test_get_foreign_key_details():
2339 login, creds = request_login_params() 2340 pool = gmConnectionPool.gmConnectionPool() 2341 pool.credentials = creds 2342 schema = 'clin' 2343 table = 'episode' 2344 col = 'pk' 2345 print('column %s.%s.%s is referenced by:' % (schema, table, col)) 2346 for row in get_foreign_keys2column ( 2347 schema = schema, 2348 table = table, 2349 column = col 2350 ): 2351 print(' <- %s.%s' % ( 2352 row['referencing_table'], 2353 row['referencing_column'] 2354 ))
2355 2356 #--------------------------------------------------------------------
2357 - def test_set_user_language():
2358 login, creds = request_login_params() 2359 pool = gmConnectionPool.gmConnectionPool() 2360 pool.credentials = creds 2361 # (user, language, result, exception type) 2362 tests = [ 2363 # current user 2364 [None, 'de_DE', True], 2365 [None, 'lang_w/o_tx', False], 2366 [None, None, True], 2367 # valid user 2368 ['any-doc', 'de_DE', True], 2369 ['any-doc', 'lang_w/o_tx', False], 2370 ['any-doc', None, True], 2371 # invalid user 2372 ['invalid user', 'de_DE', None], 2373 ['invalid user', 'lang_w/o_tx', False], # lang checking happens before user checking 2374 ['invalid user', None, True] 2375 ] 2376 for test in tests: 2377 print('testing: %s', test) 2378 try: 2379 result = set_user_language(user = test[0], language = test[1]) 2380 if result != test[2]: 2381 print("test:", test) 2382 print("result:", result, "expected:", test[2]) 2383 except psycopg2.IntegrityError as e: 2384 print(e) 2385 if test[2] is None: 2386 continue 2387 print("test:", test) 2388 print("expected exception") 2389 print("result:", e)
2390 2391 #--------------------------------------------------------------------
2392 - def test_get_schema_revision_history():
2393 login, creds = request_login_params() 2394 pool = gmConnectionPool.gmConnectionPool() 2395 pool.credentials = creds 2396 for line in get_schema_revision_history(): 2397 print(' - '.join(line))
2398 2399 #--------------------------------------------------------------------
2400 - def test_run_query():
2401 login, creds = request_login_params() 2402 pool = gmConnectionPool.gmConnectionPool() 2403 pool.credentials = creds 2404 gmDateTime.init() 2405 args = {'dt': gmDateTime.pydt_max_here()} 2406 cmd = "SELECT %(dt)s" 2407 2408 #cmd = u"SELECT 'infinity'::timestamp with time zone" 2409 2410 cmd = """ 2411 SELECT to_timestamp (foofoo,'YYMMDD.HH24MI') FROM ( 2412 SELECT REGEXP_REPLACE ( 2413 't1.130729.0902.tif', -- string 2414 E'(.1)\.([0-9\.]+)(\.tif)', -- pattern 2415 E'\\\\2' -- replacement 2416 ) AS foofoo 2417 ) AS foo""" 2418 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False) 2419 print(rows) 2420 print(rows[0]) 2421 print(rows[0][0])
2422 2423 #--------------------------------------------------------------------
2424 - def test_schema_exists():
2425 login, creds = request_login_params() 2426 pool = gmConnectionPool.gmConnectionPool() 2427 pool.credentials = creds 2428 print(schema_exists())
2429 2430 #--------------------------------------------------------------------
2431 - def test_row_locks():
2432 login, creds = request_login_params() 2433 pool = gmConnectionPool.gmConnectionPool() 2434 pool.credentials = creds 2435 2436 row_is_locked(table = 'dem.identity', pk = 12) 2437 2438 print("1st connection:") 2439 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2440 print(" 1st shared lock succeeded:", lock_row(table = 'dem.identity', pk = 12, exclusive = False)) 2441 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2442 2443 print(" 2nd shared lock should succeed:", lock_row(table = 'dem.identity', pk = 12, exclusive = False)) 2444 print(" `-> unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = False)) 2445 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2446 print(" exclusive lock should succeed:", lock_row(table = 'dem.identity', pk = 12, exclusive = True)) 2447 print(" `-> unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = True)) 2448 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2449 2450 print("2nd connection:") 2451 conn = get_raw_connection(readonly=True) 2452 print(" shared lock should succeed:", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)) 2453 print(" `-> unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)) 2454 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2455 print(" exclusive lock succeeded ?", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = True), "(should fail)") 2456 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2457 2458 print("1st connection:") 2459 print(" unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = False)) 2460 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2461 2462 print("2nd connection:") 2463 print(" exclusive lock should succeed", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = True)) 2464 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2465 print(" shared lock should succeed:", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)) 2466 print(" `-> unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)) 2467 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2468 print(" unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False)) 2469 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12)) 2470 2471 conn.close()
2472 2473 #--------------------------------------------------------------------
2474 - def test_get_foreign_key_names():
2475 login, creds = request_login_params() 2476 pool = gmConnectionPool.gmConnectionPool() 2477 pool.credentials = creds 2478 print(get_foreign_key_names ( 2479 src_schema = 'clin', 2480 src_table = 'vaccination', 2481 src_column = 'fk_episode', 2482 target_schema = 'clin', 2483 target_table = 'episode', 2484 target_column = 'pk' 2485 )) 2486 print(get_foreign_key_names ( 2487 src_schema = 'dem', 2488 src_table = 'names', 2489 src_column = 'id_identity', 2490 target_schema = 'dem', 2491 target_table = 'identity', 2492 target_column = 'pk' 2493 ))
2494 2495 #--------------------------------------------------------------------
2496 - def test_get_index_name():
2497 login, creds = request_login_params() 2498 pool = gmConnectionPool.gmConnectionPool() 2499 pool.credentials = creds 2500 print(get_index_name(indexed_table = 'clin.vaccination', indexed_column = 'fk_episode'))
2501 2502 #--------------------------------------------------------------------
2503 - def test_faulty_SQL():
2504 login, creds = request_login_params() 2505 pool = gmConnectionPool.gmConnectionPool() 2506 pool.credentials = creds 2507 conn = get_connection() 2508 run_rw_queries(queries = [{'cmd': 'SELEC 1'}])
2509 2510 #--------------------------------------------------------------------
2511 - def test_log_settings():
2512 login, creds = request_login_params() 2513 pool = gmConnectionPool.gmConnectionPool() 2514 pool.credentials = creds 2515 conn = get_connection() 2516 gmConnectionPool.log_pg_settings(curs = conn.cursor())
2517 2518 #-------------------------------------------------------------------- 2519 # run tests 2520 2521 # legacy: 2522 #test_connection_pool() 2523 2524 # tested: 2525 #test_file2bytea_lo() 2526 #test_file2bytea_copy_from() # not fully implemented 2527 #test_file2bytea_overlay() 2528 #test_file2bytea() 2529 #test_exceptions() 2530 #test_get_connection() 2531 #test_ro_queries() 2532 #test_list_args() 2533 #test_sanitize_pg_regex() 2534 #test_is_pg_interval() 2535 #test_sanity_check_time_skew() 2536 #test_get_foreign_key_details() 2537 #test_get_index_name() 2538 #test_set_user_language() 2539 #test_get_schema_revision_history() 2540 test_run_query() 2541 #test_schema_exists() 2542 #test_get_foreign_key_names() 2543 #test_row_locks() 2544 #test_faulty_SQL() 2545 test_log_settings() 2546 2547 # ====================================================================== 2548