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
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
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
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
68
69
70 known_schema_hashes = {
71 0: 'not released, testing only',
72 2: 'b09d50d7ed3f91ddf4c4ddb8ea507720',
73 3: 'e73718eaf230d8f1d2d01afa8462e176',
74 4: '4428ccf2e54c289136819e701bb095ea',
75 5: '7e7b093af57aea48c288e76632a382e5',
76 6: '90e2026ac2efd236da9c8608b8685b2d',
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
90
91 19: '57f009a159f55f77525cc0291e0c8b60',
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
116
117 '57f009a159f55f77525cc0291e0c8b60': 19,
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,
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
142 }
143
144
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
169
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
287
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 del login
305 _log.warning("user cancelled text mode login dialog")
306 print("user cancelled text mode login dialog")
307 raise gmExceptions.ConnectionError(_("Cannot connect to database without login information!"))
308
309 creds = gmConnectionPool.cPGCredentials()
310 creds.database = login.database
311 creds.host = login.host
312 creds.port = login.port
313 creds.user = login.user
314 creds.password = login.password
315
316 return login, creds
317
318
320 """GUI (wx) input request for database login parameters.
321
322 Returns gmLoginInfo.LoginInfo object
323 """
324 import wx
325
326
327 if wx.GetApp() is None:
328 raise AssertionError(_("The wxPython GUI framework hasn't been initialized yet!"))
329
330
331
332 import gmAuthWidgets
333 dlg = gmAuthWidgets.cLoginDialog(None, -1)
334 dlg.ShowModal()
335 login = dlg.panel.GetLoginInfo()
336 dlg.DestroyLater()
337
338 if login is None:
339 raise gmExceptions.ConnectionError(_("Can't connect to database without login information!"))
340
341 gmLog2.add_word2hide(login.password)
342 creds = gmConnectionPool.cPGCredentials()
343 creds.database = login.database
344 creds.host = login.host
345 creds.port = login.port
346 creds.user = login.user
347 creds.password = login.password
348 return login, creds
349
350
352 """Request login parameters for database connection."""
353
354
355 if 'DISPLAY' in os.environ:
356
357 try:
358 login, creds = __request_login_params_gui_wx()
359 except Exception:
360 pass
361 if setup_pool:
362 pool = gmConnectionPool.gmConnectionPool()
363 pool.credentials = creds
364 return login, creds
365
366
367
368 login, creds = __request_login_params_tui()
369 if setup_pool:
370 pool = gmConnectionPool.gmConnectionPool()
371 pool.credentials = creds
372 return login, creds
373
374
375
376
378 expected_hash = known_schema_hashes[version]
379 if version == 0:
380 args = {'ver': 9999}
381 else:
382 args = {'ver': version}
383 rows, idx = run_ro_queries (
384 link_obj = link_obj,
385 queries = [{
386 'cmd': 'select md5(gm.concat_table_structure(%(ver)s::integer)) as md5',
387 'args': args
388 }]
389 )
390 if rows[0]['md5'] != expected_hash:
391 _log.error('database schema version mismatch')
392 _log.error('expected: %s (%s)' % (version, expected_hash))
393 _log.error('detected: %s (%s)' % (get_schema_version(link_obj=link_obj), rows[0]['md5']))
394 if verbose:
395 _log.debug('schema dump follows:')
396 for line in get_schema_structure(link_obj = link_obj).split():
397 _log.debug(line)
398 _log.debug('schema revision history dump follows:')
399 for line in get_schema_revision_history(link_obj = link_obj):
400 _log.debug(' - '.join(line))
401 return False
402 _log.info('detected schema version [%s], hash [%s]' % (map_schema_hash2version[rows[0]['md5']], rows[0]['md5']))
403 return True
404
405
407 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select md5(gm.concat_table_structure()) as md5'}])
408 try:
409 return map_schema_hash2version[rows[0]['md5']]
410 except KeyError:
411 return 'unknown database schema version, MD5 hash is [%s]' % rows[0]['md5']
412
413
415 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select gm.concat_table_structure()'}])
416 return rows[0][0]
417
418
420 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select md5(gm.concat_table_structure()) as md5'}])
421 return rows[0]['md5']
422
423
425
426 if table_exists(link_obj = link_obj, schema = 'gm', table = 'schema_revision'):
427 cmd = """
428 SELECT
429 imported::text,
430 version,
431 filename
432 FROM gm.schema_revision
433 ORDER BY imported"""
434 elif table_exists(link_obj = link_obj, schema = 'public', table = 'gm_schema_revision'):
435 cmd = """
436 SELECT
437 imported::text,
438 version,
439 filename
440 FROM public.gm_schema_revision
441 ORDER BY imported"""
442 else:
443 return []
444
445 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd}])
446 return rows
447
448
450 queries = [
451 ("SELECT setting FROM pg_settings WHERE name = 'server_version'", "Version (PG)"),
452 ("SELECT setting FROM pg_settings WHERE name = 'server_encoding'", "Encoding (PG)"),
453 ("SELECT setting FROM pg_settings WHERE name = 'lc_collate'", "LC_COLLATE (PG)"),
454 ("SELECT setting FROM pg_settings WHERE name = 'lc_ctype'", "LC_CTYPE (PG)"),
455 ("SELECT count(1) FROM dem.identity", "Patients"),
456 ("SELECT count(1) FROM clin.encounter", "Contacts"),
457 ("SELECT count(1) FROM clin.episode", "Episodes"),
458 ("SELECT count(1) FROM clin.health_issue", "Issues"),
459 ("SELECT count(1) FROM clin.test_result", "Results"),
460 ("SELECT count(1) FROM clin.vaccination", "Vaccinations"),
461 ("SELECT count(1) FROM blobs.doc_med", "Documents"),
462 ("SELECT count(1) FROM blobs.doc_obj", "Objects"),
463 ("SELECT count(1) FROM dem.org", "Organizations"),
464 ("SELECT count(1) FROM dem.org_unit", "Organizational units"),
465 ("SELECT max(modified_when) FROM audit.audit_fields", "Most recent .modified_when"),
466 ("SELECT max(audit_when) FROM audit.audit_trail", "Most recent .audit_when")
467 ]
468 if conn is None:
469 conn = get_connection(readonly = True)
470 database = conn.get_dsn_parameters()['dbname']
471 lines = [
472 'Fingerprinting GNUmed database ...',
473 '',
474 '%20s: %s' % ('Name (DB)', database)
475 ]
476 curs = conn.cursor()
477
478 cmd = "SELECT pg_size_pretty(pg_database_size('%s'))" % database
479 curs.execute(cmd)
480 rows = curs.fetchall()
481 lines.append('%20s: %s' % ('Size (DB)', rows[0][0]))
482
483 cmd = "SELECT md5(gm.concat_table_structure())"
484 curs.execute(cmd)
485 rows = curs.fetchall()
486 md5_sum = rows[0][0]
487 try:
488 lines.append('%20s: %s (v%s)' % ('Schema hash', md5_sum, map_schema_hash2version[md5_sum]))
489 except KeyError:
490 lines.append('%20s: %s' % ('Schema hash', md5_sum))
491 for cmd, label in queries:
492 curs.execute(cmd)
493 rows = curs.fetchall()
494 lines.append('%20s: %s' % (label, rows[0][0]))
495 if with_dump:
496 curs.execute('SELECT gm.concat_table_structure()')
497 rows = curs.fetchall()
498 lines.append('')
499 lines.append(rows[0][0])
500 curs.close()
501 if fname is None:
502 if eol is None:
503 return lines
504 return eol.join(lines)
505
506 outfile = open(fname, mode = 'wt', encoding = 'utf8')
507 outfile.write('\n'.join(lines))
508 outfile.close()
509 return fname
510
511
513 rows, idx = run_ro_queries(queries = [{'cmd': 'select CURRENT_USER'}])
514 return rows[0][0]
515
516
518 """Get the foreign keys pointing to schema.table.column.
519
520 Does not properly work with multi-column FKs.
521 GNUmed doesn't use any, however.
522 """
523 args = {
524 'schema': schema,
525 'tbl': table,
526 'col': column
527 }
528 cmd = """
529 SELECT
530 %(schema)s AS referenced_schema,
531 %(tbl)s AS referenced_table,
532 %(col)s AS referenced_column,
533 pgc.confkey AS referenced_column_list,
534
535 pgc.conrelid::regclass AS referencing_table,
536 pgc.conkey AS referencing_column_list,
537 (select attname from pg_attribute where attnum = pgc.conkey[1] and attrelid = pgc.conrelid) AS referencing_column
538 FROM
539 pg_constraint pgc
540 WHERE
541 pgc.contype = 'f'
542 AND
543 pgc.confrelid = (
544 select oid from pg_class where relname = %(tbl)s and relnamespace = (
545 select oid from pg_namespace where nspname = %(schema)s
546 )
547 ) and
548 (
549 select attnum
550 from pg_attribute
551 where
552 attrelid = (select oid from pg_class where relname = %(tbl)s and relnamespace = (
553 select oid from pg_namespace where nspname = %(schema)s
554 ))
555 and
556 attname = %(col)s
557 ) = any(pgc.confkey)
558 """
559 rows, idx = run_ro_queries (
560 link_obj = link_obj,
561 queries = [
562 {'cmd': cmd, 'args': args}
563 ]
564 )
565
566 return rows
567
568
569 -def get_index_name(indexed_table=None, indexed_column=None, link_obj=None):
570
571 args = {
572 'idx_tbl': indexed_table,
573 'idx_col': indexed_column
574 }
575 rows, idx = run_ro_queries (
576 link_obj = link_obj,
577 queries = [{'cmd': SQL_get_index_name, 'args': args}],
578 get_col_idx = False
579 )
580
581 return rows
582
583
584 -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):
585
586 args = {
587 'src_schema': src_schema,
588 'src_tbl': src_table,
589 'src_col': src_column,
590 'target_schema': target_schema,
591 'target_tbl': target_table,
592 'target_col': target_column
593 }
594
595 rows, idx = run_ro_queries (
596 link_obj = link_obj,
597 queries = [{'cmd': SQL_foreign_key_name, 'args': args}],
598 get_col_idx = False
599 )
600
601 return rows
602
603
605 """Return child tables of <table>."""
606 cmd = """
607 select
608 pgn.nspname as namespace,
609 pgc.relname as table
610 from
611 pg_namespace pgn,
612 pg_class pgc
613 where
614 pgc.relnamespace = pgn.oid
615 and
616 pgc.oid in (
617 select inhrelid from pg_inherits where inhparent = (
618 select oid from pg_class where
619 relnamespace = (select oid from pg_namespace where nspname = %(schema)s) and
620 relname = %(table)s
621 )
622 )"""
623 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': {'schema': schema, 'table': table}}])
624 return rows
625
626
628 cmd = """SELECT EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = %(schema)s)"""
629 args = {'schema': schema}
630 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}])
631 return rows[0][0]
632
633
635 """Returns false, true."""
636 cmd = """
637 select exists (
638 select 1 from information_schema.tables
639 where
640 table_schema = %s and
641 table_name = %s and
642 table_type = 'BASE TABLE'
643 )"""
644 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': (schema, table)}])
645 return rows[0][0]
646
647
649
650 cmd = """
651 SELECT EXISTS (
652 SELECT 1 FROM pg_proc
653 WHERE proname = %(func)s AND pronamespace = (SELECT oid FROM pg_namespace WHERE nspname = %(schema)s)
654 )
655 """
656 args = {
657 'func': function,
658 'schema': schema
659 }
660 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}])
661 return rows[0][0]
662
663
665 if cursor.description is None:
666 _log.error('no result description available: unused cursor or last query did not select rows')
667 return None
668 col_indices = {}
669 col_index = 0
670 for col_desc in cursor.description:
671 col_name = col_desc[0]
672
673
674
675 if col_name in col_indices:
676 col_name = '%s_%s' % (col_name, col_index)
677 col_indices[col_name] = col_index
678 col_index += 1
679
680 return col_indices
681
682 -def get_col_defs(link_obj=None, schema='public', table=None):
683 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_col_defs, 'args': (schema, table)}])
684 col_names = []
685 col_type = {}
686 for row in rows:
687 col_names.append(row[0])
688
689 if row[1].startswith('_'):
690 col_type[row[0]] = row[1][1:] + '[]'
691 else:
692 col_type[row[0]] = row[1]
693 col_defs = []
694 col_defs.append(col_names)
695 col_defs.append(col_type)
696 return col_defs
697
699 """Return column attributes of table"""
700 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_attributes, 'args': (schema, table)}])
701 cols = []
702 for row in rows:
703 cols.append(row[0])
704 return cols
705
706
707
708
710 tx_file = open(filename, mode = 'wt', encoding = 'utf8')
711 tx_file.write('-- GNUmed database string translations exported %s\n' % gmDateTime.pydt_now_here().strftime('%Y-%m-%d %H:%M'))
712 tx_file.write('-- - contains translations for each of [%s]\n' % ', '.join(get_translation_languages()))
713 tx_file.write('-- - user database language is set to [%s]\n\n' % get_current_user_language())
714 tx_file.write('-- Please email this file to <gnumed-devel@gnu.org>.\n')
715 tx_file.write('-- ----------------------------------------------------------------------------------------------\n\n')
716 tx_file.write('set default_transaction_read_only to off;\n\n')
717 tx_file.write("set client_encoding to 'utf-8';\n\n")
718 tx_file.write('\\unset ON_ERROR_STOP\n\n')
719
720 cmd = 'SELECT lang, orig, trans FROM i18n.translations ORDER BY lang, orig'
721 rows, idx = run_ro_queries(queries = [{'cmd': cmd}], get_col_idx = False)
722 for row in rows:
723 line = "select i18n.upd_tx(E'%s', E'%s', E'%s');\n" % (
724 row['lang'].replace("'", "\\'"),
725 row['orig'].replace("'", "\\'"),
726 row['trans'].replace("'", "\\'")
727 )
728 tx_file.write(line)
729 tx_file.write('\n')
730
731 tx_file.write('\set ON_ERROR_STOP 1\n')
732 tx_file.close()
733
734 return True
735
736
738 cmd = 'DELETE FROM i18n.translations WHERE lang = %(lang)s AND orig = %(orig)s'
739 args = {'lang': language, 'orig': original}
740 run_rw_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}], return_data = False, end_tx = True)
741 return True
742
743
745 if language is None:
746 cmd = 'SELECT i18n.upd_tx(%(orig)s, %(trans)s)'
747 else:
748 cmd = 'SELECT i18n.upd_tx(%(lang)s, %(orig)s, %(trans)s)'
749 args = {'lang': language, 'orig': original, 'trans': translation}
750 run_rw_queries(queries = [{'cmd': cmd, 'args': args}], return_data = False, link_obj = link_obj)
751 return args
752
753
755 rows, idx = run_ro_queries (
756 queries = [{'cmd': 'select distinct lang from i18n.translations'}]
757 )
758 return [ r[0] for r in rows ]
759
760
762
763 args = {'lang': language}
764 _log.debug('language [%s]', language)
765
766 if order_by is None:
767 order_by = 'ORDER BY %s' % order_by
768 else:
769 order_by = 'ORDER BY lang, orig'
770
771 if language is None:
772 cmd = """
773 SELECT DISTINCT ON (orig, lang)
774 lang, orig, trans
775 FROM ((
776
777 -- strings stored as translation keys whether translated or not
778 SELECT
779 NULL as lang,
780 ik.orig,
781 NULL AS trans
782 FROM
783 i18n.keys ik
784
785 ) UNION ALL (
786
787 -- already translated strings
788 SELECT
789 it.lang,
790 it.orig,
791 it.trans
792 FROM
793 i18n.translations it
794
795 )) as translatable_strings
796 %s""" % order_by
797 else:
798 cmd = """
799 SELECT DISTINCT ON (orig, lang)
800 lang, orig, trans
801 FROM ((
802
803 -- strings stored as translation keys whether translated or not
804 SELECT
805 %%(lang)s as lang,
806 ik.orig,
807 i18n._(ik.orig, %%(lang)s) AS trans
808 FROM
809 i18n.keys ik
810
811 ) UNION ALL (
812
813 -- already translated strings
814 SELECT
815 %%(lang)s as lang,
816 it.orig,
817 i18n._(it.orig, %%(lang)s) AS trans
818 FROM
819 i18n.translations it
820
821 )) AS translatable_strings
822 %s""" % order_by
823
824 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False)
825
826 if rows is None:
827 _log.error('no translatable strings found')
828 else:
829 _log.debug('%s translatable strings found', len(rows))
830
831 return rows
832
833
835 cmd = 'select i18n.get_curr_lang()'
836 rows, idx = run_ro_queries(queries = [{'cmd': cmd}])
837 return rows[0][0]
838
839
841 """Set the user language in the database.
842
843 user = None: current db user
844 language = None: unset
845 """
846 _log.info('setting database language for user [%s] to [%s]', user, language)
847 args = {'usr': user, 'lang': language}
848 if language is None:
849 if user is None:
850 queries = [{'cmd': 'select i18n.unset_curr_lang()'}]
851 else:
852 queries = [{'cmd': 'select i18n.unset_curr_lang(%(usr)s)', 'args': args}]
853 queries.append({'cmd': 'select True'})
854 else:
855 if user is None:
856 queries = [{'cmd': 'select i18n.set_curr_lang(%(lang)s)', 'args': args}]
857 else:
858 queries = [{'cmd': 'select i18n.set_curr_lang(%(lang)s, %(usr)s)', 'args': args}]
859 rows, idx = run_rw_queries(queries = queries, return_data = True)
860 if not rows[0][0]:
861 _log.error('cannot set database language to [%s] for user [%s]', language, user)
862 return rows[0][0]
863
864
866 """Set the user language in the database.
867
868 - regardless of whether there is any translation available.
869 - only for the current user
870 """
871 _log.info('forcing database language for current db user to [%s]', language)
872
873 run_rw_queries(queries = [{
874 'cmd': 'select i18n.force_curr_lang(%(lang)s)',
875 'args': {'lang': language}
876 }])
877
878
879
880
882 cmd = 'notify "db_maintenance_warning"'
883 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
884
885
887 cmd = 'notify "db_maintenance_disconnect"'
888 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
889
890
892 cmd = 'SELECT %(candidate)s::interval'
893 try:
894 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}])
895 return True
896 except Exception:
897 cmd = 'SELECT %(candidate)s::text::interval'
898 try:
899 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}])
900 return True
901 except Exception:
902 return False
903
904
905 -def lock_row(link_obj=None, table=None, pk=None, exclusive=False):
906 """Uses pg_advisory(_shared).
907
908 - locks stack upon each other and need one unlock per lock
909 - same connection:
910 - all locks succeed
911 - different connections:
912 - shared + shared succeed
913 - shared + exclusive fail
914 """
915 _log.debug('locking row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
916 if exclusive:
917 cmd = """SELECT pg_try_advisory_lock('%s'::regclass::oid::int, %s)""" % (table, pk)
918 else:
919 cmd = """SELECT pg_try_advisory_lock_shared('%s'::regclass::oid::int, %s)""" % (table, pk)
920 rows, idx = run_rw_queries(link_obj = link_obj, queries = [{'cmd': cmd}], get_col_idx = False, return_data = True)
921 if rows[0][0]:
922 return True
923
924 _log.warning('cannot lock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
925 return False
926
927
928 -def unlock_row(link_obj=None, table=None, pk=None, exclusive=False):
929 """Uses pg_advisory_unlock(_shared).
930
931 - each lock needs one unlock
932 """
933 _log.debug('trying to unlock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
934 if exclusive:
935 cmd = "SELECT pg_advisory_unlock('%s'::regclass::oid::int, %s)" % (table, pk)
936 else:
937 cmd = "SELECT pg_advisory_unlock_shared('%s'::regclass::oid::int, %s)" % (table, pk)
938 rows, idx = run_rw_queries(link_obj = link_obj, queries = [{'cmd': cmd}], get_col_idx = False, return_data = True)
939 if rows[0][0]:
940 return True
941
942 _log.warning('cannot unlock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
943 return False
944
945
947 """Looks at pk_locks
948
949 - does not take into account locks other than 'advisory', however
950 """
951 cmd = """SELECT EXISTS (
952 SELECT 1 FROM pg_locks WHERE
953 classid = '%s'::regclass::oid::int
954 AND
955 objid = %s
956 AND
957 locktype = 'advisory'
958 )""" % (table, pk)
959 rows, idx = run_ro_queries(queries = [{'cmd': cmd}], get_col_idx = False)
960 if rows[0][0]:
961 _log.debug('row is locked: [%s] [%s]', table, pk)
962 return True
963 _log.debug('row is NOT locked: [%s] [%s]', table, pk)
964 return False
965
966
967
968
970 md5 = hashlib.md5()
971 md5.update(('%s' % cache_key_data).encode('utf8'))
972 return os.path.join(gmTools.gmPaths().bytea_cache_dir, md5.hexdigest())
973
974
976 cached_name = __generate_cached_filename(cache_key_data)
977 _log.debug('[%s] -> [%s] -> [%s]', filename, cache_key_data, cached_name)
978 if not gmTools.remove_file(cached_name, log_error = True, force = True):
979 _log.error('cannot remove existing file [%s] for key [%s] from cache', filename, cached_name)
980 return None
981
982 PERMS_owner_only = 0o0660
983 try:
984 shutil.copyfile(filename, cached_name, follow_symlinks = True)
985 os.chmod(cached_name, PERMS_owner_only)
986 except shutil.SameFileError:
987 _log.exception('file seems to exist in cache, despite having checked and possible removed it just before')
988
989
990
991
992 return None
993 except OSError:
994 _log.exception('cannot copy file into cache: [%s] -> [%s]', filename, cached_name)
995 return None
996 except PermissionError:
997 _log.exception('cannot set cache file [%s] permissions to [%s]', cached_name, stat.filemode(PERMS_owner_only))
998 return None
999
1000 return cached_name
1001
1002
1004 """Calculate and verify filename in cache given cache key details."""
1005 cached_name = __generate_cached_filename(cache_key_data)
1006 try:
1007 stat = os.stat(cached_name)
1008 except FileNotFoundError:
1009 return None
1010
1011 _log.debug('cache hit: [%s] -> [%s] (%s)', cache_key_data, cached_name, stat)
1012 if os.path.islink(cached_name) or (not os.path.isfile(cached_name)):
1013 _log.error('object in cache is not a regular file: %s', cached_name)
1014 _log.error('possibly an attack, removing')
1015 if gmTools.remove_file(cached_name, log_error = True):
1016 return None
1017
1018 raise Exception('cannot delete suspicious object in cache dir: %s', cached_name)
1019
1020 if stat.st_size == data_size:
1021 return cached_name
1022
1023 _log.debug('size in cache [%s] <> expected size [%s], removing cached file', stat.st_size, data_size)
1024 if gmTools.remove_file(cached_name, log_error = True):
1025 return None
1026
1027 raise Exception('cannot remove suspicious object from cache dir: %s', cached_name)
1028
1029
1031 """Get file from cache if available."""
1032 cached_filename = __get_filename_in_cache(cache_key_data = cache_key_data, data_size = data_size)
1033 if cached_filename is None:
1034 return False
1035
1036 if link2cached:
1037 try:
1038
1039
1040 os.link(cached_filename, filename)
1041 _log.debug('hardlinked [%s] as [%s]', cached_filename, filename)
1042 return True
1043
1044 except Exception:
1045 pass
1046 _log.debug('cannot hardlink to cache, trying copy-from-cache')
1047 try:
1048 shutil.copyfile(cached_filename, filename, follow_symlinks = True)
1049 return True
1050
1051 except shutil.SameFileError:
1052
1053 pass
1054 except OSError:
1055 _log.exception('cannot copy cached file [%s] into [%s]', cached_filename, filename)
1056
1057 _log.debug('downloading new copy of file, despite found in cache')
1058 return False
1059
1060
1061 -def bytea2file(data_query=None, filename=None, chunk_size=0, data_size=None, data_size_query=None, conn=None, link2cached=True):
1062
1063 if data_size == 0:
1064 open(filename, 'wb').close()
1065 return True
1066
1067 if data_size is None:
1068 rows, idx = run_ro_queries(link_obj = conn, queries = [data_size_query])
1069 data_size = rows[0][0]
1070 if data_size == 0:
1071 open(filename, 'wb').close()
1072 return True
1073
1074 if data_size is None:
1075 return False
1076
1077 if conn is None:
1078 conn = gmConnectionPool.gmConnectionPool().get_connection()
1079 cache_key_data = '%s::%s' % (conn.dsn, data_query)
1080 found_in_cache = __get_file_from_cache(filename, cache_key_data = cache_key_data, data_size = data_size, link2cached = link2cached)
1081 if found_in_cache:
1082
1083 return True
1084
1085 outfile = open(filename, 'wb')
1086 result = bytea2file_object (
1087 data_query = data_query,
1088 file_obj = outfile,
1089 chunk_size = chunk_size,
1090 data_size = data_size,
1091 data_size_query = data_size_query,
1092 conn = conn
1093 )
1094 outfile.close()
1095 __store_file_in_cache(filename, cache_key_data)
1096 return result
1097
1098
1099 -def bytea2file_object(data_query=None, file_obj=None, chunk_size=0, data_size=None, data_size_query=None, conn=None):
1100 """Store data from a bytea field into a file.
1101
1102 <data_query>
1103 - dict {'cmd': ..., 'args': ...}
1104 - 'cmd' must be a string containing "... substring(data from %(start)s for %(size)s) ..."
1105 - 'args' must be a dict
1106 - must return one row with one field of type bytea
1107 <file>
1108 - must be a file like Python object
1109 <data_size>
1110 - integer of the total size of the expected data or None
1111 <data_size_query>
1112 - dict {'cmd': ..., 'args': ...}
1113 - must return one row with one field with the octet_length() of the data field
1114 - used only when <data_size> is None
1115 """
1116 if data_size == 0:
1117 return True
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130 if conn is None:
1131 conn = get_raw_connection(readonly = True)
1132
1133 if data_size is None:
1134 rows, idx = run_ro_queries(link_obj = conn, queries = [data_size_query])
1135 data_size = rows[0][0]
1136 if data_size in [None, 0]:
1137 conn.rollback()
1138 return True
1139
1140 max_chunk_size = 1024 * 1024 * 20
1141 if chunk_size == 0:
1142 chunk_size = min(data_size, max_chunk_size)
1143
1144 _log.debug('expecting %s bytes of BYTEA data in chunks of %s bytes', data_size, chunk_size)
1145
1146
1147
1148
1149 needed_chunks, remainder = divmod(data_size, chunk_size)
1150 _log.debug('%s chunk(s), %s byte(s) remainder', needed_chunks, remainder)
1151
1152
1153
1154
1155
1156
1157
1158 for chunk_id in range(needed_chunks):
1159 chunk_start = (chunk_id * chunk_size) + 1
1160 data_query['args']['start'] = chunk_start
1161 data_query['args']['size'] = chunk_size
1162 try:
1163 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query])
1164 except Exception:
1165 _log.error('cannot retrieve chunk [%s/%s], size [%s], try decreasing chunk size' % (chunk_id+1, needed_chunks, chunk_size))
1166 conn.rollback()
1167 raise
1168
1169 file_obj.write(rows[0][0])
1170
1171
1172 if remainder > 0:
1173 chunk_start = (needed_chunks * chunk_size) + 1
1174 data_query['args']['start'] = chunk_start
1175 data_query['args']['size'] = remainder
1176 try:
1177 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query])
1178 except Exception:
1179 _log.error('cannot retrieve remaining [%s] bytes' % remainder)
1180 conn.rollback()
1181 raise
1182
1183 file_obj.write(rows[0][0])
1184
1185 conn.rollback()
1186 return True
1187
1188
1189 -def file2bytea(query=None, filename=None, args=None, conn=None, file_md5=None):
1190 """Store data from a file into a bytea field.
1191
1192 The query must:
1193 - contain a format spec identifying the row (eg a primary key)
1194 matching <args> if it is an UPDATE
1195 - contain a format spec " <field> = %(data)s::bytea"
1196
1197 The query CAN return the MD5 of the inserted data:
1198 RETURNING md5(<field>) AS md5
1199 in which case the returned hash will compared to the md5 of the file.
1200 """
1201 retry_delay = 100
1202 attempt = 0
1203 max_attempts = 3
1204 while attempt < max_attempts:
1205 attempt += 1
1206 try:
1207 infile = open(filename, "rb")
1208 except (BlockingIOError, FileNotFoundError, PermissionError):
1209 _log.exception('#%s: cannot open [%s]', attempt, filename)
1210 _log.error('retrying after %sms', retry_delay)
1211 infile = None
1212 time.sleep(retry_delay / 1000)
1213 if infile is None:
1214 return False
1215
1216 data_as_byte_string = infile.read()
1217 infile.close()
1218 if args is None:
1219 args = {}
1220
1221 args['data'] = memoryview(data_as_byte_string)
1222 del(data_as_byte_string)
1223
1224 if conn is None:
1225 conn = get_raw_connection(readonly = False)
1226 close_conn = True
1227 else:
1228 close_conn = False
1229 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = (file_md5 is not None))
1230 success_status = True
1231 if file_md5 is None:
1232 conn.commit()
1233 else:
1234 db_md5 = rows[0]['md5']
1235 if file_md5 != db_md5:
1236 conn.rollback()
1237 success_status = False
1238 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5)
1239 else:
1240 conn.commit()
1241 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5)
1242 if close_conn:
1243 conn.close()
1244 return success_status
1245
1246
1247 -def file2lo(filename=None, conn=None, check_md5=False):
1248
1249 file_size = os.path.getsize(filename)
1250 if file_size > (1024 * 1024) * 1024:
1251 _log.debug('file size of [%s] > 1 GB, supposedly not supported by psycopg2 large objects (but seems to work anyway ?)', file_size)
1252
1253
1254 if conn is None:
1255 conn = get_raw_connection(readonly = False)
1256 close_conn = conn.close
1257 else:
1258 close_conn = __noop
1259 _log.debug('[%s] -> large object', filename)
1260
1261
1262 lo = conn.lobject(0, 'w', 0, filename)
1263 lo_oid = lo.oid
1264 lo.close()
1265 _log.debug('large object OID: %s', lo_oid)
1266
1267
1268 if file_md5 is None:
1269 conn.commit()
1270 close_conn()
1271 return lo_oid
1272 cmd = 'SELECT md5(lo_get(%(loid)s::oid))'
1273 args = {'loid': lo_oid}
1274 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': cmd, 'args': args}])
1275 db_md5 = rows[0][0]
1276 if file_md5 == db_md5:
1277 conn.commit()
1278 close_conn()
1279 _log.debug('MD5 sums of data file and database large object match: [file::%s] = [DB::%s]', file_md5, db_md5)
1280 return lo_oid
1281 conn.rollback()
1282 close_conn()
1283 _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)
1284 return -1
1285
1286
1288
1289 file_size = os.path.getsize(filename)
1290 if file_size > (1024 * 1024) * 1024:
1291 _log.debug('file size of [%s] > 1 GB, supposedly not supported by psycopg2 large objects (but seems to work anyway ?)', file_size)
1292
1293
1294 if conn is None:
1295 conn = get_raw_connection(readonly = False)
1296 close_conn = conn.close
1297 else:
1298 close_conn = __noop
1299 _log.debug('[%s] -> large object', filename)
1300
1301
1302 lo = conn.lobject(0, 'w', 0, filename)
1303 lo_oid = lo.oid
1304 lo.close()
1305 _log.debug('large object OID: %s', lo_oid)
1306
1307
1308 if file_md5 is None:
1309 conn.commit()
1310 close_conn()
1311 return lo_oid
1312 cmd = 'SELECT md5(lo_get(%(loid)s::oid))'
1313 args = {'loid': lo_oid}
1314 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': cmd, 'args': args}])
1315 db_md5 = rows[0][0]
1316 if file_md5 == db_md5:
1317 conn.commit()
1318 close_conn()
1319 _log.debug('MD5 sums of data file and database large object match: [file::%s] = [DB::%s]', file_md5, db_md5)
1320 return lo_oid
1321 conn.rollback()
1322 close_conn()
1323 _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)
1324 return -1
1325
1326
1327 -def file2bytea_copy_from(table=None, columns=None, filename=None, conn=None, md5_query=None, file_md5=None):
1328
1329
1330
1331
1332 chunk_size = 32 * (1024 * 1024)
1333 _log.debug('[%s] (%s bytes) --(%s bytes)-> %s(%s)', filename, os.path.getsize(filename), chunk_size, table, columns)
1334 if conn is None:
1335 conn = get_raw_connection(readonly = False)
1336 close_conn = True
1337 else:
1338 close_conn = False
1339 curs = conn.cursor()
1340
1341 infile = open(filename, "rb")
1342 curs.copy_from(infile, table, size = chunk_size, columns = columns)
1343 infile.close()
1344 curs.close()
1345 if None in [file_md5, md5_query]:
1346 conn.commit()
1347 close_conn()
1348 return True
1349
1350 rows, idx = run_ro_queries(link_obj = conn, queries = [md5_query])
1351 db_md5 = rows[0][0]
1352 if file_md5 == db_md5:
1353 conn.commit()
1354 close_conn()
1355 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5)
1356 return True
1357 close_conn()
1358 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5)
1359 return False
1360
1361
1362 -def file2bytea_overlay(query=None, args=None, filename=None, conn=None, md5_query=None, file_md5=None):
1363 """Store data from a file into a bytea field.
1364
1365 The query must:
1366 - 'cmd' must be in unicode
1367 - 'cmd' must contain a format spec identifying the row (eg
1368 a primary key) matching <args> if it is an UPDATE
1369 - 'cmd' must contain "... SET ... <some_bytea_field> = OVERLAY(some_bytea_field PLACING %(data)s::bytea FROM %(start)s FOR %(size)s) ..."
1370 - 'args' must be a dict matching 'cmd'
1371
1372 The query CAN return the MD5 of the inserted data:
1373 RETURNING md5(<field>) AS md5
1374 in which case it will compare it to the md5
1375 of the file.
1376
1377 UPDATE
1378 the_table
1379 SET
1380 bytea_field = OVERLAY (
1381 coalesce(bytea_field, '':bytea),
1382 PLACING
1383 %(data)s::bytea
1384 FROM
1385 %(start)s
1386 FOR
1387 %(size)s
1388 )
1389 WHERE
1390 primary_key = pk_value
1391
1392 SELECT md5(bytea_field) FROM the_table WHERE primary_key = pk_value
1393 """
1394 chunk_size = 32 * (1024 * 1024)
1395 file_size = os.path.getsize(filename)
1396 if file_size <= chunk_size:
1397 chunk_size = file_size
1398 needed_chunks, remainder = divmod(file_size, chunk_size)
1399 _log.debug('file data: %s bytes, chunks: %s, chunk size: %s bytes, remainder: %s bytes', file_size, needed_chunks, chunk_size, remainder)
1400
1401 if conn is None:
1402 conn = get_raw_connection(readonly = False)
1403 close_conn = conn.close
1404 else:
1405 close_conn = __noop
1406
1407 infile = open(filename, "rb")
1408
1409 for chunk_id in range(needed_chunks):
1410 chunk_start = (chunk_id * chunk_size) + 1
1411 args['start'] = chunk_start
1412 args['size'] = chunk_size
1413 data_as_byte_string = infile.read(chunk_size)
1414
1415 args['data'] = memoryview(data_as_byte_string)
1416 del(data_as_byte_string)
1417 try:
1418 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = False)
1419 except Exception:
1420 _log.exception('cannot write chunk [%s/%s] of size [%s], try decreasing chunk size', chunk_id+1, needed_chunks, chunk_size)
1421 conn.rollback()
1422 close_conn()
1423 infile.close()
1424 raise
1425
1426 if remainder > 0:
1427 chunk_start = (needed_chunks * chunk_size) + 1
1428 args['start'] = chunk_start
1429 args['size'] = remainder
1430 data_as_byte_string = infile.read(remainder)
1431
1432 args['data'] = memoryview(data_as_byte_string)
1433 del(data_as_byte_string)
1434 try:
1435 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = False)
1436 except Exception:
1437 _log.error('cannot retrieve remaining [%s] bytes' % remainder)
1438 conn.rollback()
1439 close_conn()
1440 infile.close()
1441 raise
1442 infile.close()
1443 if None in [file_md5, md5_query]:
1444 conn.commit()
1445 close_conn()
1446 return True
1447
1448 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': md5_query, 'args': args}])
1449 db_md5 = rows[0][0]
1450 if file_md5 == db_md5:
1451 conn.commit()
1452 close_conn()
1453 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5)
1454 return True
1455 close_conn()
1456 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5)
1457 return False
1458
1459
1461 if schema is None:
1462 schema = prompted_input(prompt = 'schema for table to dump', default = None)
1463 if schema is None:
1464 _log.debug('aborted by user (no schema entered)')
1465 return None
1466
1467 if table is None:
1468 table = prompted_input(prompt = 'table to dump (in schema %s.)' % schema, default = None)
1469 if table is None:
1470 _log.debug('aborted by user (no table entered)')
1471 return None
1472
1473 _log.debug('dumping <%s.%s>', schema, table)
1474 conn = get_connection(readonly=True, verbose = False, pooled = True, connection_name = 'read_all_rows_of_table')
1475
1476 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': SQL_get_primary_key_name, 'args': {'schema': schema, 'table': table}}])
1477 if rows:
1478 _log.debug('primary key def: %s', rows)
1479 if len(rows) > 1:
1480 _log.error('cannot handle multi-column primary key')
1481 return False
1482
1483 pk_name = rows[0][0]
1484 else:
1485 _log.debug('cannot determine primary key, asking user')
1486 pk_name = prompted_input(prompt = 'primary key name for %s.%s' % (schema, table), default = None)
1487 if pk_name is None:
1488 _log.debug('aborted by user (no primary key name entered)')
1489 return None
1490
1491
1492 qualified_table = '%s.%s' % (schema, table)
1493 qualified_pk_name = '%s.%s.%s' % (schema, table, pk_name)
1494 cmd = psysql.SQL('SELECT {schema_table_pk} FROM {schema_table} ORDER BY 1'.format (
1495 schema_table_pk = qualified_pk_name,
1496 schema_table = qualified_table
1497 ))
1498 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': cmd}])
1499 if not rows:
1500 _log.debug('no rows to dump')
1501 return True
1502
1503
1504 _log.debug('dumping %s rows', len(rows))
1505 cmd = psysql.SQL('SELECT * FROM {schema_table} WHERE {schema_table_pk} = %(pk_val)s'.format (
1506 schema_table = qualified_table,
1507 schema_table_pk = qualified_pk_name
1508 ))
1509 found_errors = False
1510 idx = 0
1511 for row in rows:
1512 idx += 1
1513 args = {'pk_val': row[0]}
1514 _log.debug('dumping row #%s with pk [%s]', idx, row[0])
1515 try:
1516 run_ro_queries(link_obj = conn, queries = [{'cmd': cmd, 'args': args}])
1517 except dbapi.InternalError:
1518 found_errors = True
1519 _log.exception('error dumping row')
1520 print('ERROR: cannot dump row %s of %s with pk %s = %s', idx, len(rows), qualified_pk_name, rows[0])
1521
1522 return found_errors is False
1523
1524
1525
1527
1528 if conn is None:
1529 conn = get_connection(readonly = False)
1530
1531 from Gnumed.pycommon import gmPsql
1532 psql = gmPsql.Psql(conn)
1533
1534 if psql.run(sql_script) == 0:
1535 query = {
1536 'cmd': 'select gm.log_script_insertion(%(name)s, %(ver)s)',
1537 'args': {'name': sql_script, 'ver': 'current'}
1538 }
1539 run_rw_queries(link_obj = conn, queries = [query])
1540 conn.commit()
1541 return True
1542
1543 _log.error('error running sql script: %s', sql_script)
1544 return False
1545
1546
1548 """Escape input for use in a PostgreSQL regular expression.
1549
1550 If a fragment comes from user input and is to be used
1551 as a regular expression we need to make sure it doesn't
1552 contain invalid regex patterns such as unbalanced ('s.
1553
1554 <escape_all>
1555 True: try to escape *all* metacharacters
1556 False: only escape those which render the regex invalid
1557 """
1558 return expression.replace (
1559 '(', '\('
1560 ).replace (
1561 ')', '\)'
1562 ).replace (
1563 '[', '\['
1564 ).replace (
1565 '+', '\+'
1566 ).replace (
1567 '.', '\.'
1568 ).replace (
1569 '*', '\*'
1570 ).replace (
1571 '?', '\?'
1572 )
1573
1574
1575
1576 -def run_ro_queries(link_obj=None, queries=None, verbose=False, return_data=True, get_col_idx=False):
1577 """Run read-only queries.
1578
1579 <queries> must be a list of dicts:
1580 [
1581 {'cmd': <string>, 'args': <dict> or <tuple>},
1582 {...},
1583 ...
1584 ]
1585 """
1586 if isinstance(link_obj, dbapi._psycopg.cursor):
1587 curs = link_obj
1588 curs_close = lambda *x:None
1589 tx_rollback = lambda *x:None
1590 readonly_rollback_just_in_case = lambda *x:None
1591 elif isinstance(link_obj, dbapi._psycopg.connection):
1592 curs = link_obj.cursor()
1593 curs_close = curs.close
1594 tx_rollback = link_obj.rollback
1595 if link_obj.autocommit is True:
1596 readonly_rollback_just_in_case = link_obj.rollback
1597 else:
1598
1599
1600
1601 readonly_rollback_just_in_case = lambda *x:None
1602 elif link_obj is None:
1603 conn = get_connection(readonly = True, verbose = verbose)
1604 curs = conn.cursor()
1605 curs_close = curs.close
1606 tx_rollback = conn.rollback
1607 readonly_rollback_just_in_case = conn.rollback
1608 else:
1609 raise ValueError('link_obj must be cursor, connection or None but not [%s]' % link_obj)
1610
1611 if verbose:
1612 _log.debug('cursor: %s', curs)
1613
1614 for query in queries:
1615 try:
1616 args = query['args']
1617 except KeyError:
1618 args = None
1619 try:
1620 curs.execute(query['cmd'], args)
1621 if verbose:
1622 gmConnectionPool.log_cursor_state(curs)
1623 except PG_ERROR_EXCEPTION as pg_exc:
1624 _log.error('query failed in RO connection')
1625 gmConnectionPool.log_pg_exception_details(pg_exc)
1626 try:
1627 curs_close()
1628 except PG_ERROR_EXCEPTION as pg_exc2:
1629 _log.exception('cannot close cursor')
1630 gmConnectionPool.log_pg_exception_details(pg_exc2)
1631 try:
1632 tx_rollback()
1633 except PG_ERROR_EXCEPTION as pg_exc2:
1634 _log.exception('cannot rollback transaction')
1635 gmConnectionPool.log_pg_exception_details(pg_exc2)
1636 if pg_exc.pgcode == sql_error_codes.INSUFFICIENT_PRIVILEGE:
1637 details = 'Query: [%s]' % curs.query.strip().strip('\n').strip().strip('\n')
1638 if curs.statusmessage != '':
1639 details = 'Status: %s\n%s' % (
1640 curs.statusmessage.strip().strip('\n').strip().strip('\n'),
1641 details
1642 )
1643 if pg_exc.pgerror is None:
1644 msg = '[%s]' % pg_exc.pgcode
1645 else:
1646 msg = '[%s]: %s' % (pg_exc.pgcode, pg_exc.pgerror)
1647 raise gmExceptions.AccessDenied (
1648 msg,
1649 source = 'PostgreSQL',
1650 code = pg_exc.pgcode,
1651 details = details
1652 )
1653 raise
1654 except Exception:
1655 _log.exception('error during query run in RO connection')
1656 gmConnectionPool.log_cursor_state(curs)
1657 try:
1658 curs_close()
1659 except PG_ERROR_EXCEPTION as pg_exc:
1660 _log.exception('cannot close cursor')
1661 gmConnectionPool.log_pg_exception_details(pg_exc)
1662 try:
1663 tx_rollback()
1664 except PG_ERROR_EXCEPTION as pg_exc:
1665 _log.exception('cannot rollback transation')
1666 gmConnectionPool.log_pg_exception_details(pg_exc)
1667 raise
1668
1669 data = None
1670 col_idx = None
1671 if return_data:
1672 data = curs.fetchall()
1673 if verbose:
1674 _log.debug('last query returned [%s (%s)] rows', curs.rowcount, len(data))
1675 _log.debug('cursor description: %s', curs.description)
1676 if get_col_idx:
1677 col_idx = get_col_indices(curs)
1678
1679 curs_close()
1680
1681
1682
1683 readonly_rollback_just_in_case()
1684 return (data, col_idx)
1685
1686
1687 -def run_rw_queries(link_obj=None, queries=None, end_tx=False, return_data=None, get_col_idx=False, verbose=False):
1688 """Convenience function for running a transaction
1689 that is supposed to get committed.
1690
1691 <link_obj>
1692 can be either:
1693 - a cursor
1694 - a connection
1695
1696 <queries>
1697 is a list of dicts [{'cmd': <string>, 'args': <dict> or <tuple>)
1698 to be executed as a single transaction, the last
1699 query may usefully return rows (such as a
1700 "SELECT currval('some_sequence')" statement)
1701
1702 <end_tx>
1703 - controls whether the transaction is finalized (eg.
1704 COMMITted/ROLLed BACK) or not, this allows the
1705 call to run_rw_queries() to be part of a framing
1706 transaction
1707 - if link_obj is a *connection* then <end_tx> will
1708 default to False unless it is explicitly set to
1709 True which is taken to mean "yes, you do have full
1710 control over the transaction" in which case the
1711 transaction is properly finalized
1712 - if link_obj is a *cursor* we CANNOT finalize the
1713 transaction because we would need the connection for that
1714 - if link_obj is *None* <end_tx> will, of course, always be True
1715
1716 <return_data>
1717 - if true, the returned data will include the rows
1718 the last query selected
1719 - if false, it returns None instead
1720
1721 <get_col_idx>
1722 - if true, the returned data will include a dictionary
1723 mapping field names to column positions
1724 - if false, the returned data returns None instead
1725
1726 method result:
1727 - returns a tuple (data, idx)
1728 - <data>:
1729 * (None, None) if last query did not return rows
1730 * ("fetchall() result", <index>) if last query returned any rows
1731 * for <index> see <get_col_idx>
1732 """
1733 if isinstance(link_obj, dbapi._psycopg.cursor):
1734 conn_close = lambda *x:None
1735 conn_commit = lambda *x:None
1736 tx_rollback = lambda *x:None
1737 curs = link_obj
1738 curs_close = lambda *x:None
1739 notices_accessor = curs.connection
1740 elif isinstance(link_obj, dbapi._psycopg.connection):
1741 conn_close = lambda *x:None
1742 if end_tx:
1743 conn_commit = link_obj.commit
1744 tx_rollback = link_obj.rollback
1745 else:
1746 conn_commit = lambda *x:None
1747 tx_rollback = lambda *x:None
1748 curs = link_obj.cursor()
1749 curs_close = curs.close
1750 notices_accessor = link_obj
1751 elif link_obj is None:
1752 conn = get_connection(readonly=False)
1753 conn_close = conn.close
1754 conn_commit = conn.commit
1755 tx_rollback = conn.rollback
1756 curs = conn.cursor()
1757 curs_close = curs.close
1758 notices_accessor = conn
1759 else:
1760 raise ValueError('link_obj must be cursor, connection or None but not [%s]' % link_obj)
1761
1762 for query in queries:
1763 try:
1764 args = query['args']
1765 except KeyError:
1766 args = None
1767 try:
1768 curs.execute(query['cmd'], args)
1769 if verbose:
1770 gmConnectionPool.log_cursor_state(curs)
1771 for notice in notices_accessor.notices:
1772 _log.debug(notice.replace('\n', '/').replace('\n', '/'))
1773 del notices_accessor.notices[:]
1774
1775 except dbapi.Error as pg_exc:
1776 _log.error('query failed in RW connection')
1777 gmConnectionPool.log_pg_exception_details(pg_exc)
1778 for notice in notices_accessor.notices:
1779 _log.debug(notice.replace('\n', '/').replace('\n', '/'))
1780 del notices_accessor.notices[:]
1781 try:
1782 curs_close()
1783 except PG_ERROR_EXCEPTION as pg_exc2:
1784 _log.exception('cannot close cursor')
1785 gmConnectionPool.log_pg_exception_details(pg_exc2)
1786 try:
1787 tx_rollback()
1788 except PG_ERROR_EXCEPTION as pg_exc2:
1789 _log.exception('cannot rollback transaction')
1790 gmConnectionPool.log_pg_exception_details(pg_exc2)
1791
1792 if pg_exc.pgcode == sql_error_codes.INSUFFICIENT_PRIVILEGE:
1793 details = 'Query: [%s]' % curs.query.strip().strip('\n').strip().strip('\n')
1794 if curs.statusmessage != '':
1795 details = 'Status: %s\n%s' % (
1796 curs.statusmessage.strip().strip('\n').strip().strip('\n'),
1797 details
1798 )
1799 if pg_exc.pgerror is None:
1800 msg = '[%s]' % pg_exc.pgcode
1801 else:
1802 msg = '[%s]: %s' % (pg_exc.pgcode, pg_exc.pgerror)
1803 try:
1804 curs_close()
1805 tx_rollback()
1806 conn_close()
1807 except dbapi.InterfaceError:
1808 _log.exception('cannot cleanup')
1809 raise gmExceptions.AccessDenied (
1810 msg,
1811 source = 'PostgreSQL',
1812 code = pg_exc.pgcode,
1813 details = details
1814 )
1815
1816 gmLog2.log_stack_trace()
1817 try:
1818 curs_close()
1819 tx_rollback()
1820 conn_close()
1821 except dbapi.InterfaceError:
1822 _log.exception('cannot cleanup')
1823 raise
1824
1825 except Exception:
1826 _log.exception('error running query in RW connection')
1827 gmConnectionPool.log_cursor_state(curs)
1828 for notice in notices_accessor.notices:
1829 _log.debug(notice.replace('\n', '/').replace('\n', '/'))
1830 del notices_accessor.notices[:]
1831 gmLog2.log_stack_trace()
1832 try:
1833 curs_close()
1834 except PG_ERROR_EXCEPTION as pg_exc:
1835 _log.exception('cannot close cursor')
1836 gmConnectionPool.log_pg_exception_details(pg_exc)
1837 try:
1838 tx_rollback()
1839 conn_close()
1840 except PG_ERROR_EXCEPTION as pg_exc:
1841 _log.exception('cannot rollback transation')
1842 gmConnectionPool.log_pg_exception_details(pg_exc)
1843 raise
1844
1845 data = None
1846 col_idx = None
1847 if return_data:
1848 try:
1849 data = curs.fetchall()
1850 except Exception:
1851 _log.exception('error fetching data from RW query')
1852 gmLog2.log_stack_trace()
1853 try:
1854 curs_close()
1855 tx_rollback()
1856 conn_close()
1857 except dbapi.InterfaceError:
1858 _log.exception('cannot cleanup')
1859 raise
1860 raise
1861 if get_col_idx:
1862 col_idx = get_col_indices(curs)
1863
1864 curs_close()
1865 conn_commit()
1866 conn_close()
1867
1868 return (data, col_idx)
1869
1870
1871 -def run_insert(link_obj=None, schema=None, table=None, values=None, returning=None, end_tx=False, get_col_idx=False, verbose=False):
1872 """Generates SQL for an INSERT query.
1873
1874 values: dict of values keyed by field to insert them into
1875 """
1876 if schema is None:
1877 schema = 'public'
1878
1879 fields = list(values)
1880 val_snippets = []
1881 for field in fields:
1882 val_snippets.append('%%(%s)s' % field)
1883
1884 if returning is None:
1885 returning = ''
1886 return_data = False
1887 else:
1888 returning = '\n\tRETURNING\n\t\t%s' % ', '.join(returning)
1889 return_data = True
1890
1891 cmd = """\nINSERT INTO %s.%s (
1892 %s
1893 ) VALUES (
1894 %s
1895 )%s""" % (
1896 schema,
1897 table,
1898 ',\n\t\t'.join(fields),
1899 ',\n\t\t'.join(val_snippets),
1900 returning
1901 )
1902
1903 _log.debug('running SQL: >>>%s<<<', cmd)
1904
1905 return run_rw_queries (
1906 link_obj = link_obj,
1907 queries = [{'cmd': cmd, 'args': values}],
1908 end_tx = end_tx,
1909 return_data = return_data,
1910 get_col_idx = get_col_idx,
1911 verbose = verbose
1912 )
1913
1914
1915
1916
1917 -def get_raw_connection(verbose=False, readonly=True, connection_name=None, autocommit=False):
1918 """Get a raw, unadorned connection.
1919
1920 - this will not set any parameters such as encoding, timezone, datestyle
1921 - the only requirement is valid connection parameters having been passed to the connection pool
1922 - hence it can be used for "service" connections
1923 for verifying encodings etc
1924 """
1925 return gmConnectionPool.gmConnectionPool().get_raw_connection (
1926 readonly = readonly,
1927 verbose = verbose,
1928 connection_name = connection_name,
1929 autocommit = autocommit
1930 )
1931
1932
1933 -def get_connection(readonly=True, verbose=False, pooled=True, connection_name=None, autocommit=False):
1934 return gmConnectionPool.gmConnectionPool().get_connection (
1935 readonly = readonly,
1936 verbose = verbose,
1937 connection_name = connection_name,
1938 autocommit = autocommit,
1939 pooled = pooled
1940 )
1941
1942
1945
1946
1948 gmConnectionPool.gmConnectionPool().shutdown()
1949
1950
1951
1952
1955
1956
1958 run_insert (
1959 schema = 'gm',
1960 table = 'access_log',
1961 values = {'user_action': action},
1962 end_tx = True
1963 )
1964
1965
1967 """Check server time and local time to be within
1968 the given tolerance of each other.
1969
1970 tolerance: seconds
1971 """
1972 _log.debug('maximum skew tolerance (seconds): %s', tolerance)
1973
1974 cmd = "SELECT now() at time zone 'UTC'"
1975 conn = get_raw_connection(readonly=True)
1976 curs = conn.cursor()
1977
1978 start = time.time()
1979 rows, idx = run_ro_queries(link_obj = curs, queries = [{'cmd': cmd}])
1980 end = time.time()
1981 client_now_as_utc = pydt.datetime.utcnow()
1982
1983 curs.close()
1984 conn.commit()
1985
1986 server_now_as_utc = rows[0][0]
1987 query_duration = end - start
1988 _log.info('server "now" (UTC): %s', server_now_as_utc)
1989 _log.info('client "now" (UTC): %s', client_now_as_utc)
1990 _log.debug('wire roundtrip (seconds): %s', query_duration)
1991
1992 if query_duration > tolerance:
1993 _log.error('useless to check client/server time skew, wire roundtrip > tolerance')
1994 return False
1995
1996 if server_now_as_utc > client_now_as_utc:
1997 real_skew = server_now_as_utc - client_now_as_utc
1998 else:
1999 real_skew = client_now_as_utc - server_now_as_utc
2000
2001 _log.debug('client/server time skew: %s', real_skew)
2002
2003 if real_skew > pydt.timedelta(seconds = tolerance):
2004 _log.error('client/server time skew > tolerance')
2005 return False
2006
2007 return True
2008
2009
2011 """Checks database settings.
2012
2013 returns (status, message)
2014 status:
2015 0: no problem
2016 1: non-fatal problem
2017 2: fatal problem
2018 """
2019 _log.debug('checking database settings')
2020
2021 conn = get_connection()
2022
2023
2024 global postgresql_version_string
2025 if postgresql_version_string is None:
2026 curs = conn.cursor()
2027 curs.execute('SELECT version()')
2028 postgresql_version_string = curs.fetchone()['version']
2029 curs.close()
2030 _log.info('PostgreSQL version (string): "%s"' % postgresql_version_string)
2031
2032 options2check = {
2033
2034 'allow_system_table_mods': [['off'], 'system breakage', False],
2035 'check_function_bodies': [['on'], 'suboptimal error detection', False],
2036 'datestyle': [['ISO'], 'faulty timestamp parsing', True],
2037 'default_transaction_isolation': [['read committed'], 'faulty database reads', True],
2038 'default_transaction_read_only': [['on'], 'accidental database writes', False],
2039 'fsync': [['on'], 'data loss/corruption', True],
2040 'full_page_writes': [['on'], 'data loss/corruption', False],
2041 'lc_messages': [['C'], 'suboptimal error detection', False],
2042 'password_encryption': [['on', 'md5', 'scram-sha-256'], 'breach of confidentiality', False],
2043
2044 'synchronous_commit': [['on'], 'data loss/corruption', False],
2045 'sql_inheritance': [['on'], 'query breakage, data loss/corruption', True],
2046 'ignore_checksum_failure': [['off'], 'data loss/corruption', False],
2047 'track_commit_timestamp': [['on'], 'suboptimal auditing', False]
2048 }
2049
2050 from Gnumed.pycommon import gmCfg2
2051 _cfg = gmCfg2.gmCfgData()
2052 if _cfg.get(option = 'hipaa'):
2053 options2check['log_connections'] = [['on'], 'non-compliance with HIPAA', True]
2054 options2check['log_disconnections'] = [['on'], 'non-compliance with HIPAA', True]
2055 else:
2056 options2check['log_connections'] = [['on'], 'non-compliance with HIPAA', None]
2057 options2check['log_disconnections'] = [['on'], 'non-compliance with HIPAA', None]
2058
2059 cmd = "SELECT name, setting from pg_settings where name in %(settings)s"
2060 rows, idx = run_ro_queries (
2061 link_obj = conn,
2062 queries = [{'cmd': cmd, 'args': {'settings': tuple(options2check)}}],
2063 get_col_idx = False
2064 )
2065
2066 found_error = False
2067 found_problem = False
2068 msg = []
2069 for row in rows:
2070 option = row['name']
2071 value_found = row['setting']
2072 values_expected = options2check[option][0]
2073 risk = options2check[option][1]
2074 fatal_setting = options2check[option][2]
2075 if value_found not in values_expected:
2076 if fatal_setting is True:
2077 found_error = True
2078 elif fatal_setting is False:
2079 found_problem = True
2080 elif fatal_setting is None:
2081 pass
2082 else:
2083 _log.error(options2check[option])
2084 raise ValueError('invalid database configuration sanity check')
2085 msg.append(_(' option [%s]: %s') % (option, value_found))
2086 msg.append(_(' risk: %s') % risk)
2087 _log.warning('PG option [%s] set to [%s], expected %s, risk: <%s>' % (option, value_found, values_expected, risk))
2088
2089 if found_error:
2090 return 2, '\n'.join(msg)
2091
2092 if found_problem:
2093 return 1, '\n'.join(msg)
2094
2095 return 0, ''
2096
2097
2098
2099
2100 log_pg_settings = gmConnectionPool.log_pg_settings
2101 log_pg_exception_details = gmConnectionPool.log_pg_exception_details
2102
2103 exception_is_connection_loss = gmConnectionPool.exception_is_connection_loss
2104
2105 cAuthenticationError = gmConnectionPool.cAuthenticationError
2106
2107
2108 if __name__ == "__main__":
2109
2110 if len(sys.argv) < 2:
2111 sys.exit()
2112
2113 if sys.argv[1] != 'test':
2114 sys.exit()
2115
2116 from Gnumed.pycommon.gmTools import file2md5
2117
2118 logging.basicConfig(level=logging.DEBUG)
2119
2120
2122 login, creds = request_login_params()
2123 pool = gmConnectionPool.gmConnectionPool()
2124 pool.credentials = creds
2125 run_rw_queries(queries = [
2126 {'cmd': 'drop table if exists test_bytea'},
2127 {'cmd': 'create table test_bytea (data bytea)'}
2128 ])
2129 try:
2130
2131 file2bytea(query = 'insert into test_bytea values (%(data)s::bytea)', filename = sys.argv[2])
2132 except Exception:
2133 _log.exception('error')
2134
2135 run_rw_queries(queries = [
2136 {'cmd': 'drop table test_bytea'}
2137 ])
2138
2139
2150
2151
2152
2153
2154
2155
2157 login, creds = request_login_params()
2158 pool = gmConnectionPool.gmConnectionPool()
2159 pool.credentials = creds
2160
2161 run_rw_queries(queries = [
2162 {'cmd': 'drop table if exists test_bytea'},
2163 {'cmd': 'create table test_bytea (pk serial primary key, data bytea)'},
2164 {'cmd': "insert into test_bytea (data) values (NULL::bytea)"}
2165 ])
2166
2167 md5_query = {
2168 'cmd': 'select md5(data) AS md5 FROM test_bytea WHERE pk = %(pk)s',
2169 'args': {'pk': 1}
2170 }
2171
2172 file2bytea_copy_from (
2173 table = 'test_bytea',
2174 columns = ['data'],
2175 filename = sys.argv[2],
2176 md5_query = md5_query,
2177 file_md5 = file2md5(sys.argv[2], True)
2178 )
2179
2180 run_rw_queries(queries = [
2181 {'cmd': 'drop table if exists test_bytea'}
2182 ])
2183
2184
2186 login, creds = request_login_params()
2187 pool = gmConnectionPool.gmConnectionPool()
2188 pool.credentials = creds
2189
2190 run_rw_queries(queries = [
2191 {'cmd': 'drop table if exists test_bytea'},
2192 {'cmd': 'create table test_bytea (pk serial primary key, data bytea)'},
2193 {'cmd': "insert into test_bytea (data) values (NULL::bytea)"}
2194 ])
2195
2196 cmd = """
2197 update test_bytea
2198 set data = overlay (
2199 coalesce(data, ''::bytea)
2200 placing %(data)s::bytea
2201 from %(start)s
2202 for %(size)s
2203 )
2204 where
2205 pk > %(pk)s
2206 """
2207 md5_cmd = 'select md5(data) from test_bytea'
2208 args = {'pk': 0}
2209 file2bytea_overlay (
2210 query = cmd,
2211 args = args,
2212 filename = sys.argv[2],
2213 conn = None,
2214 md5_query = md5_cmd,
2215 file_md5 = file2md5(sys.argv[2], True)
2216 )
2217
2218 run_rw_queries(queries = [
2219 {'cmd': 'drop table test_bytea'}
2220 ])
2221
2222
2224 print("testing get_connection()")
2225
2226 login, creds = request_login_params()
2227 pool = gmConnectionPool.gmConnectionPool()
2228 pool.credentials = creds
2229
2230 print('')
2231 dsn = 'foo'
2232 try:
2233 conn = get_connection(dsn=dsn)
2234 except dbapi.ProgrammingError as e:
2235 print("1) SUCCESS: get_connection(%s) failed as expected" % dsn)
2236 t, v = sys.exc_info()[:2]
2237 print (' ', t)
2238 print (' ', v)
2239
2240 print('')
2241 dsn = 'dbname=gnumed_v22'
2242 try:
2243 conn = get_connection(dsn=dsn)
2244 print("2) ERROR: get_connection() did not fail")
2245 except cAuthenticationError:
2246 print("2) SUCCESS: get_connection(%s) failed as expected" % dsn)
2247 t, v = sys.exc_info()[:2]
2248 print(' ', t)
2249 print(' ', v)
2250
2251 print('')
2252 dsn = 'dbname=gnumed_v22 user=abc'
2253 try:
2254 conn = get_connection(dsn=dsn)
2255 print("3) ERROR: get_connection() did not fail")
2256 except cAuthenticationError:
2257 print("3) SUCCESS: get_connection(%s) failed as expected" % dsn)
2258 t, v = sys.exc_info()[:2]
2259 print(' ', t)
2260 print(' ', v)
2261
2262 print('')
2263 dsn = 'dbname=gnumed_v22 user=any-doc password=abc'
2264 try:
2265 conn = get_connection(dsn=dsn)
2266 print("4) ERROR: get_connection() did not fail")
2267 except cAuthenticationError:
2268 print("4) SUCCESS: get_connection(%s) failed as expected" % dsn)
2269 t, v = sys.exc_info()[:2]
2270 print(' ', t)
2271 print(' ', v)
2272
2273 print('')
2274 dsn = 'dbname=gnumed_v22 user=any-doc password=any-doc'
2275 conn = get_connection(dsn=dsn, readonly=True)
2276 print('5) SUCCESS: get_connection(ro)')
2277
2278 dsn = 'dbname=gnumed_v22 user=any-doc password=any-doc'
2279 conn = get_connection(dsn=dsn, readonly=False, verbose=True)
2280 print('6) SUCCESS: get_connection(rw)')
2281
2282 print('')
2283 dsn = 'dbname=gnumed_v22 user=any-doc'
2284 try:
2285 conn = get_connection(dsn=dsn)
2286 print("8) SUCCESS:", dsn)
2287 print('pid:', conn.get_backend_pid())
2288 except cAuthenticationError:
2289 print("4) SUCCESS: get_connection(%s) failed" % dsn)
2290 t, v = sys.exc_info()[:2]
2291 print(' ', t)
2292 print(' ', v)
2293
2294 try:
2295 curs = conn.cursor()
2296 input('hit enter to run query')
2297 curs.execute('selec 1')
2298 except Exception as exc:
2299 print('ERROR')
2300 _log.exception('exception occurred')
2301 gmConnectionPool.log_pg_exception_details(exc)
2302 if gmConnectionPool.exception_is_connection_loss(exc):
2303 _log.error('lost connection')
2304
2305
2307 login, creds = request_login_params()
2308 pool = gmConnectionPool.gmConnectionPool()
2309 pool.credentials = creds
2310
2311 print("testing run_ro_queries()")
2312
2313 dsn = 'dbname=gnumed_v22 user=any-doc password=any-doc'
2314 conn = get_connection(dsn, readonly=True)
2315
2316 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': 'SELECT version()'}], return_data=True, get_col_idx=True, verbose=True)
2317 print(data)
2318 print(idx)
2319 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': 'SELECT 1'}], return_data=True, get_col_idx=True)
2320 print(data)
2321 print(idx)
2322
2323 curs = conn.cursor()
2324
2325 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'SELECT version()'}], return_data=True, get_col_idx=True, verbose=True)
2326 print(data)
2327 print(idx)
2328
2329 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'SELECT 1'}], return_data=True, get_col_idx=True, verbose=True)
2330 print(data)
2331 print(idx)
2332
2333 try:
2334 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'selec 1'}], return_data=True, get_col_idx=True, verbose=True)
2335 print(data)
2336 print(idx)
2337 except psycopg2.ProgrammingError:
2338 print('SUCCESS: run_ro_queries("selec 1") failed as expected')
2339 t, v = sys.exc_info()[:2]
2340 print(' ', t)
2341 print(' ', v)
2342
2343 curs.close()
2344
2345
2355
2356
2358 login, creds = request_login_params()
2359 pool = gmConnectionPool.gmConnectionPool()
2360 pool.credentials = creds
2361 conn = get_connection('', readonly=True)
2362 curs = conn.cursor()
2363 curs.execute('SELECT * from clin.clin_narrative where narrative = %s', ['a'])
2364
2365
2367 tests = [
2368 ['(', '\\(']
2369 , ['[', '\\[']
2370 , [')', '\\)']
2371 ]
2372 for test in tests:
2373 result = sanitize_pg_regex(test[0])
2374 if result != test[1]:
2375 print('ERROR: sanitize_pg_regex(%s) returned "%s", expected "%s"' % (test[0], result, test[1]))
2376
2377
2379 login, creds = request_login_params()
2380 pool = gmConnectionPool.gmConnectionPool()
2381 pool.credentials = creds
2382 status = True
2383 tests = [
2384 [None, True],
2385 [1, True],
2386 ['1', True],
2387 ['abc', False]
2388 ]
2389
2390 if not is_pg_interval():
2391 print('ERROR: is_pg_interval() returned "False", expected "True"')
2392 status = False
2393
2394 for test in tests:
2395 result = is_pg_interval(test[0])
2396 if result != test[1]:
2397 print('ERROR: is_pg_interval(%s) returned "%s", expected "%s"' % (test[0], result, test[1]))
2398 status = False
2399
2400 return status
2401
2402
2408
2409
2411 login, creds = request_login_params()
2412 pool = gmConnectionPool.gmConnectionPool()
2413 pool.credentials = creds
2414 schema = 'clin'
2415 table = 'episode'
2416 col = 'pk'
2417 print('column %s.%s.%s is referenced by:' % (schema, table, col))
2418 for row in get_foreign_keys2column (
2419 schema = schema,
2420 table = table,
2421 column = col
2422 ):
2423 print(' <- %s.%s' % (
2424 row['referencing_table'],
2425 row['referencing_column']
2426 ))
2427
2428
2430 login, creds = request_login_params()
2431 pool = gmConnectionPool.gmConnectionPool()
2432 pool.credentials = creds
2433
2434 tests = [
2435
2436 [None, 'de_DE', True],
2437 [None, 'lang_w/o_tx', False],
2438 [None, None, True],
2439
2440 ['any-doc', 'de_DE', True],
2441 ['any-doc', 'lang_w/o_tx', False],
2442 ['any-doc', None, True],
2443
2444 ['invalid user', 'de_DE', None],
2445 ['invalid user', 'lang_w/o_tx', False],
2446 ['invalid user', None, True]
2447 ]
2448 for test in tests:
2449 print('testing: %s', test)
2450 try:
2451 result = set_user_language(user = test[0], language = test[1])
2452 if result != test[2]:
2453 print("test:", test)
2454 print("result:", result, "expected:", test[2])
2455 except psycopg2.IntegrityError as e:
2456 print(e)
2457 if test[2] is None:
2458 continue
2459 print("test:", test)
2460 print("expected exception")
2461 print("result:", e)
2462
2463
2465 login, creds = request_login_params()
2466 pool = gmConnectionPool.gmConnectionPool()
2467 pool.credentials = creds
2468 for line in get_schema_revision_history():
2469 print(' - '.join(line))
2470
2471
2473 login, creds = request_login_params()
2474 pool = gmConnectionPool.gmConnectionPool()
2475 pool.credentials = creds
2476 gmDateTime.init()
2477 args = {'dt': gmDateTime.pydt_max_here()}
2478 cmd = "SELECT %(dt)s"
2479
2480
2481
2482 cmd = """
2483 SELECT to_timestamp (foofoo,'YYMMDD.HH24MI') FROM (
2484 SELECT REGEXP_REPLACE (
2485 't1.130729.0902.tif', -- string
2486 E'(.1)\.([0-9\.]+)(\.tif)', -- pattern
2487 E'\\\\2' -- replacement
2488 ) AS foofoo
2489 ) AS foo"""
2490 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False)
2491 print(rows)
2492 print(rows[0])
2493 print(rows[0][0])
2494
2495
2501
2502
2504 login, creds = request_login_params()
2505 pool = gmConnectionPool.gmConnectionPool()
2506 pool.credentials = creds
2507
2508 row_is_locked(table = 'dem.identity', pk = 12)
2509
2510 print("1st connection:")
2511 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2512 print(" 1st shared lock succeeded:", lock_row(table = 'dem.identity', pk = 12, exclusive = False))
2513 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2514
2515 print(" 2nd shared lock should succeed:", lock_row(table = 'dem.identity', pk = 12, exclusive = False))
2516 print(" `-> unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = False))
2517 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2518 print(" exclusive lock should succeed:", lock_row(table = 'dem.identity', pk = 12, exclusive = True))
2519 print(" `-> unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = True))
2520 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2521
2522 print("2nd connection:")
2523 conn = get_raw_connection(readonly=True)
2524 print(" shared lock should succeed:", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
2525 print(" `-> unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
2526 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2527 print(" exclusive lock succeeded ?", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = True), "(should fail)")
2528 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2529
2530 print("1st connection:")
2531 print(" unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = False))
2532 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2533
2534 print("2nd connection:")
2535 print(" exclusive lock should succeed", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = True))
2536 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2537 print(" shared lock should succeed:", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
2538 print(" `-> unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
2539 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2540 print(" unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
2541 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2542
2543 conn.close()
2544
2545
2547 login, creds = request_login_params()
2548 pool = gmConnectionPool.gmConnectionPool()
2549 pool.credentials = creds
2550 print(get_foreign_key_names (
2551 src_schema = 'clin',
2552 src_table = 'vaccination',
2553 src_column = 'fk_episode',
2554 target_schema = 'clin',
2555 target_table = 'episode',
2556 target_column = 'pk'
2557 ))
2558 print(get_foreign_key_names (
2559 src_schema = 'dem',
2560 src_table = 'names',
2561 src_column = 'id_identity',
2562 target_schema = 'dem',
2563 target_table = 'identity',
2564 target_column = 'pk'
2565 ))
2566
2567
2569 login, creds = request_login_params()
2570 pool = gmConnectionPool.gmConnectionPool()
2571 pool.credentials = creds
2572 print(get_index_name(indexed_table = 'clin.vaccination', indexed_column = 'fk_episode'))
2573
2574
2581
2582
2589
2590
2598
2599
2600
2601
2602
2603
2604
2605
2606
2607
2608
2609
2610
2611
2612
2613
2614
2615
2616
2617
2618
2619
2620
2621
2622
2623
2624
2625
2626
2627 test_get_db_fingerprint()
2628
2629
2630