1 """GNUmed PostgreSQL connection handling.
2
3 TODO: iterator/generator batch fetching:
4 - http://groups-beta.google.com/group/comp.lang.python/msg/7ff516d7d9387dad
5 - search Google for "Geneator/Iterator Nesting Problem - Any Ideas? 2.4"
6
7 winner:
8 def resultset_functional_batchgenerator(cursor, size=100):
9 for results in iter(lambda: cursor.fetchmany(size), []):
10 for rec in results:
11 yield rec
12 """
13
14 __author__ = "K.Hilbert <Karsten.Hilbert@gmx.net>"
15 __license__ = 'GPL v2 or later (details at http://www.gnu.org)'
16
17
18 import time
19 import sys
20 import os
21 import io
22 import codecs
23 import logging
24 import datetime as pydt
25 import re as regex
26 import threading
27
28
29
30 if __name__ == '__main__':
31 sys.path.insert(0, '../../')
32 from Gnumed.pycommon import gmLoginInfo
33 from Gnumed.pycommon import gmExceptions
34 from Gnumed.pycommon import gmDateTime
35 from Gnumed.pycommon import gmBorg
36 from Gnumed.pycommon import gmI18N
37 from Gnumed.pycommon import gmLog2
38 from Gnumed.pycommon.gmTools import prompted_input, u_replacement_character, format_dict_like
39
40 _log = logging.getLogger('gm.db')
41
42
43
44 try:
45 import psycopg2 as dbapi
46 except ImportError:
47 _log.exception("Python database adapter psycopg2 not found.")
48 print("CRITICAL ERROR: Cannot find module psycopg2 for connecting to the database server.")
49 raise
50
51
52 _log.info('psycopg2 version: %s' % dbapi.__version__)
53 _log.info('PostgreSQL via DB-API module "%s": API level %s, thread safety %s, parameter style "%s"' % (dbapi, dbapi.apilevel, dbapi.threadsafety, dbapi.paramstyle))
54 if not (float(dbapi.apilevel) >= 2.0):
55 raise ImportError('gmPG2: supported DB-API level too low')
56 if not (dbapi.threadsafety > 0):
57 raise ImportError('gmPG2: lacking minimum thread safety in psycopg2')
58 if not (dbapi.paramstyle == 'pyformat'):
59 raise ImportError('gmPG2: lacking pyformat (%%(<name>)s style) placeholder support in psycopg2')
60 try:
61 dbapi.__version__.index('dt')
62 except ValueError:
63 raise ImportError('gmPG2: lacking datetime support in psycopg2')
64 try:
65 dbapi.__version__.index('ext')
66 except ValueError:
67 raise ImportError('gmPG2: lacking extensions support in psycopg2')
68 try:
69 dbapi.__version__.index('pq3')
70 except ValueError:
71 raise ImportError('gmPG2: lacking v3 backend protocol support in psycopg2')
72
73 import psycopg2.extras
74 import psycopg2.extensions
75 import psycopg2.pool
76 import psycopg2.errorcodes as sql_error_codes
77
78
79 _default_client_encoding = 'UTF8'
80 _log.info('assuming default client encoding of [%s]' % _default_client_encoding)
81
82
83 _default_client_timezone = None
84 _sql_set_timezone = None
85 _timestamp_template = "cast('%s' as timestamp with time zone)"
86 FixedOffsetTimezone = dbapi.tz.FixedOffsetTimezone
87
88 _default_dsn = None
89 _default_login = None
90
91 default_database = 'gnumed_v22'
92
93 postgresql_version_string = None
94 postgresql_version = None
95
96 __ro_conn_pool = None
97
98 auto_request_login_params = True
99
100
101
102
103 known_schema_hashes = {
104 0: 'not released, testing only',
105 2: 'b09d50d7ed3f91ddf4c4ddb8ea507720',
106 3: 'e73718eaf230d8f1d2d01afa8462e176',
107 4: '4428ccf2e54c289136819e701bb095ea',
108 5: '7e7b093af57aea48c288e76632a382e5',
109 6: '90e2026ac2efd236da9c8608b8685b2d',
110 7: '6c9f6d3981483f8e9433df99d1947b27',
111 8: '89b13a7af83337c3aad153b717e52360',
112 9: '641a9b2be3c378ffc2bb2f0b1c9f051d',
113 10: '7ef42a8fb2bd929a2cdd0c63864b4e8a',
114 11: '03042ae24f3f92877d986fb0a6184d76',
115 12: '06183a6616db62257e22814007a8ed07',
116 13: 'fab7c1ae408a6530c47f9b5111a0841e',
117 14: 'e170d543f067d1ea60bfe9076b1560cf',
118 15: '70012ff960b77ecdff4981c94b5b55b6',
119 16: '0bcf44ca22c479b52976e5eda1de8161',
120 17: '161428ee97a00e3bf56168c3a15b7b50',
121 18: 'a0f9efcabdecfb4ddb6d8c0b69c02092',
122
123
124 19: '57f009a159f55f77525cc0291e0c8b60',
125 20: 'baed1901ed4c2f272b56c8cb2c6d88e8',
126 21: 'e6a51a89dd22b75b61ead8f7083f251f',
127 22: 'bf45f01327fb5feb2f5d3c06ba4a6792'
128 }
129
130 map_schema_hash2version = {
131 'b09d50d7ed3f91ddf4c4ddb8ea507720': 2,
132 'e73718eaf230d8f1d2d01afa8462e176': 3,
133 '4428ccf2e54c289136819e701bb095ea': 4,
134 '7e7b093af57aea48c288e76632a382e5': 5,
135 '90e2026ac2efd236da9c8608b8685b2d': 6,
136 '6c9f6d3981483f8e9433df99d1947b27': 7,
137 '89b13a7af83337c3aad153b717e52360': 8,
138 '641a9b2be3c378ffc2bb2f0b1c9f051d': 9,
139 '7ef42a8fb2bd929a2cdd0c63864b4e8a': 10,
140 '03042ae24f3f92877d986fb0a6184d76': 11,
141 '06183a6616db62257e22814007a8ed07': 12,
142 'fab7c1ae408a6530c47f9b5111a0841e': 13,
143 'e170d543f067d1ea60bfe9076b1560cf': 14,
144 '70012ff960b77ecdff4981c94b5b55b6': 15,
145 '0bcf44ca22c479b52976e5eda1de8161': 16,
146 '161428ee97a00e3bf56168c3a15b7b50': 17,
147 'a0f9efcabdecfb4ddb6d8c0b69c02092': 18,
148
149
150 '57f009a159f55f77525cc0291e0c8b60': 19,
151 'baed1901ed4c2f272b56c8cb2c6d88e8': 20,
152 'e6a51a89dd22b75b61ead8f7083f251f': 21,
153 'bf45f01327fb5feb2f5d3c06ba4a6792': 22
154 }
155
156 map_client_branch2required_db_version = {
157 'GIT tree': 0,
158 '0.3': 9,
159 '0.4': 10,
160 '0.5': 11,
161 '0.6': 12,
162 '0.7': 13,
163 '0.8': 14,
164 '0.9': 15,
165 '1.0': 16,
166 '1.1': 16,
167 '1.2': 17,
168 '1.3': 18,
169 '1.4': 19,
170 '1.5': 20,
171 '1.6': 21,
172 '1.7': 22,
173 '1.8': 22
174 }
175
176 map_psyco_tx_status2str = [
177 'TRANSACTION_STATUS_IDLE',
178 'TRANSACTION_STATUS_ACTIVE',
179 'TRANSACTION_STATUS_INTRANS',
180 'TRANSACTION_STATUS_INERROR',
181 'TRANSACTION_STATUS_UNKNOWN'
182 ]
183
184 map_psyco_conn_status2str = [
185 '0 - ?',
186 'STATUS_READY',
187 'STATUS_BEGIN_ALIAS_IN_TRANSACTION',
188 'STATUS_PREPARED'
189 ]
190
191 map_psyco_iso_level2str = {
192 None: 'ISOLATION_LEVEL_DEFAULT (configured on server)',
193 0: 'ISOLATION_LEVEL_AUTOCOMMIT',
194 1: 'ISOLATION_LEVEL_READ_UNCOMMITTED',
195 2: 'ISOLATION_LEVEL_REPEATABLE_READ',
196 3: 'ISOLATION_LEVEL_SERIALIZABLE',
197 4: 'ISOLATION_LEVEL_READ_UNCOMMITTED'
198 }
199
200
201 query_table_col_defs = """select
202 cols.column_name,
203 cols.udt_name
204 from
205 information_schema.columns cols
206 where
207 cols.table_schema = %s
208 and
209 cols.table_name = %s
210 order by
211 cols.ordinal_position"""
212
213 query_table_attributes = """select
214 cols.column_name
215 from
216 information_schema.columns cols
217 where
218 cols.table_schema = %s
219 and
220 cols.table_name = %s
221 order by
222 cols.ordinal_position"""
223
224
225
226 SQL_foreign_key_name = """SELECT
227 fk_tbl.*,
228 (SELECT nspname FROM pg_catalog.pg_namespace WHERE oid = fk_tbl.connamespace) AS constraint_schema,
229 fk_tbl.conname AS constraint_name,
230 (SELECT nspname FROM pg_catalog.pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class where oid = fk_tbl.conrelid)) AS source_schema,
231 (SELECT relname FROM pg_catalog.pg_class where oid = fk_tbl.conrelid) AS source_table,
232 (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,
233 (SELECT nspname FROM pg_catalog.pg_namespace WHERE oid = (SELECT relnamespace FROM pg_class where oid = fk_tbl.confrelid)) AS target_schema,
234 (SELECT relname FROM pg_catalog.pg_class where oid = fk_tbl.confrelid) AS target_table,
235 (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
236 FROM
237 pg_catalog.pg_constraint fk_tbl
238 WHERE
239 fk_tbl.contype = 'f'
240 AND
241 fk_tbl.conrelid = (%(src_schema)s || '.' || %(src_tbl)s)::regclass
242 AND
243 fk_tbl.conkey[1] = (
244 SELECT
245 col_tbl1.attnum
246 FROM
247 pg_catalog.pg_attribute col_tbl1
248 WHERE
249 col_tbl1.attname = %(src_col)s
250 AND
251 col_tbl1.attrelid = (%(src_schema)s || '.' || %(src_tbl)s)::regclass
252 )
253 AND
254 fk_tbl.confrelid = (%(target_schema)s || '.' || %(target_tbl)s)::regclass
255 AND
256 fk_tbl.confkey[1] = (
257 SELECT
258 col_tbl2.attnum
259 FROM
260 pg_catalog.pg_attribute col_tbl2
261 WHERE
262 col_tbl2.attname = %(target_col)s
263 AND
264 col_tbl2.attrelid = (%(target_schema)s || '.' || %(target_tbl)s)::regclass
265 )
266 """
267
268 SQL_get_index_name = """
269 SELECT
270 (SELECT nspname FROM pg_namespace WHERE pg_namespace.oid = pg_class.relnamespace)
271 AS index_schema,
272 pg_class.relname
273 AS index_name
274 FROM
275 pg_class
276 WHERE
277 pg_class.oid IN (
278 SELECT
279 indexrelid
280 FROM
281 pg_index
282 WHERE
283 pg_index.indrelid = %(idx_tbl)s::regclass
284 AND
285 pg_index.indnatts = 1 -- only one column in index
286 AND
287 pg_index.indkey[0] IN (
288 SELECT
289 pg_attribute.attnum
290 FROM
291 pg_attribute
292 WHERE
293 pg_attribute.attrelid = %(idx_tbl)s::regclass
294 AND
295 pg_attribute.attname = %(idx_col)s
296 )
297 )
298 """
299
300 SQL_get_pk_col_def = """
301 SELECT
302 pg_attribute.attname
303 AS pk_col,
304 format_type(pg_attribute.atttypid, pg_attribute.atttypmod)
305 AS pk_type
306 FROM pg_index, pg_class, pg_attribute, pg_namespace
307 WHERE
308 pg_class.oid = %(table)s::regclass
309 AND
310 indrelid = pg_class.oid
311 AND
312 -- nspname = %%(schema)s
313 -- AND
314 pg_class.relnamespace = pg_namespace.oid
315 AND
316 pg_attribute.attrelid = pg_class.oid
317 AND
318 pg_attribute.attnum = any(pg_index.indkey)
319 AND
320 indisprimary
321 """
322
323
324
325
327
328 if encoding not in psycopg2.extensions.encodings:
329 raise ValueError('psycopg2 does not know how to handle client (wire) encoding [%s]' % encoding)
330
331 py_enc = psycopg2.extensions.encodings[encoding]
332 try:
333 codecs.lookup(py_enc)
334 except LookupError:
335 _log.warning('<codecs> module can NOT handle encoding [psycopg2::<%s> -> Python::<%s>]' % (encoding, py_enc))
336 raise
337
338
339
340
341 global _default_client_encoding
342 _log.info('setting default client encoding from [%s] to [%s]' % (_default_client_encoding, str(encoding)))
343 _default_client_encoding = encoding
344 return True
345
346
358
359
361
362 _log.debug('validating time zone [%s]', timezone)
363
364 cmd = 'set timezone to %(tz)s'
365 args = {'tz': timezone}
366
367 conn.commit()
368 curs = conn.cursor()
369 is_valid = False
370 try:
371 curs.execute(cmd, args)
372 _log.info('time zone [%s] is settable', timezone)
373
374 cmd = """select '1920-01-19 23:00:00+01'::timestamp with time zone"""
375 try:
376 curs.execute(cmd)
377 curs.fetchone()
378 _log.info('time zone [%s] is usable', timezone)
379 is_valid = True
380 except:
381 _log.error('error using time zone [%s]', timezone)
382 except dbapi.DataError:
383 _log.warning('time zone [%s] is not settable', timezone)
384 except:
385 _log.error('failed to set time zone to [%s]', timezone)
386 _log.exception('')
387
388 curs.close()
389 conn.rollback()
390
391 return is_valid
392
393
395 """some timezone defs are abbreviations so try to expand
396 them because "set time zone" doesn't take abbreviations"""
397
398 cmd = """
399 select distinct on (abbrev) name
400 from pg_timezone_names
401 where
402 abbrev = %(tz)s and
403 name ~ '^[^/]+/[^/]+$' and
404 name !~ '^Etc/'
405 """
406 args = {'tz': timezone}
407
408 conn.commit()
409 curs = conn.cursor()
410
411 result = timezone
412 try:
413 curs.execute(cmd, args)
414 rows = curs.fetchall()
415 if len(rows) > 0:
416 result = rows[0]['name']
417 _log.debug('[%s] maps to [%s]', timezone, result)
418 except:
419 _log.exception('cannot expand timezone abbreviation [%s]', timezone)
420
421 curs.close()
422 conn.rollback()
423
424 return result
425
426
472
473
474
475
477 """Text mode request of database login parameters"""
478 import getpass
479 login = gmLoginInfo.LoginInfo()
480
481 print("\nPlease enter the required login parameters:")
482 try:
483 login.host = prompted_input(prompt = "host ('' = non-TCP/IP)", default = '')
484 login.database = prompted_input(prompt = "database", default = default_database)
485 login.user = prompted_input(prompt = "user name", default = '')
486 tmp = 'password for "%s" (not shown): ' % login.user
487 login.password = getpass.getpass(tmp)
488 gmLog2.add_word2hide(login.password)
489 login.port = prompted_input(prompt = "port", default = 5432)
490 except KeyboardInterrupt:
491 _log.warning("user cancelled text mode login dialog")
492 print("user cancelled text mode login dialog")
493 raise gmExceptions.ConnectionError(_("Cannot connect to database without login information!"))
494
495 return login
496
497
499 """GUI (wx) input request for database login parameters.
500
501 Returns gmLoginInfo.LoginInfo object
502 """
503 import wx
504
505
506 if wx.GetApp() is None:
507 raise AssertionError(_("The wxPython GUI framework hasn't been initialized yet!"))
508
509
510
511 import gmAuthWidgets
512 dlg = gmAuthWidgets.cLoginDialog(None, -1)
513 dlg.ShowModal()
514 login = dlg.panel.GetLoginInfo()
515 dlg.Destroy()
516
517
518 if login is None:
519 raise gmExceptions.ConnectionError(_("Can't connect to database without login information!"))
520
521 gmLog2.add_word2hide(login.password)
522
523 return login
524
525
527 """Request login parameters for database connection."""
528
529 if not auto_request_login_params:
530 raise Exception('Cannot request login parameters.')
531
532
533
534 if 'DISPLAY' in os.environ:
535
536 try:
537 return __request_login_params_gui_wx()
538 except:
539 pass
540
541
542
543 return __request_login_params_tui()
544
545
546
547
548 -def make_psycopg2_dsn(database=None, host=None, port=5432, user=None, password=None):
549 dsn_parts = []
550
551 if (database is not None) and (database.strip() != ''):
552 dsn_parts.append('dbname=%s' % database)
553
554 if (host is not None) and (host.strip() != ''):
555 dsn_parts.append('host=%s' % host)
556
557 if (port is not None) and (str(port).strip() != ''):
558 dsn_parts.append('port=%s' % port)
559
560 if (user is not None) and (user.strip() != ''):
561 dsn_parts.append('user=%s' % user)
562
563 if (password is not None) and (password.strip() != ''):
564 dsn_parts.append('password=%s' % password)
565
566 dsn_parts.append('sslmode=prefer')
567 dsn_parts.append('fallback_application_name=GNUmed')
568
569 return ' '.join(dsn_parts)
570
571
576
577
587
588
590 if login is None:
591 return False
592
593 if login.host is not None:
594 if login.host.strip() == '':
595 login.host = None
596
597 global _default_login
598 _default_login = login
599 _log.info('setting default login from [%s] to [%s]' % (_default_login, login))
600
601 dsn = make_psycopg2_dsn(login.database, login.host, login.port, login.user, login.password)
602
603 global _default_dsn
604 if _default_dsn is None:
605 old_dsn = 'None'
606 else:
607 old_dsn = regex.sub(r'password=[^\s]+', 'password=%s' % u_replacement_character, _default_dsn)
608 _log.info ('setting default DSN from [%s] to [%s]',
609 old_dsn,
610 regex.sub(r'password=[^\s]+', 'password=%s' % u_replacement_character, dsn)
611 )
612 _default_dsn = dsn
613
614 return True
615
616
618 try:
619 pgpass_file = os.path.expanduser(os.path.join('~', '.pgpass'))
620 if os.path.exists(pgpass_file):
621 _log.debug('standard .pgpass (%s) exists', pgpass_file)
622 else:
623 _log.debug('standard .pgpass (%s) not found', pgpass_file)
624 pgpass_var = os.getenv('PGPASSFILE')
625 if pgpass_var is None:
626 _log.debug('$PGPASSFILE not set')
627 else:
628 if os.path.exists(pgpass_var):
629 _log.debug('$PGPASSFILE=%s exists', pgpass_var)
630 else:
631 _log.debug('$PGPASSFILE=%s not found')
632 except Exception:
633 _log.exception('cannot detect .pgpass and or $PGPASSFILE')
634
635
636
637
639 expected_hash = known_schema_hashes[version]
640 if version == 0:
641 args = {'ver': 9999}
642 else:
643 args = {'ver': version}
644 rows, idx = run_ro_queries (
645 link_obj = link_obj,
646 queries = [{
647 'cmd': 'select md5(gm.concat_table_structure(%(ver)s::integer)) as md5',
648 'args': args
649 }]
650 )
651 if rows[0]['md5'] != expected_hash:
652 _log.error('database schema version mismatch')
653 _log.error('expected: %s (%s)' % (version, expected_hash))
654 _log.error('detected: %s (%s)' % (get_schema_version(link_obj=link_obj), rows[0]['md5']))
655 if verbose:
656 _log.debug('schema dump follows:')
657 for line in get_schema_structure(link_obj = link_obj).split():
658 _log.debug(line)
659 _log.debug('schema revision history dump follows:')
660 for line in get_schema_revision_history(link_obj = link_obj):
661 _log.debug(' - '.join(line))
662 return False
663 _log.info('detected schema version [%s], hash [%s]' % (map_schema_hash2version[rows[0]['md5']], rows[0]['md5']))
664 return True
665
666
668 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select md5(gm.concat_table_structure()) as md5'}])
669 try:
670 return map_schema_hash2version[rows[0]['md5']]
671 except KeyError:
672 return 'unknown database schema version, MD5 hash is [%s]' % rows[0]['md5']
673
674
676 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select gm.concat_table_structure()'}])
677 return rows[0][0]
678
679
681 rows, idx = run_ro_queries(link_obj=link_obj, queries = [{'cmd': 'select md5(gm.concat_table_structure()) as md5'}])
682 return rows[0]['md5']
683
684
686
687 if table_exists(link_obj = link_obj, schema = 'gm', table = 'schema_revision'):
688 cmd = """
689 SELECT
690 imported::text,
691 version,
692 filename
693 FROM gm.schema_revision
694 ORDER BY imported"""
695 elif table_exists(link_obj = link_obj, schema = 'public', table = 'gm_schema_revision'):
696 cmd = """
697 SELECT
698 imported::text,
699 version,
700 filename
701 FROM public.gm_schema_revision
702 ORDER BY imported"""
703 else:
704 return []
705
706 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd}])
707 return rows
708
710 rows, idx = run_ro_queries(queries = [{'cmd': 'select CURRENT_USER'}])
711 return rows[0][0]
712
713
715 """Get the foreign keys pointing to schema.table.column.
716
717 Does not properly work with multi-column FKs.
718 GNUmed doesn't use any, however.
719 """
720 args = {
721 'schema': schema,
722 'tbl': table,
723 'col': column
724 }
725 cmd = """
726 SELECT
727 %(schema)s AS referenced_schema,
728 %(tbl)s AS referenced_table,
729 %(col)s AS referenced_column,
730 pgc.confkey AS referenced_column_list,
731
732 pgc.conrelid::regclass AS referencing_table,
733 pgc.conkey AS referencing_column_list,
734 (select attname from pg_attribute where attnum = pgc.conkey[1] and attrelid = pgc.conrelid) AS referencing_column
735 FROM
736 pg_constraint pgc
737 WHERE
738 pgc.contype = 'f'
739 AND
740 pgc.confrelid = (
741 select oid from pg_class where relname = %(tbl)s and relnamespace = (
742 select oid from pg_namespace where nspname = %(schema)s
743 )
744 ) and
745 (
746 select attnum
747 from pg_attribute
748 where
749 attrelid = (select oid from pg_class where relname = %(tbl)s and relnamespace = (
750 select oid from pg_namespace where nspname = %(schema)s
751 ))
752 and
753 attname = %(col)s
754 ) = any(pgc.confkey)
755 """
756 rows, idx = run_ro_queries (
757 link_obj = link_obj,
758 queries = [
759 {'cmd': cmd, 'args': args}
760 ]
761 )
762
763 return rows
764
765
766 -def get_index_name(indexed_table=None, indexed_column=None, link_obj=None):
767
768 args = {
769 'idx_tbl': indexed_table,
770 'idx_col': indexed_column
771 }
772 rows, idx = run_ro_queries (
773 link_obj = link_obj,
774 queries = [{'cmd': SQL_get_index_name, 'args': args}],
775 get_col_idx = False
776 )
777
778 return rows
779
780
781 -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):
782
783 args = {
784 'src_schema': src_schema,
785 'src_tbl': src_table,
786 'src_col': src_column,
787 'target_schema': target_schema,
788 'target_tbl': target_table,
789 'target_col': target_column
790 }
791
792 rows, idx = run_ro_queries (
793 link_obj = link_obj,
794 queries = [{'cmd': SQL_foreign_key_name, 'args': args}],
795 get_col_idx = False
796 )
797
798 return rows
799
800
802 """Return child tables of <table>."""
803 cmd = """
804 select
805 pgn.nspname as namespace,
806 pgc.relname as table
807 from
808 pg_namespace pgn,
809 pg_class pgc
810 where
811 pgc.relnamespace = pgn.oid
812 and
813 pgc.oid in (
814 select inhrelid from pg_inherits where inhparent = (
815 select oid from pg_class where
816 relnamespace = (select oid from pg_namespace where nspname = %(schema)s) and
817 relname = %(table)s
818 )
819 )"""
820 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': {'schema': schema, 'table': table}}])
821 return rows
822
823
825 cmd = """SELECT EXISTS (SELECT 1 FROM pg_namespace WHERE nspname = %(schema)s)"""
826 args = {'schema': schema}
827 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}])
828 return rows[0][0]
829
830
832 """Returns false, true."""
833 cmd = """
834 select exists (
835 select 1 from information_schema.tables
836 where
837 table_schema = %s and
838 table_name = %s and
839 table_type = 'BASE TABLE'
840 )"""
841 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': (schema, table)}])
842 return rows[0][0]
843
844
846
847 cmd = """
848 SELECT EXISTS (
849 SELECT 1 FROM pg_proc
850 WHERE proname = %(func)s AND pronamespace = (SELECT oid FROM pg_namespace WHERE nspname = %(schema)s)
851 )
852 """
853 args = {
854 'func': function,
855 'schema': schema
856 }
857 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}])
858 return rows[0][0]
859
860
862 if cursor.description is None:
863 _log.error('no result description available: unused cursor or last query did not select rows')
864 return None
865 col_indices = {}
866 col_index = 0
867 for col_desc in cursor.description:
868 col_name = col_desc[0]
869
870
871
872 if col_name in col_indices:
873 col_name = '%s_%s' % (col_name, col_index)
874 col_indices[col_name] = col_index
875 col_index += 1
876
877 return col_indices
878
879 -def get_col_defs(link_obj=None, schema='public', table=None):
880 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_col_defs, 'args': (schema, table)}])
881 col_names = []
882 col_type = {}
883 for row in rows:
884 col_names.append(row[0])
885
886 if row[1].startswith('_'):
887 col_type[row[0]] = row[1][1:] + '[]'
888 else:
889 col_type[row[0]] = row[1]
890 col_defs = []
891 col_defs.append(col_names)
892 col_defs.append(col_type)
893 return col_defs
894
896 """Return column attributes of table"""
897 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': query_table_attributes, 'args': (schema, table)}])
898 cols = []
899 for row in rows:
900 cols.append(row[0])
901 return cols
902
903
904
905
907 tx_file = io.open(filename, mode = 'wt', encoding = 'utf8')
908 tx_file.write('-- GNUmed database string translations exported %s\n' % gmDateTime.pydt_now_here().strftime('%Y-%m-%d %H:%M'))
909 tx_file.write('-- - contains translations for each of [%s]\n' % ', '.join(get_translation_languages()))
910 tx_file.write('-- - user database language is set to [%s]\n\n' % get_current_user_language())
911 tx_file.write('-- Please email this file to <gnumed-devel@gnu.org>.\n')
912 tx_file.write('-- ----------------------------------------------------------------------------------------------\n\n')
913 tx_file.write('set default_transaction_read_only to off;\n\n')
914 tx_file.write("set client_encoding to 'utf-8';\n\n")
915 tx_file.write('\\unset ON_ERROR_STOP\n\n')
916
917 cmd = 'SELECT lang, orig, trans FROM i18n.translations ORDER BY lang, orig'
918 rows, idx = run_ro_queries(queries = [{'cmd': cmd}], get_col_idx = False)
919 for row in rows:
920 line = "select i18n.upd_tx(E'%s', E'%s', E'%s');\n" % (
921 row['lang'].replace("'", "\\'"),
922 row['orig'].replace("'", "\\'"),
923 row['trans'].replace("'", "\\'")
924 )
925 tx_file.write(line)
926 tx_file.write('\n')
927
928 tx_file.write('\set ON_ERROR_STOP 1\n')
929 tx_file.close()
930
931 return True
932
933
935 cmd = 'DELETE FROM i18n.translations WHERE lang = %(lang)s AND orig = %(orig)s'
936 args = {'lang': language, 'orig': original}
937 run_rw_queries(link_obj = link_obj, queries = [{'cmd': cmd, 'args': args}], return_data = False, end_tx = True)
938 return True
939
940
942 if language is None:
943 cmd = 'SELECT i18n.upd_tx(%(orig)s, %(trans)s)'
944 else:
945 cmd = 'SELECT i18n.upd_tx(%(lang)s, %(orig)s, %(trans)s)'
946 args = {'lang': language, 'orig': original, 'trans': translation}
947 run_rw_queries(queries = [{'cmd': cmd, 'args': args}], return_data = False, link_obj = link_obj)
948 return args
949
950
952 rows, idx = run_ro_queries (
953 queries = [{'cmd': 'select distinct lang from i18n.translations'}]
954 )
955 return [ r[0] for r in rows ]
956
957
959
960 args = {'lang': language}
961 _log.debug('language [%s]', language)
962
963 if order_by is None:
964 order_by = 'ORDER BY %s' % order_by
965 else:
966 order_by = 'ORDER BY lang, orig'
967
968 if language is None:
969 cmd = """
970 SELECT DISTINCT ON (orig, lang)
971 lang, orig, trans
972 FROM ((
973
974 -- strings stored as translation keys whether translated or not
975 SELECT
976 NULL as lang,
977 ik.orig,
978 NULL AS trans
979 FROM
980 i18n.keys ik
981
982 ) UNION ALL (
983
984 -- already translated strings
985 SELECT
986 it.lang,
987 it.orig,
988 it.trans
989 FROM
990 i18n.translations it
991
992 )) as translatable_strings
993 %s""" % order_by
994 else:
995 cmd = """
996 SELECT DISTINCT ON (orig, lang)
997 lang, orig, trans
998 FROM ((
999
1000 -- strings stored as translation keys whether translated or not
1001 SELECT
1002 %%(lang)s as lang,
1003 ik.orig,
1004 i18n._(ik.orig, %%(lang)s) AS trans
1005 FROM
1006 i18n.keys ik
1007
1008 ) UNION ALL (
1009
1010 -- already translated strings
1011 SELECT
1012 %%(lang)s as lang,
1013 it.orig,
1014 i18n._(it.orig, %%(lang)s) AS trans
1015 FROM
1016 i18n.translations it
1017
1018 )) AS translatable_strings
1019 %s""" % order_by
1020
1021 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False)
1022
1023 if rows is None:
1024 _log.error('no translatable strings found')
1025 else:
1026 _log.debug('%s translatable strings found', len(rows))
1027
1028 return rows
1029
1030
1032 cmd = 'select i18n.get_curr_lang()'
1033 rows, idx = run_ro_queries(queries = [{'cmd': cmd}])
1034 return rows[0][0]
1035
1036
1038 """Set the user language in the database.
1039
1040 user = None: current db user
1041 language = None: unset
1042 """
1043 _log.info('setting database language for user [%s] to [%s]', user, language)
1044
1045 args = {
1046 'usr': user,
1047 'lang': language
1048 }
1049
1050 if language is None:
1051 if user is None:
1052 queries = [{'cmd': 'select i18n.unset_curr_lang()'}]
1053 else:
1054 queries = [{'cmd': 'select i18n.unset_curr_lang(%(usr)s)', 'args': args}]
1055 queries.append({'cmd': 'select True'})
1056 else:
1057 if user is None:
1058 queries = [{'cmd': 'select i18n.set_curr_lang(%(lang)s)', 'args': args}]
1059 else:
1060 queries = [{'cmd': 'select i18n.set_curr_lang(%(lang)s, %(usr)s)', 'args': args}]
1061
1062 rows, idx = run_rw_queries(queries = queries, return_data = True)
1063
1064 if not rows[0][0]:
1065 _log.error('cannot set database language to [%s] for user [%s]', language, user)
1066
1067 return rows[0][0]
1068
1070 """Set the user language in the database.
1071
1072 - regardless of whether there is any translation available.
1073 - only for the current user
1074 """
1075 _log.info('forcing database language for current db user to [%s]', language)
1076
1077 run_rw_queries(queries = [{
1078 'cmd': 'select i18n.force_curr_lang(%(lang)s)',
1079 'args': {'lang': language}
1080 }])
1081
1082
1083
1084
1086 cmd = 'notify "db_maintenance_warning"'
1087 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
1088
1089
1091 cmd = 'notify "db_maintenance_disconnect"'
1092 run_rw_queries(queries = [{'cmd': cmd}], return_data = False)
1093
1094
1096 cmd = 'SELECT %(candidate)s::interval'
1097 try:
1098 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}])
1099 return True
1100 except:
1101 cmd = 'SELECT %(candidate)s::text::interval'
1102 try:
1103 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': {'candidate': candidate}}])
1104 return True
1105 except:
1106 return False
1107
1108
1109 -def lock_row(link_obj=None, table=None, pk=None, exclusive=False):
1110 """Uses pg_advisory(_shared).
1111
1112 - locks stack upon each other and need one unlock per lock
1113 - same connection:
1114 - all locks succeed
1115 - different connections:
1116 - shared + shared succeed
1117 - shared + exclusive fail
1118 """
1119 _log.debug('locking row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
1120 if exclusive:
1121 cmd = """SELECT pg_try_advisory_lock('%s'::regclass::oid::int, %s)""" % (table, pk)
1122 else:
1123 cmd = """SELECT pg_try_advisory_lock_shared('%s'::regclass::oid::int, %s)""" % (table, pk)
1124 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd}], get_col_idx = False)
1125 if rows[0][0]:
1126 return True
1127 _log.warning('cannot lock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
1128 return False
1129
1130
1131 -def unlock_row(link_obj=None, table=None, pk=None, exclusive=False):
1132 """Uses pg_advisory_unlock(_shared).
1133
1134 - each lock needs one unlock
1135 """
1136 _log.debug('trying to unlock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
1137 if exclusive:
1138 cmd = "SELECT pg_advisory_unlock('%s'::regclass::oid::int, %s)" % (table, pk)
1139 else:
1140 cmd = "SELECT pg_advisory_unlock_shared('%s'::regclass::oid::int, %s)" % (table, pk)
1141 rows, idx = run_ro_queries(link_obj = link_obj, queries = [{'cmd': cmd}], get_col_idx = False)
1142 if rows[0][0]:
1143 return True
1144 _log.warning('cannot unlock row: [%s] [%s] (exclusive: %s)', table, pk, exclusive)
1145 return False
1146
1147
1149 """Looks at pk_locks
1150
1151 - does not take into account locks other than 'advisory', however
1152 """
1153 cmd = """SELECT EXISTS (
1154 SELECT 1 FROM pg_locks WHERE
1155 classid = '%s'::regclass::oid::int
1156 AND
1157 objid = %s
1158 AND
1159 locktype = 'advisory'
1160 )""" % (table, pk)
1161 rows, idx = run_ro_queries(queries = [{'cmd': cmd}], get_col_idx = False)
1162 if rows[0][0]:
1163 _log.debug('row is locked: [%s] [%s]', table, pk)
1164 return True
1165 _log.debug('row is NOT locked: [%s] [%s]', table, pk)
1166 return False
1167
1168
1169 -def bytea2file(data_query=None, filename=None, chunk_size=0, data_size=None, data_size_query=None, conn=None):
1170 outfile = io.open(filename, 'wb')
1171 result = bytea2file_object (
1172 data_query = data_query,
1173 file_obj = outfile,
1174 chunk_size = chunk_size,
1175 data_size = data_size,
1176 data_size_query = data_size_query,
1177 conn = conn
1178 )
1179 outfile.close()
1180 return result
1181
1182
1183 -def bytea2file_object(data_query=None, file_obj=None, chunk_size=0, data_size=None, data_size_query=None, conn=None):
1184 """Store data from a bytea field into a file.
1185
1186 <data_query>
1187 - dict {'cmd': ..., 'args': ...}
1188 - 'cmd' must be a string containing "... substring(data from %(start)s for %(size)s) ..."
1189 - 'args' must be a dict
1190 - must return one row with one field of type bytea
1191 <file>
1192 - must be a file like Python object
1193 <data_size>
1194 - integer of the total size of the expected data or None
1195 <data_size_query>
1196 - dict {'cmd': ..., 'args': ...}
1197 - cmd must be unicode
1198 - must return one row with one field with the octet_length() of the data field
1199 - used only when <data_size> is None
1200 """
1201 if data_size == 0:
1202 return True
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215 if conn is None:
1216 conn = get_raw_connection(readonly = True)
1217
1218 if data_size is None:
1219 rows, idx = run_ro_queries(link_obj = conn, queries = [data_size_query])
1220 data_size = rows[0][0]
1221 if data_size in [None, 0]:
1222 conn.rollback()
1223 return True
1224
1225 max_chunk_size = 1024 * 1024 * 20
1226 if chunk_size == 0:
1227 chunk_size = min(data_size, max_chunk_size)
1228
1229 _log.debug('expecting %s bytes of BYTEA data in chunks of %s bytes', data_size, chunk_size)
1230
1231
1232
1233
1234 needed_chunks, remainder = divmod(data_size, chunk_size)
1235 _log.debug('# of chunks: %s; remainder: %s bytes', needed_chunks, remainder)
1236
1237
1238
1239
1240
1241
1242
1243 for chunk_id in range(needed_chunks):
1244 chunk_start = (chunk_id * chunk_size) + 1
1245 data_query['args']['start'] = chunk_start
1246 data_query['args']['size'] = chunk_size
1247 try:
1248 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query])
1249 except:
1250 _log.error('cannot retrieve chunk [%s/%s], size [%s], try decreasing chunk size' % (chunk_id+1, needed_chunks, chunk_size))
1251 conn.rollback()
1252 raise
1253
1254 file_obj.write(rows[0][0])
1255
1256
1257 if remainder > 0:
1258 chunk_start = (needed_chunks * chunk_size) + 1
1259 data_query['args']['start'] = chunk_start
1260 data_query['args']['size'] = remainder
1261 try:
1262 rows, idx = run_ro_queries(link_obj=conn, queries=[data_query])
1263 except:
1264 _log.error('cannot retrieve remaining [%s] bytes' % remainder)
1265 conn.rollback()
1266 raise
1267
1268 file_obj.write(rows[0][0])
1269
1270 conn.rollback()
1271 return True
1272
1273
1274 -def file2bytea(query=None, filename=None, args=None, conn=None, file_md5=None):
1275 """Store data from a file into a bytea field.
1276
1277 The query must:
1278 - be in unicode
1279 - contain a format spec identifying the row (eg a primary key)
1280 matching <args> if it is an UPDATE
1281 - contain a format spec " <field> = %(data)s::bytea"
1282
1283 The query CAN return the MD5 of the inserted data:
1284 RETURNING md5(<field>) AS md5
1285 in which case it will compare it to the md5
1286 of the file.
1287 """
1288
1289 infile = open(filename, "rb")
1290 data_as_byte_string = infile.read()
1291 infile.close()
1292 if args is None:
1293 args = {}
1294
1295 args['data'] = memoryview(data_as_byte_string)
1296 del(data_as_byte_string)
1297
1298
1299 if conn is None:
1300 conn = get_raw_connection(readonly = False)
1301 close_conn = True
1302 else:
1303 close_conn = False
1304
1305 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = (file_md5 is not None))
1306
1307 success_status = True
1308 if file_md5 is None:
1309 conn.commit()
1310 else:
1311 db_md5 = rows[0]['md5']
1312 if file_md5 != db_md5:
1313 conn.rollback()
1314 success_status = False
1315 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5)
1316 else:
1317 conn.commit()
1318 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5)
1319
1320 if close_conn:
1321 conn.close()
1322
1323 return success_status
1324
1325
1326 -def file2lo(filename=None, conn=None, check_md5=False):
1327
1328 file_size = os.path.getsize(filename)
1329 if file_size > (1024 * 1024) * 1024:
1330 _log.debug('file size of [%s] > 1 GB, supposedly not supported by psycopg2 large objects (but seems to work anyway ?)', file_size)
1331
1332
1333 if conn is None:
1334 conn = get_raw_connection(readonly = False)
1335 close_conn = conn.close
1336 else:
1337 close_conn = __noop
1338 _log.debug('[%s] -> large object', filename)
1339
1340
1341 lo = conn.lobject(0, 'w', 0, filename)
1342 lo_oid = lo.oid
1343 lo.close()
1344 _log.debug('large object OID: %s', lo_oid)
1345
1346
1347 if file_md5 is None:
1348 conn.commit()
1349 close_conn()
1350 return lo_oid
1351 cmd = 'SELECT md5(lo_get(%(loid)s::oid))'
1352 args = {'loid': lo_oid}
1353 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': cmd, 'args': args}])
1354 db_md5 = rows[0][0]
1355 if file_md5 == db_md5:
1356 conn.commit()
1357 close_conn()
1358 _log.debug('MD5 sums of data file and database large object match: [file::%s] = [DB::%s]', file_md5, db_md5)
1359 return lo_oid
1360 conn.rollback()
1361 close_conn()
1362 _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)
1363 return -1
1364
1365
1367
1368 file_size = os.path.getsize(filename)
1369 if file_size > (1024 * 1024) * 1024:
1370 _log.debug('file size of [%s] > 1 GB, supposedly not supported by psycopg2 large objects (but seems to work anyway ?)', file_size)
1371
1372
1373 if conn is None:
1374 conn = get_raw_connection(readonly = False)
1375 close_conn = conn.close
1376 else:
1377 close_conn = __noop
1378 _log.debug('[%s] -> large object', filename)
1379
1380
1381 lo = conn.lobject(0, 'w', 0, filename)
1382 lo_oid = lo.oid
1383 lo.close()
1384 _log.debug('large object OID: %s', lo_oid)
1385
1386
1387 if file_md5 is None:
1388 conn.commit()
1389 close_conn()
1390 return lo_oid
1391 cmd = 'SELECT md5(lo_get(%(loid)s::oid))'
1392 args = {'loid': lo_oid}
1393 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': cmd, 'args': args}])
1394 db_md5 = rows[0][0]
1395 if file_md5 == db_md5:
1396 conn.commit()
1397 close_conn()
1398 _log.debug('MD5 sums of data file and database large object match: [file::%s] = [DB::%s]', file_md5, db_md5)
1399 return lo_oid
1400 conn.rollback()
1401 close_conn()
1402 _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)
1403 return -1
1404
1405
1406 -def file2bytea_copy_from(table=None, columns=None, filename=None, conn=None, md5_query=None, file_md5=None):
1407
1408
1409
1410
1411 chunk_size = 32 * (1024 * 1024)
1412 _log.debug('[%s] (%s bytes) --(%s bytes)-> %s(%s)', filename, os.path.getsize(filename), chunk_size, table, columns)
1413 if conn is None:
1414 conn = get_raw_connection(readonly = False)
1415 close_conn = True
1416 else:
1417 close_conn = False
1418 curs = conn.cursor()
1419
1420 infile = open(filename, "rb")
1421 curs.copy_from(infile, table, size = chunk_size, columns = columns)
1422 infile.close()
1423 curs.close()
1424 if None in [file_md5, md5_query]:
1425 conn.commit()
1426 close_conn()
1427 return True
1428
1429 rows, idx = run_ro_queries(link_obj = conn, queries = [md5_query])
1430 db_md5 = rows[0][0]
1431 if file_md5 == db_md5:
1432 conn.commit()
1433 close_conn()
1434 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5)
1435 return True
1436 close_conn()
1437 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5)
1438 return False
1439
1440
1441 -def file2bytea_overlay(query=None, args=None, filename=None, conn=None, md5_query=None, file_md5=None):
1442 """Store data from a file into a bytea field.
1443
1444 The query must:
1445 - 'cmd' must be in unicode
1446 - 'cmd' must contain a format spec identifying the row (eg
1447 a primary key) matching <args> if it is an UPDATE
1448 - 'cmd' must contain "... SET ... <some_bytea_field> = OVERLAY(some_bytea_field PLACING %(data)s::bytea FROM %(start)s FOR %(size)s) ..."
1449 - 'args' must be a dict matching 'cmd'
1450
1451 The query CAN return the MD5 of the inserted data:
1452 RETURNING md5(<field>) AS md5
1453 in which case it will compare it to the md5
1454 of the file.
1455
1456 UPDATE
1457 the_table
1458 SET
1459 bytea_field = OVERLAY (
1460 coalesce(bytea_field, '':bytea),
1461 PLACING
1462 %(data)s::bytea
1463 FROM
1464 %(start)s
1465 FOR
1466 %(size)s
1467 )
1468 WHERE
1469 primary_key = pk_value
1470
1471 SELECT md5(bytea_field) FROM the_table WHERE primary_key = pk_value
1472 """
1473 chunk_size = 32 * (1024 * 1024)
1474 file_size = os.path.getsize(filename)
1475 if file_size <= chunk_size:
1476 chunk_size = file_size
1477 needed_chunks, remainder = divmod(file_size, chunk_size)
1478 _log.debug('file data: %s bytes, chunks: %s, chunk size: %s bytes, remainder: %s bytes', file_size, needed_chunks, chunk_size, remainder)
1479
1480 if conn is None:
1481 conn = get_raw_connection(readonly = False)
1482 close_conn = conn.close
1483 else:
1484 close_conn = __noop
1485
1486 infile = open(filename, "rb")
1487
1488 for chunk_id in range(needed_chunks):
1489 chunk_start = (chunk_id * chunk_size) + 1
1490 args['start'] = chunk_start
1491 args['size'] = chunk_size
1492 data_as_byte_string = infile.read(chunk_size)
1493
1494 args['data'] = memoryview(data_as_byte_string)
1495 del(data_as_byte_string)
1496 try:
1497 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = False)
1498 except Exception:
1499 _log.exception('cannot write chunk [%s/%s] of size [%s], try decreasing chunk size', chunk_id+1, needed_chunks, chunk_size)
1500 conn.rollback()
1501 close_conn()
1502 infile.close()
1503 raise
1504
1505 if remainder > 0:
1506 chunk_start = (needed_chunks * chunk_size) + 1
1507 args['start'] = chunk_start
1508 args['size'] = remainder
1509 data_as_byte_string = infile.read(remainder)
1510
1511 args['data'] = memoryview(data_as_byte_string)
1512 del(data_as_byte_string)
1513 try:
1514 rows, idx = run_rw_queries(link_obj = conn, queries = [{'cmd': query, 'args': args}], end_tx = False, return_data = False)
1515 except Exception:
1516 _log.error('cannot retrieve remaining [%s] bytes' % remainder)
1517 conn.rollback()
1518 close_conn()
1519 infile.close()
1520 raise
1521 infile.close()
1522 if None in [file_md5, md5_query]:
1523 conn.commit()
1524 close_conn()
1525 return True
1526
1527 rows, idx = run_ro_queries(link_obj = conn, queries = [{'cmd': md5_query, 'args': args}])
1528 db_md5 = rows[0][0]
1529 if file_md5 == db_md5:
1530 conn.commit()
1531 close_conn()
1532 _log.debug('MD5 sums of data file and database BYTEA field match: [file::%s] = [DB::%s]', file_md5, db_md5)
1533 return True
1534 close_conn()
1535 _log.error('MD5 sums of data file and database BYTEA field do not match: [file::%s] <> [DB::%s]', file_md5, db_md5)
1536 return False
1537
1538
1540
1541 if conn is None:
1542 conn = get_connection(readonly = False)
1543
1544 from Gnumed.pycommon import gmPsql
1545 psql = gmPsql.Psql(conn)
1546
1547 if psql.run(sql_script) == 0:
1548 query = {
1549 'cmd': 'select gm.log_script_insertion(%(name)s, %(ver)s)',
1550 'args': {'name': sql_script, 'ver': 'current'}
1551 }
1552 run_rw_queries(link_obj = conn, queries = [query])
1553 conn.commit()
1554 return True
1555
1556 _log.error('error running sql script: %s', sql_script)
1557 return False
1558
1559
1561 """Escape input for use in a PostgreSQL regular expression.
1562
1563 If a fragment comes from user input and is to be used
1564 as a regular expression we need to make sure it doesn't
1565 contain invalid regex patterns such as unbalanced ('s.
1566
1567 <escape_all>
1568 True: try to escape *all* metacharacters
1569 False: only escape those which render the regex invalid
1570 """
1571 return expression.replace (
1572 '(', '\('
1573 ).replace (
1574 ')', '\)'
1575 ).replace (
1576 '[', '\['
1577 ).replace (
1578 '+', '\+'
1579 ).replace (
1580 '.', '\.'
1581 ).replace (
1582 '*', '\*'
1583 )
1584
1585
1586
1588
1589 tx_status = conn.get_transaction_status()
1590 if tx_status in [ psycopg2.extensions.TRANSACTION_STATUS_INERROR, psycopg2.extensions.TRANSACTION_STATUS_UNKNOWN ]:
1591 isolation_level = '%s (tx aborted or unknown, cannot retrieve)' % conn.isolation_level
1592 else:
1593 isolation_level = '%s (%s)' % (conn.isolation_level, map_psyco_iso_level2str[conn.isolation_level])
1594 conn_status = '%s (%s)' % (conn.status, map_psyco_conn_status2str[conn.status])
1595 if conn.closed != 0:
1596 conn_status = 'undefined (%s)' % conn_status
1597 try:
1598 conn_deferrable = conn.deferrable
1599 except AttributeError:
1600 conn_deferrable = 'unavailable'
1601
1602 d = {
1603 'identity': id(conn),
1604 'backend PID': conn.get_backend_pid(),
1605 'protocol version': conn.protocol_version,
1606 'encoding': conn.encoding,
1607 'closed': conn.closed,
1608 'readonly': conn.readonly,
1609 'autocommit': conn.autocommit,
1610 'isolation level (psyco)': isolation_level,
1611 'async': conn.async,
1612 'deferrable': conn_deferrable,
1613 'transaction status': '%s (%s)' % (tx_status, map_psyco_tx_status2str[tx_status]),
1614 'connection status': conn_status,
1615 'executing async op': conn.isexecuting(),
1616 'type': type(conn)
1617 }
1618 return '%s\n' % conn + format_dict_like (
1619 d,
1620 relevant_keys = [
1621 'type',
1622 'identity',
1623 'backend PID',
1624 'protocol version',
1625 'encoding',
1626 'isolation level (psyco)',
1627 'readonly',
1628 'autocommit',
1629 'closed',
1630 'connection status',
1631 'transaction status',
1632 'deferrable',
1633 'async',
1634 'executing async op'
1635 ],
1636 tabular = True,
1637 value_delimiters = None
1638 )
1639
1640
1642 conn = cursor.connection
1643
1644 tx_status = conn.get_transaction_status()
1645 if tx_status in [ psycopg2.extensions.TRANSACTION_STATUS_INERROR, psycopg2.extensions.TRANSACTION_STATUS_UNKNOWN ]:
1646 isolation_level = 'tx aborted or unknown, cannot retrieve'
1647 else:
1648 isolation_level = conn.isolation_level
1649 try:
1650 conn_deferrable = conn.deferrable
1651 except AttributeError:
1652 conn_deferrable = 'unavailable'
1653
1654 if cursor.query is None:
1655 query = '<no query>'
1656 else:
1657 query = str(cursor.query, 'utf8', 'replace')
1658
1659 txt = """Link state:
1660 Cursor
1661 identity: %s; name: %s
1662 closed: %s; scrollable: %s; with hold: %s; arraysize: %s; itersize: %s;
1663 last rowcount: %s; rownumber: %s; lastrowid (OID): %s;
1664 last description: %s
1665 statusmessage: %s
1666 Connection
1667 identity: %s; backend pid: %s; protocol version: %s;
1668 closed: %s; autocommit: %s; isolation level: %s; encoding: %s; async: %s; deferrable: %s; readonly: %s;
1669 TX status: %s; CX status: %s; executing async op: %s;
1670 Query
1671 %s
1672 """ % (
1673 id(cursor),
1674 cursor.name,
1675 cursor.closed,
1676 cursor.scrollable,
1677 cursor.withhold,
1678 cursor.arraysize,
1679 cursor.itersize,
1680 cursor.rowcount,
1681 cursor.rownumber,
1682 cursor.lastrowid,
1683 cursor.description,
1684 cursor.statusmessage,
1685
1686 id(conn),
1687 conn.get_backend_pid(),
1688 conn.protocol_version,
1689 conn.closed,
1690 conn.autocommit,
1691 isolation_level,
1692 conn.encoding,
1693 conn.async,
1694 conn_deferrable,
1695 conn.readonly,
1696 map_psyco_tx_status2str[tx_status],
1697 map_psyco_conn_status2str[conn.status],
1698 conn.isexecuting(),
1699
1700 query
1701 )
1702 return txt
1703
1704
1705 -def run_ro_queries(link_obj=None, queries=None, verbose=False, return_data=True, get_col_idx=False):
1706 """Run read-only queries.
1707
1708 <queries> must be a list of dicts:
1709 [
1710 {'cmd': <string>, 'args': <dict> or <tuple>},
1711 {...},
1712 ...
1713 ]
1714 """
1715 if isinstance(link_obj, dbapi._psycopg.cursor):
1716 curs = link_obj
1717 curs_close = lambda :1
1718 tx_rollback = lambda :1
1719 readonly_rollback_just_in_case = lambda :1
1720 elif isinstance(link_obj, dbapi._psycopg.connection):
1721 curs = link_obj.cursor()
1722 curs_close = curs.close
1723 tx_rollback = link_obj.rollback
1724 if link_obj.autocommit is True:
1725 readonly_rollback_just_in_case = link_obj.rollback
1726 else:
1727
1728
1729
1730 readonly_rollback_just_in_case = lambda :1
1731 elif link_obj is None:
1732 conn = get_connection(readonly=True, verbose=verbose)
1733 curs = conn.cursor()
1734 curs_close = curs.close
1735 tx_rollback = conn.rollback
1736 readonly_rollback_just_in_case = conn.rollback
1737 else:
1738 raise ValueError('link_obj must be cursor, connection or None but not [%s]' % link_obj)
1739
1740 if verbose:
1741 _log.debug('cursor: %s', curs)
1742
1743 for query in queries:
1744 try:
1745 args = query['args']
1746 except KeyError:
1747 args = None
1748 try:
1749 curs.execute(query['cmd'], args)
1750 if verbose:
1751 _log.debug(capture_cursor_state(curs))
1752 except dbapi.Error as pg_exc:
1753 _log.error('query failed in RO connection')
1754 _log.error(capture_cursor_state(curs))
1755 if hasattr(pg_exc, 'diag'):
1756 for prop in dir(pg_exc.diag):
1757 if prop.startswith('__'):
1758 continue
1759 val = getattr(pg_exc.diag, prop)
1760 if val is None:
1761 continue
1762 _log.error('PG diags %s: %s', prop, val)
1763 pg_exc = make_pg_exception_fields_unicode(pg_exc)
1764 _log.error('PG error code: %s', pg_exc.pgcode)
1765 if pg_exc.pgerror is not None:
1766 _log.error('PG error message: %s', pg_exc.u_pgerror)
1767 try:
1768 curs_close()
1769 except dbapi.InterfaceError:
1770 _log.exception('cannot close cursor')
1771 tx_rollback()
1772 if pg_exc.pgcode == sql_error_codes.INSUFFICIENT_PRIVILEGE:
1773 details = 'Query: [%s]' % curs.query.strip().strip('\n').strip().strip('\n')
1774 if curs.statusmessage != '':
1775 details = 'Status: %s\n%s' % (
1776 curs.statusmessage.strip().strip('\n').strip().strip('\n'),
1777 details
1778 )
1779 if pg_exc.pgerror is None:
1780 msg = '[%s]' % pg_exc.pgcode
1781 else:
1782 msg = '[%s]: %s' % (pg_exc.pgcode, pg_exc.u_pgerror)
1783 raise gmExceptions.AccessDenied (
1784 msg,
1785 source = 'PostgreSQL',
1786 code = pg_exc.pgcode,
1787 details = details
1788 )
1789 raise
1790 except:
1791 _log.exception('query failed in RO connection')
1792 _log.error(capture_cursor_state(curs))
1793 try:
1794 curs_close()
1795 except dbapi.InterfaceError:
1796 _log.exception('cannot close cursor')
1797 tx_rollback()
1798 raise
1799
1800 data = None
1801 col_idx = None
1802 if return_data:
1803 data = curs.fetchall()
1804 if verbose:
1805 _log.debug('last query returned [%s (%s)] rows', curs.rowcount, len(data))
1806 _log.debug('cursor description: %s', str(curs.description))
1807 if get_col_idx:
1808 col_idx = get_col_indices(curs)
1809
1810 curs_close()
1811
1812
1813
1814 readonly_rollback_just_in_case()
1815 return (data, col_idx)
1816
1817
1818 -def run_rw_queries(link_obj=None, queries=None, end_tx=False, return_data=None, get_col_idx=False, verbose=False):
1819 """Convenience function for running a transaction
1820 that is supposed to get committed.
1821
1822 <link_obj>
1823 can be either:
1824 - a cursor
1825 - a connection
1826
1827 <queries>
1828 is a list of dicts [{'cmd': <string>, 'args': <dict> or <tuple>)
1829 to be executed as a single transaction, the last
1830 query may usefully return rows (such as a
1831 "SELECT currval('some_sequence')" statement)
1832
1833 <end_tx>
1834 - controls whether the transaction is finalized (eg.
1835 committed/rolled back) or not, this allows the
1836 call to run_rw_queries() to be part of a framing
1837 transaction
1838 - if link_obj is a connection then <end_tx> will
1839 default to False unless it is explicitly set to
1840 True which is taken to mean "yes, you do have full
1841 control over the transaction" in which case the
1842 transaction is properly finalized
1843 - if link_obj is a cursor we CANNOT finalize the
1844 transaction because we would need the connection for that
1845 - if link_obj is None <end_tx> will, of course, always be True
1846
1847 <return_data>
1848 - if true, the returned data will include the rows
1849 the last query selected
1850 - if false, it returns None instead
1851
1852 <get_col_idx>
1853 - if true, the returned data will include a dictionary
1854 mapping field names to column positions
1855 - if false, the returned data returns None instead
1856
1857 method result:
1858 - returns a tuple (data, idx)
1859 - <data>:
1860 * (None, None) if last query did not return rows
1861 * ("fetchall() result", <index>) if last query returned any rows
1862 * for <index> see <get_col_idx>
1863 """
1864 if isinstance(link_obj, dbapi._psycopg.cursor):
1865 conn_close = lambda :1
1866 conn_commit = lambda :1
1867 tx_rollback = lambda :1
1868 curs = link_obj
1869 curs_close = lambda :1
1870 notices_accessor = curs.connection
1871 elif isinstance(link_obj, dbapi._psycopg.connection):
1872 conn_close = lambda :1
1873 if end_tx:
1874 conn_commit = link_obj.commit
1875 tx_rollback = link_obj.rollback
1876 else:
1877 conn_commit = lambda :1
1878 tx_rollback = lambda :1
1879 curs = link_obj.cursor()
1880 curs_close = curs.close
1881 notices_accessor = link_obj
1882 elif link_obj is None:
1883 conn = get_connection(readonly=False)
1884 conn_close = conn.close
1885 conn_commit = conn.commit
1886 tx_rollback = conn.rollback
1887 curs = conn.cursor()
1888 curs_close = curs.close
1889 notices_accessor = conn
1890 else:
1891 raise ValueError('link_obj must be cursor, connection or None but not [%s]' % link_obj)
1892
1893 for query in queries:
1894 try:
1895 args = query['args']
1896 except KeyError:
1897 args = None
1898 try:
1899 curs.execute(query['cmd'], args)
1900 if verbose:
1901 _log.debug(capture_cursor_state(curs))
1902 for notice in notices_accessor.notices:
1903 _log.debug(str(notice, 'utf8', 'replace').strip('\n').strip('\r'))
1904 del notices_accessor.notices[:]
1905
1906 except dbapi.Error as pg_exc:
1907 _log.error('query failed in RW connection')
1908 _log.error(capture_cursor_state(curs))
1909 if hasattr(pg_exc, 'diag'):
1910 for prop in dir(pg_exc.diag):
1911 if prop.startswith('__'):
1912 continue
1913 val = getattr(pg_exc.diag, prop)
1914 if val is None:
1915 continue
1916 _log.error('PG diags %s: %s', prop, val)
1917 for notice in notices_accessor.notices:
1918 _log.error(str(notice, 'utf8', 'replace').strip('\n').strip('\r'))
1919 del notices_accessor.notices[:]
1920 pg_exc = make_pg_exception_fields_unicode(pg_exc)
1921 _log.error('PG error code: %s', pg_exc.pgcode)
1922 if pg_exc.pgerror is not None:
1923 _log.error('PG error message: %s', pg_exc.u_pgerror)
1924
1925 if pg_exc.pgcode == sql_error_codes.INSUFFICIENT_PRIVILEGE:
1926 details = 'Query: [%s]' % curs.query.strip().strip('\n').strip().strip('\n')
1927 if curs.statusmessage != '':
1928 details = 'Status: %s\n%s' % (
1929 curs.statusmessage.strip().strip('\n').strip().strip('\n'),
1930 details
1931 )
1932 if pg_exc.pgerror is None:
1933 msg = '[%s]' % pg_exc.pgcode
1934 else:
1935 msg = '[%s]: %s' % (pg_exc.pgcode, pg_exc.u_pgerror)
1936 try:
1937 curs_close()
1938 tx_rollback()
1939 conn_close()
1940 except dbapi.InterfaceError:
1941 _log.exception('cannot cleanup')
1942 raise gmExceptions.AccessDenied (
1943 msg,
1944 source = 'PostgreSQL',
1945 code = pg_exc.pgcode,
1946 details = details
1947 )
1948
1949 gmLog2.log_stack_trace()
1950 try:
1951 curs_close()
1952 tx_rollback()
1953 conn_close()
1954 except dbapi.InterfaceError:
1955 _log.exception('cannot cleanup')
1956 raise
1957
1958 except:
1959 _log.exception('error running query in RW connection')
1960 _log.error(capture_cursor_state(curs))
1961 for notice in notices_accessor.notices:
1962 _log.debug(str(notice, 'utf8', 'replace').strip('\n').strip('\r'))
1963 del notices_accessor.notices[:]
1964 gmLog2.log_stack_trace()
1965 try:
1966 curs_close()
1967 tx_rollback()
1968 conn_close()
1969 except dbapi.InterfaceError:
1970 _log.exception('cannot cleanup')
1971 raise
1972
1973 data = None
1974 col_idx = None
1975 if return_data:
1976 try:
1977 data = curs.fetchall()
1978 except:
1979 _log.exception('error fetching data from RW query')
1980 gmLog2.log_stack_trace()
1981 try:
1982 curs_close()
1983 tx_rollback()
1984 conn_close()
1985 except dbapi.InterfaceError:
1986 _log.exception('cannot cleanup')
1987 raise
1988 raise
1989 if get_col_idx:
1990 col_idx = get_col_indices(curs)
1991
1992 curs_close()
1993 conn_commit()
1994 conn_close()
1995
1996 return (data, col_idx)
1997
1998
1999 -def run_insert(link_obj=None, schema=None, table=None, values=None, returning=None, end_tx=False, get_col_idx=False, verbose=False):
2000 """Generates SQL for an INSERT query.
2001
2002 values: dict of values keyed by field to insert them into
2003 """
2004 if schema is None:
2005 schema = 'public'
2006
2007 fields = values.keys()
2008 val_snippets = []
2009 for field in fields:
2010 val_snippets.append('%%(%s)s' % field)
2011
2012 if returning is None:
2013 returning = ''
2014 return_data = False
2015 else:
2016 returning = '\n\tRETURNING\n\t\t%s' % ', '.join(returning)
2017 return_data = True
2018
2019 cmd = """\nINSERT INTO %s.%s (
2020 %s
2021 ) VALUES (
2022 %s
2023 )%s""" % (
2024 schema,
2025 table,
2026 ',\n\t\t'.join(fields),
2027 ',\n\t\t'.join(val_snippets),
2028 returning
2029 )
2030
2031 _log.debug('running SQL: >>>%s<<<', cmd)
2032
2033 return run_rw_queries (
2034 link_obj = link_obj,
2035 queries = [{'cmd': cmd, 'args': values}],
2036 end_tx = end_tx,
2037 return_data = return_data,
2038 get_col_idx = get_col_idx,
2039 verbose = verbose
2040 )
2041
2042
2043
2044
2046 """GNUmed database connection pool.
2047
2048 Extends psycopg2's ThreadedConnectionPool with
2049 a custom _connect() function. Supports one connection
2050 per thread - which also ties it to one particular DSN."""
2051
2053 _log.debug('conn request with key [%s]', key)
2054 conn = get_raw_connection(dsn = self._kwargs['dsn'], verbose = self._kwargs['verbose'], readonly = True)
2055
2056 conn.original_close = conn.close
2057 conn.close = _raise_exception_on_ro_conn_close
2058 if key is not None:
2059 self._used[key] = conn
2060 self._rused[id(conn)] = key
2061 else:
2062 self._pool.append(conn)
2063 return conn
2064
2065
2067 if key is None:
2068 key = threading.current_thread().ident
2069 try:
2070 conn = self._used[key]
2071 except KeyError:
2072 _log.error('no such key in connection pool: %s', key)
2073 _log.debug('available keys: %s', self._used.keys())
2074 return
2075 del self._used[key]
2076 del self._rused[id(conn)]
2077 conn.original_close()
2078
2079
2081 for conn_key in self._used.keys():
2082 conn = self._used[conn_key]
2083 if conn.closed != 0:
2084 continue
2085 _log.debug('closing pooled database connection, pool key: %s, backend PID: %s', conn_key, self._used[conn_key].get_backend_pid())
2086 conn.original_close()
2087
2088
2089 -def get_raw_connection(dsn=None, verbose=False, readonly=True, connection_name=None, autocommit=False):
2090 """Get a raw, unadorned connection.
2091
2092 - this will not set any parameters such as encoding, timezone, datestyle
2093 - the only requirement is a valid DSN
2094 - hence it can be used for "service" connections
2095 for verifying encodings etc
2096 """
2097
2098 if dsn is None:
2099 dsn = get_default_dsn()
2100
2101 if 'host=salaam.homeunix' in dsn:
2102 raise ValueError('The public database is not hosted by <salaam.homeunix.com> anymore.\n\nPlease point your configuration files to <publicdb.gnumed.de>.')
2103
2104
2105
2106
2107 if ' client_encoding=' not in dsn:
2108 dsn += ' client_encoding=utf8'
2109
2110 if ' application_name' not in dsn:
2111 if connection_name is None:
2112 dsn += " application_name=GNUmed-[%s]" % threading.current_thread().name.replace(' ', '_')
2113 else:
2114 dsn += " application_name=%s" % connection_name
2115
2116 try:
2117
2118 conn = dbapi.connect(dsn=dsn, connection_factory=psycopg2.extras.DictConnection)
2119 except dbapi.OperationalError as e:
2120 t, v, tb = sys.exc_info()
2121 try:
2122 msg = e.args[0]
2123 except (AttributeError, IndexError, TypeError):
2124 raise
2125 if 'fe_sendauth' in msg:
2126 raise cAuthenticationError(dsn, msg).with_traceback(tb)
2127 if regex.search('user ".*" does not exist', msg) is not None:
2128 raise cAuthenticationError(dsn, msg).with_traceback(tb)
2129 if 'uthenti' in msg:
2130 raise cAuthenticationError(dsn, msg).with_traceback(tb)
2131 raise
2132
2133 if connection_name is None:
2134 _log.debug('established anonymous database connection, backend PID: %s', conn.get_backend_pid())
2135 else:
2136 _log.debug('established database connection "%s", backend PID: %s', connection_name, conn.get_backend_pid())
2137
2138
2139
2140 global postgresql_version
2141 if postgresql_version is None:
2142 curs = conn.cursor()
2143 curs.execute("""
2144 SELECT
2145 substring(setting, E'^\\\\d{1,2}\\\\.\\\\d{1,2}')::numeric AS version
2146 FROM
2147 pg_settings
2148 WHERE
2149 name = 'server_version'
2150 """)
2151 postgresql_version = curs.fetchone()['version']
2152 _log.info('PostgreSQL version (numeric): %s' % postgresql_version)
2153 try:
2154 curs.execute("SELECT pg_size_pretty(pg_database_size(current_database()))")
2155 _log.info('database size: %s', curs.fetchone()[0])
2156 except:
2157 pass
2158 if verbose:
2159 _log_PG_settings(curs = curs)
2160 curs.close()
2161 conn.commit()
2162
2163 if _default_client_timezone is None:
2164 __detect_client_timezone(conn = conn)
2165
2166
2167 if readonly is True:
2168 _log.debug('readonly: forcing autocommit=True to avoid <IDLE IN TRANSACTION>')
2169 autocommit = True
2170 else:
2171 _log.debug('autocommit is desired to be: %s', autocommit)
2172 conn.commit()
2173 conn.autocommit = autocommit
2174 conn.readonly = readonly
2175
2176 conn.is_decorated = False
2177
2178 return conn
2179
2180
2181 -def get_connection(dsn=None, readonly=True, encoding=None, verbose=False, pooled=True, connection_name=None, autocommit=False):
2182 """Get a new connection.
2183
2184 This assumes the locale system has been initialized
2185 unless an encoding is specified.
2186 """
2187
2188
2189 if pooled and readonly and (dsn is None):
2190 global __ro_conn_pool
2191 if __ro_conn_pool is None:
2192 log_ro_conn = True
2193 __ro_conn_pool = cConnectionPool (
2194 minconn = 1,
2195 maxconn = 2,
2196 dsn = dsn,
2197 verbose = verbose
2198 )
2199 else:
2200 log_ro_conn = False
2201 try:
2202 conn = __ro_conn_pool.getconn()
2203 except psycopg2.pool.PoolError:
2204 _log.exception('falling back to non-pooled connection')
2205 conn = get_raw_connection(dsn = dsn, verbose = verbose, readonly = readonly, connection_name = connection_name, autocommit = autocommit)
2206 log_ro_conn = True
2207 if log_ro_conn:
2208 [ _log.debug(line) for line in capture_conn_state(conn = conn).split('\n') ]
2209 else:
2210 conn = get_raw_connection(dsn = dsn, verbose = verbose, readonly = readonly, connection_name = connection_name, autocommit = autocommit)
2211
2212 if conn.is_decorated:
2213 return conn
2214
2215 if encoding is None:
2216 encoding = _default_client_encoding
2217 if encoding is None:
2218 encoding = gmI18N.get_encoding()
2219 _log.warning('client encoding not specified')
2220 _log.warning('the string encoding currently set in the active locale is used: [%s]' % encoding)
2221 _log.warning('for this to work properly the application MUST have called locale.setlocale() before')
2222
2223
2224
2225 try:
2226 conn.set_client_encoding(encoding)
2227 except dbapi.OperationalError:
2228 t, v, tb = sys.exc_info()
2229 if str(v).find("can't set encoding to") != -1:
2230 raise cEncodingError(encoding, v).with_traceback(tb)
2231 raise
2232
2233
2234 if readonly:
2235
2236 pass
2237 else:
2238 conn.set_isolation_level(psycopg2.extensions.ISOLATION_LEVEL_SERIALIZABLE)
2239
2240 _log.debug('client time zone [%s]', _default_client_timezone)
2241
2242
2243 curs = conn.cursor()
2244 curs.execute(_sql_set_timezone, [_default_client_timezone])
2245 curs.close()
2246 conn.commit()
2247
2248 conn.is_decorated = True
2249
2250 if verbose:
2251 [ _log.debug(line) for line in capture_conn_state(conn = conn).split('\n') ]
2252
2253 return conn
2254
2255
2260
2261
2266
2267
2268
2269
2272
2273
2275 raise TypeError('close() called on read-only connection')
2276
2277
2279 run_insert (
2280 schema = 'gm',
2281 table = 'access_log',
2282 values = {'user_action': action},
2283 end_tx = True
2284 )
2285
2286
2288 """Check server time and local time to be within
2289 the given tolerance of each other.
2290
2291 tolerance: seconds
2292 """
2293 _log.debug('maximum skew tolerance (seconds): %s', tolerance)
2294
2295 cmd = "SELECT now() at time zone 'UTC'"
2296 conn = get_raw_connection(readonly=True)
2297 curs = conn.cursor()
2298
2299 start = time.time()
2300 rows, idx = run_ro_queries(link_obj = curs, queries = [{'cmd': cmd}])
2301 end = time.time()
2302 client_now_as_utc = pydt.datetime.utcnow()
2303
2304 curs.close()
2305 conn.commit()
2306
2307 server_now_as_utc = rows[0][0]
2308 query_duration = end - start
2309 _log.info('server "now" (UTC): %s', server_now_as_utc)
2310 _log.info('client "now" (UTC): %s', client_now_as_utc)
2311 _log.debug('wire roundtrip (seconds): %s', query_duration)
2312
2313 if query_duration > tolerance:
2314 _log.error('useless to check client/server time skew, wire roundtrip > tolerance')
2315 return False
2316
2317 if server_now_as_utc > client_now_as_utc:
2318 real_skew = server_now_as_utc - client_now_as_utc
2319 else:
2320 real_skew = client_now_as_utc - server_now_as_utc
2321
2322 _log.debug('client/server time skew: %s', real_skew)
2323
2324 if real_skew > pydt.timedelta(seconds = tolerance):
2325 _log.error('client/server time skew > tolerance')
2326 return False
2327
2328 return True
2329
2330
2332 """Checks database settings.
2333
2334 returns (status, message)
2335 status:
2336 0: no problem
2337 1: non-fatal problem
2338 2: fatal problem
2339 """
2340 _log.debug('checking database settings')
2341
2342 conn = get_connection()
2343
2344
2345 global postgresql_version_string
2346 if postgresql_version_string is None:
2347 curs = conn.cursor()
2348 curs.execute('SELECT version()')
2349 postgresql_version_string = curs.fetchone()['version']
2350 curs.close()
2351 _log.info('PostgreSQL version (string): "%s"' % postgresql_version_string)
2352
2353 options2check = {
2354
2355 'allow_system_table_mods': [['off'], 'system breakage', False],
2356 'check_function_bodies': [['on'], 'suboptimal error detection', False],
2357 'datestyle': [['ISO'], 'faulty timestamp parsing', True],
2358 'default_transaction_isolation': [['read committed'], 'faulty database reads', True],
2359 'default_transaction_read_only': [['on'], 'accidental database writes', False],
2360 'fsync': [['on'], 'data loss/corruption', True],
2361 'full_page_writes': [['on'], 'data loss/corruption', False],
2362 'lc_messages': [['C'], 'suboptimal error detection', False],
2363 'password_encryption': [['on', 'md5', 'scram-sha-256'], 'breach of confidentiality', False],
2364
2365 'synchronous_commit': [['on'], 'data loss/corruption', False],
2366 'sql_inheritance': [['on'], 'query breakage, data loss/corruption', True],
2367 'ignore_checksum_failure': [['off'], 'data loss/corruption', False],
2368 'track_commit_timestamp': [['on'], 'suboptimal auditing', False]
2369 }
2370
2371 from Gnumed.pycommon import gmCfg2
2372 _cfg = gmCfg2.gmCfgData()
2373 if _cfg.get(option = 'hipaa'):
2374 options2check['log_connections'] = [['on'], 'non-compliance with HIPAA', True]
2375 options2check['log_disconnections'] = [['on'], 'non-compliance with HIPAA', True]
2376 else:
2377 options2check['log_connections'] = [['on'], 'non-compliance with HIPAA', None]
2378 options2check['log_disconnections'] = [['on'], 'non-compliance with HIPAA', None]
2379
2380 cmd = "SELECT name, setting from pg_settings where name in %(settings)s"
2381 rows, idx = run_ro_queries (
2382 link_obj = conn,
2383 queries = [{'cmd': cmd, 'args': {'settings': tuple(options2check.keys())}}],
2384 get_col_idx = False
2385 )
2386
2387 found_error = False
2388 found_problem = False
2389 msg = []
2390 for row in rows:
2391 option = row['name']
2392 value_found = row['setting']
2393 values_expected = options2check[option][0]
2394 risk = options2check[option][1]
2395 fatal_setting = options2check[option][2]
2396 if value_found not in values_expected:
2397 if fatal_setting is True:
2398 found_error = True
2399 elif fatal_setting is False:
2400 found_problem = True
2401 elif fatal_setting is None:
2402 pass
2403 else:
2404 _log.error(options2check[option])
2405 raise ValueError('invalid database configuration sanity check')
2406 msg.append(_(' option [%s]: %s') % (option, value_found))
2407 msg.append(_(' risk: %s') % risk)
2408 _log.warning('PG option [%s] set to [%s], expected %s, risk: <%s>' % (option, value_found, values_expected, risk))
2409
2410 if found_error:
2411 return 2, '\n'.join(msg)
2412
2413 if found_problem:
2414 return 1, '\n'.join(msg)
2415
2416 return 0, ''
2417
2418
2420
2421
2422 try:
2423
2424
2425 curs.execute('SELECT name, setting, unit, source, reset_val, sourcefile, sourceline FROM pg_settings')
2426 except:
2427 _log.exception('cannot log PG settings ("SELECT ... FROM pg_settings" failed)')
2428 return False
2429 settings = curs.fetchall()
2430 for setting in settings:
2431 if setting['unit'] is None:
2432 unit = ''
2433 else:
2434 unit = ' %s' % setting['unit']
2435 if setting['sourcefile'] is None:
2436 sfile = ''
2437 else:
2438 sfile = '// %s @ %s' % (setting['sourcefile'], setting['sourceline'])
2439
2440
2441
2442
2443
2444
2445 _log.debug('%s: %s%s (set from: [%s] // sess RESET will set to: [%s]%s)',
2446 setting['name'],
2447 setting['setting'],
2448 unit,
2449 setting['source'],
2450 setting['reset_val'],
2451
2452 sfile
2453 )
2454
2455 try:
2456 curs.execute('select pg_available_extensions()')
2457 except:
2458 _log.exception('cannot log available PG extensions')
2459 return False
2460 extensions = curs.fetchall()
2461 if extensions is None:
2462 _log.error('no PG extensions available')
2463 return False
2464 for ext in extensions:
2465 _log.debug('PG extension: %s', ext['pg_available_extensions'])
2466
2467
2468
2469
2470
2471
2472
2473
2474
2475
2476
2477
2478 return True
2479
2480
2482
2483 if not isinstance(exc, dbapi.Error):
2484 return exc
2485
2486 if exc.pgerror is None:
2487 try:
2488 msg = exc.args[0]
2489 except (AttributeError, IndexError, TypeError):
2490 return exc
2491
2492 exc.u_pgerror = msg
2493 return exc
2494
2495
2496 exc.u_pgerror = exc.pgerror.strip().strip('\n').strip().strip('\n')
2497
2498 return exc
2499
2500
2502
2503 try:
2504 msg = exc.args[0]
2505 except (AttributeError, IndexError, TypeError):
2506 return 'cannot extract message from exception'
2507
2508
2509 return str(msg, gmI18N.get_encoding(), 'replace')
2510
2511
2513
2514 - def __init__(self, dsn=None, prev_val=None):
2515 self.dsn = dsn
2516 self.prev_val = prev_val
2517
2519 return 'PostgreSQL: %sDSN: %s' % (self.prev_val, self.dsn)
2520
2521
2522
2523
2525
2526 - def __init__(self, encoding=None, prev_val=None):
2527 self.encoding = encoding
2528 self.prev_val = prev_val
2529
2531 return 'PostgreSQL: %s\nencoding: %s' % (self.prev_val, self.encoding)
2532
2533
2534
2535
2536
2538
2540 if dt.tzinfo is None:
2541 raise ValueError('datetime.datetime instance is lacking a time zone: [%s]' % _timestamp_template % dt.isoformat())
2542 self.__dt = dt
2543
2546
2547
2548
2549
2550
2551
2552 psycopg2.extensions.register_type(psycopg2.extensions.UNICODE)
2553 psycopg2.extensions.register_type(psycopg2._psycopg.UNICODEARRAY)
2554
2555
2556
2557 psycopg2.extensions.register_adapter(pydt.datetime, cAdapterPyDateTime)
2558
2559
2560
2561
2562
2563
2564
2565
2566 if __name__ == "__main__":
2567
2568 if len(sys.argv) < 2:
2569 sys.exit()
2570
2571 if sys.argv[1] != 'test':
2572 sys.exit()
2573
2574 from Gnumed.pycommon.gmTools import file2md5
2575
2576 logging.basicConfig(level=logging.DEBUG)
2577
2578
2580 run_rw_queries(queries = [
2581 {'cmd': 'drop table if exists test_bytea'},
2582 {'cmd': 'create table test_bytea (data bytea)'}
2583 ])
2584
2585 try:
2586 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))
2587 except:
2588 _log.exception('error')
2589
2590 run_rw_queries(queries = [
2591 {'cmd': 'drop table test_bytea'}
2592 ])
2593
2594
2601
2602
2603
2604
2605
2606
2608
2609 run_rw_queries(queries = [
2610 {'cmd': 'drop table if exists test_bytea'},
2611 {'cmd': 'create table test_bytea (pk serial primary key, data bytea)'},
2612 {'cmd': "insert into test_bytea (data) values (NULL::bytea)"}
2613 ])
2614
2615 md5_query = {
2616 'cmd': 'select md5(data) AS md5 FROM test_bytea WHERE pk = %(pk)s',
2617 'args': {'pk': 1}
2618 }
2619
2620 file2bytea_copy_from (
2621 table = 'test_bytea',
2622 columns = ['data'],
2623 filename = sys.argv[2],
2624 md5_query = md5_query,
2625 file_md5 = file2md5(sys.argv[2], True)
2626 )
2627
2628 run_rw_queries(queries = [
2629 {'cmd': 'drop table if exists test_bytea'}
2630 ])
2631
2632
2634
2635 run_rw_queries(queries = [
2636 {'cmd': 'drop table if exists test_bytea'},
2637 {'cmd': 'create table test_bytea (pk serial primary key, data bytea)'},
2638 {'cmd': "insert into test_bytea (data) values (NULL::bytea)"}
2639 ])
2640
2641 cmd = """
2642 update test_bytea
2643 set data = overlay (
2644 coalesce(data, ''::bytea)
2645 placing %(data)s::bytea
2646 from %(start)s
2647 for %(size)s
2648 )
2649 where
2650 pk > %(pk)s
2651 """
2652 md5_cmd = 'select md5(data) from test_bytea'
2653 args = {'pk': 0}
2654 file2bytea_overlay (
2655 query = cmd,
2656 args = args,
2657 filename = sys.argv[2],
2658 conn = None,
2659 md5_query = md5_cmd,
2660 file_md5 = file2md5(sys.argv[2], True)
2661 )
2662
2663 run_rw_queries(queries = [
2664 {'cmd': 'drop table test_bytea'}
2665 ])
2666
2667
2669 print("testing get_connection()")
2670
2671 dsn = 'foo'
2672 try:
2673 conn = get_connection(dsn=dsn)
2674 except dbapi.OperationalError as e:
2675 print("SUCCESS: get_connection(%s) failed as expected" % dsn)
2676 t, v = sys.exc_info()[:2]
2677 print (' ', t)
2678 print (' ', v)
2679
2680 dsn = 'dbname=gnumed_v9'
2681 try:
2682 conn = get_connection(dsn=dsn)
2683 except cAuthenticationError:
2684 print("SUCCESS: get_connection(%s) failed as expected" % dsn)
2685 t, v = sys.exc_info()[:2]
2686 print(' ', t)
2687 print(' ', v)
2688
2689 dsn = 'dbname=gnumed_v9 user=abc'
2690 try:
2691 conn = get_connection(dsn=dsn)
2692 except cAuthenticationError:
2693 print("SUCCESS: get_connection(%s) failed as expected" % dsn)
2694 t, v = sys.exc_info()[:2]
2695 print(' ', t)
2696 print(' ', v)
2697
2698 dsn = 'dbname=gnumed_v9 user=any-doc'
2699 try:
2700 conn = get_connection(dsn=dsn)
2701 except cAuthenticationError:
2702 print("SUCCESS: get_connection(%s) failed as expected" % dsn)
2703 t, v = sys.exc_info()[:2]
2704 print(' ', t)
2705 print(' ', v)
2706
2707 dsn = 'dbname=gnumed_v9 user=any-doc password=abc'
2708 try:
2709 conn = get_connection(dsn=dsn)
2710 except cAuthenticationError:
2711 print("SUCCESS: get_connection(%s) failed as expected" % dsn)
2712 t, v = sys.exc_info()[:2]
2713 print(' ', t)
2714 print(' ', v)
2715
2716 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc'
2717 conn = get_connection(dsn=dsn, readonly=True)
2718
2719 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc'
2720 conn = get_connection(dsn=dsn, readonly=False)
2721
2722 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc'
2723 encoding = 'foo'
2724 try:
2725 conn = get_connection(dsn=dsn, encoding=encoding)
2726 except cEncodingError:
2727 print("SUCCESS: get_connection(%s, %s) failed as expected" % (dsn, encoding))
2728 t, v = sys.exc_info()[:2]
2729 print(' ', t)
2730 print(' ', v)
2731
2733 print("testing exceptions")
2734
2735 try:
2736 raise cAuthenticationError('no dsn', 'no previous exception')
2737 except cAuthenticationError:
2738 t, v, tb = sys.exc_info()
2739 print(t)
2740 print(v)
2741 print(tb)
2742
2743 try:
2744 raise cEncodingError('no dsn', 'no previous exception')
2745 except cEncodingError:
2746 t, v, tb = sys.exc_info()
2747 print(t)
2748 print(v)
2749 print(tb)
2750
2752 print("testing run_ro_queries()")
2753
2754 dsn = 'dbname=gnumed_v9 user=any-doc password=any-doc'
2755 conn = get_connection(dsn, readonly=True)
2756
2757 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': 'SELECT version()'}], return_data=True, get_col_idx=True, verbose=True)
2758 print(data)
2759 print(idx)
2760 data, idx = run_ro_queries(link_obj=conn, queries=[{'cmd': 'SELECT 1'}], return_data=True, get_col_idx=True)
2761 print(data)
2762 print(idx)
2763
2764 curs = conn.cursor()
2765
2766 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'SELECT version()'}], return_data=True, get_col_idx=True, verbose=True)
2767 print(data)
2768 print(idx)
2769
2770 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'SELECT 1'}], return_data=True, get_col_idx=True, verbose=True)
2771 print(data)
2772 print(idx)
2773
2774 try:
2775 data, idx = run_ro_queries(link_obj=curs, queries=[{'cmd': 'selec 1'}], return_data=True, get_col_idx=True, verbose=True)
2776 print(data)
2777 print(idx)
2778 except psycopg2.ProgrammingError:
2779 print('SUCCESS: run_ro_queries("selec 1") failed as expected')
2780 t, v = sys.exc_info()[:2]
2781 print(' ', t)
2782 print(' ', v)
2783
2784 curs.close()
2785
2790
2792 print("testing set_default_client_encoding()")
2793
2794 enc = 'foo'
2795 try:
2796 set_default_client_encoding(enc)
2797 print("SUCCESS: encoding [%s] worked" % enc)
2798 except ValueError:
2799 print("SUCCESS: set_default_client_encoding(%s) failed as expected" % enc)
2800 t, v = sys.exc_info()[:2]
2801 print(' ', t)
2802 print(' ', v)
2803
2804 enc = ''
2805 try:
2806 set_default_client_encoding(enc)
2807 print("SUCCESS: encoding [%s] worked" % enc)
2808 except ValueError:
2809 print("SUCCESS: set_default_client_encoding(%s) failed as expected" % enc)
2810 t, v = sys.exc_info()[:2]
2811 print(' ', t)
2812 print(' ', v)
2813
2814 enc = 'latin1'
2815 try:
2816 set_default_client_encoding(enc)
2817 print("SUCCESS: encoding [%s] worked" % enc)
2818 except ValueError:
2819 print("SUCCESS: set_default_client_encoding(%s) failed as expected" % enc)
2820 t, v = sys.exc_info()[:2]
2821 print(' ', t)
2822 print(' ', v)
2823
2824 enc = 'utf8'
2825 try:
2826 set_default_client_encoding(enc)
2827 print("SUCCESS: encoding [%s] worked" % enc)
2828 except ValueError:
2829 print("SUCCESS: set_default_client_encoding(%s) failed as expected" % enc)
2830 t, v = sys.exc_info()[:2]
2831 print(' ', t)
2832 print(' ', v)
2833
2834 enc = 'unicode'
2835 try:
2836 set_default_client_encoding(enc)
2837 print("SUCCESS: encoding [%s] worked" % enc)
2838 except ValueError:
2839 print("SUCCESS: set_default_client_encoding(%s) failed as expected" % enc)
2840 t, v = sys.exc_info()[:2]
2841 print(' ', t)
2842 print(' ', v)
2843
2844 enc = 'UNICODE'
2845 try:
2846 set_default_client_encoding(enc)
2847 print("SUCCESS: encoding [%s] worked" % enc)
2848 except ValueError:
2849 print("SUCCESS: set_default_client_encoding(%s) failed as expected" % enc)
2850 t, v = sys.exc_info()[:2]
2851 print(' ', t)
2852 print(' ', v)
2853
2862
2864 dsn = get_default_dsn()
2865 conn = get_connection(dsn, readonly=True)
2866 curs = conn.cursor()
2867 curs.execute('SELECT * from clin.clin_narrative where narrative = %s', ['a'])
2868
2870 tests = [
2871 ['(', '\\(']
2872 , ['[', '\\[']
2873 , [')', '\\)']
2874 ]
2875 for test in tests:
2876 result = sanitize_pg_regex(test[0])
2877 if result != test[1]:
2878 print('ERROR: sanitize_pg_regex(%s) returned "%s", expected "%s"' % (test[0], result, test[1]))
2879
2881 status = True
2882 tests = [
2883 [None, True],
2884 [1, True],
2885 ['1', True],
2886 ['abc', False]
2887 ]
2888
2889 if not is_pg_interval():
2890 print('ERROR: is_pg_interval() returned "False", expected "True"')
2891 status = False
2892
2893 for test in tests:
2894 result = is_pg_interval(test[0])
2895 if result != test[1]:
2896 print('ERROR: is_pg_interval(%s) returned "%s", expected "%s"' % (test[0], result, test[1]))
2897 status = False
2898
2899 return status
2900
2903
2904
2906 print(get_foreign_key_names (
2907 src_schema = 'clin',
2908 src_table = 'vaccination',
2909 src_column = 'fk_episode',
2910 target_schema = 'clin',
2911 target_table = 'episode',
2912 target_column = 'pk'
2913 ))
2914
2915
2917 schema = 'clin'
2918 table = 'episode'
2919 col = 'pk'
2920 print('column %s.%s.%s is referenced by:' % (schema, table, col))
2921 for row in get_foreign_keys2column (
2922 schema = schema,
2923 table = table,
2924 column = col
2925 ):
2926 print(' <- %s.%s' % (
2927 row['referencing_table'],
2928 row['referencing_column']
2929 ))
2930
2931
2933
2934 tests = [
2935
2936 [None, 'de_DE', True],
2937 [None, 'lang_w/o_tx', False],
2938 [None, None, True],
2939
2940 ['any-doc', 'de_DE', True],
2941 ['any-doc', 'lang_w/o_tx', False],
2942 ['any-doc', None, True],
2943
2944 ['invalid user', 'de_DE', None],
2945 ['invalid user', 'lang_w/o_tx', False],
2946 ['invalid user', None, True]
2947 ]
2948 for test in tests:
2949 try:
2950 result = set_user_language(user = test[0], language = test[1])
2951 if result != test[2]:
2952 print("test:", test)
2953 print("result:", result, "expected:", test[2])
2954 except psycopg2.IntegrityError as e:
2955 if test[2] is None:
2956 continue
2957 print("test:", test)
2958 print("expected exception")
2959 print("result:", e)
2960
2961
2963 for line in get_schema_revision_history():
2964 print(' - '.join(line))
2965
2966
2968 gmDateTime.init()
2969 args = {'dt': gmDateTime.pydt_max_here()}
2970 cmd = "SELECT %(dt)s"
2971
2972
2973
2974 cmd = """
2975 SELECT to_timestamp (foofoo,'YYMMDD.HH24MI') FROM (
2976 SELECT REGEXP_REPLACE (
2977 't1.130729.0902.tif', -- string
2978 E'(.1)\.([0-9\.]+)(\.tif)', -- pattern
2979 E'\\\\2' -- replacement
2980 ) AS foofoo
2981 ) AS foo"""
2982 rows, idx = run_ro_queries(queries = [{'cmd': cmd, 'args': args}], get_col_idx = False)
2983 print(rows)
2984 print(rows[0])
2985 print(rows[0][0])
2986
2989
2991 row_is_locked(table = 'dem.identity', pk = 12)
2992
2993 print("1st connection:")
2994 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2995 print(" 1st shared lock succeeded:", lock_row(table = 'dem.identity', pk = 12, exclusive = False))
2996 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
2997
2998 print(" 2nd shared lock should succeed:", lock_row(table = 'dem.identity', pk = 12, exclusive = False))
2999 print(" `-> unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = False))
3000 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
3001 print(" exclusive lock should succeed:", lock_row(table = 'dem.identity', pk = 12, exclusive = True))
3002 print(" `-> unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = True))
3003 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
3004
3005 print("2nd connection:")
3006 conn = get_raw_connection(readonly=True)
3007 print(" shared lock should succeed:", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
3008 print(" `-> unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
3009 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
3010 print(" exclusive lock succeeded ?", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = True), "(should fail)")
3011 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
3012
3013 print("1st connection:")
3014 print(" unlock succeeded:", unlock_row(table = 'dem.identity', pk = 12, exclusive = False))
3015 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
3016
3017 print("2nd connection:")
3018 print(" exclusive lock should succeed", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = True))
3019 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
3020 print(" shared lock should succeed:", lock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
3021 print(" `-> unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
3022 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
3023 print(" unlock succeeded:", unlock_row(link_obj = conn, table = 'dem.identity', pk = 12, exclusive = False))
3024 print(" locked:", row_is_locked(table = 'dem.identity', pk = 12))
3025
3026 conn.close()
3027
3028
3030 print(get_foreign_key_names (
3031 src_schema = 'dem',
3032 src_table = 'names',
3033 src_column = 'id_identity',
3034 target_schema = 'dem',
3035 target_table = 'identity',
3036 target_column = 'pk'
3037 ))
3038
3039
3041 print(get_index_name(indexed_table = 'clin.vaccination', indexed_column = 'fk_episode'))
3042
3043
3046
3047
3051
3052
3053
3054
3055
3056
3057
3058
3059
3060
3061
3062
3063
3064 test_get_foreign_key_details()
3065
3066
3067
3068
3069
3070
3071
3072
3073
3074
3075
3076
3077
3078
3079
3080
3081