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