From eb5e7f8b2df369c83b68bcb96a5057848ae9c76b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Fr=C3=A9d=C3=A9ric=20P=C3=A9ters?= Date: Sun, 1 Jan 2023 18:53:34 +0100 Subject: [PATCH] sql: always use CREATE INDEX IF NOT EXISTS (#60507) --- wcs/sql.py | 119 ++++++++++++----------------------------------------- 1 file changed, 26 insertions(+), 93 deletions(-) diff --git a/wcs/sql.py b/wcs/sql.py index 337ba9b8c..60cda0275 100644 --- a/wcs/sql.py +++ b/wcs/sql.py @@ -1069,52 +1069,24 @@ AS $${code}$$; def do_formdef_indexes(formdef, created, conn, cur, concurrently=False): table_name = get_formdef_table_name(formdef) evolutions_table_name = table_name + '_evolutions' - existing_indexes = set() - if not created: - cur.execute( - '''SELECT pci.relname, array_length(pi.indkey, 1) - FROM pg_index pi - JOIN pg_class pci on pci.oid = pi.indexrelid - JOIN pg_class pct on pct.oid = pi.indrelid - WHERE pci.relnamespace = 'public'::regnamespace - AND pct.relname in (%s, %s)''', - (table_name, evolutions_table_name), - ) - existing_indexes = {x[0]: x[1] for x in cur.fetchall()} - create_index = 'CREATE INDEX' + create_index = 'CREATE INDEX IF NOT EXISTS' if concurrently: - create_index = 'CREATE INDEX CONCURRENTLY' + create_index = 'CREATE INDEX CONCURRENTLY IF NOT EXISTS' - fid_idx = evolutions_table_name + '_fid' - - if fid_idx in existing_indexes and existing_indexes[fid_idx] != 2: - # The index was previously (< #67757) on formdata_id only, so - # search for it with only one key and recreate it if needed. - if concurrently: - cur.execute('DROP INDEX CONCURRENTLY %s' % fid_idx) - else: - cur.execute('DROP INDEX %s' % fid_idx) - cur.execute( - '''%s %s_fid ON %s (formdata_id, id)''' - % (create_index, evolutions_table_name, evolutions_table_name) - ) - elif fid_idx not in existing_indexes: - cur.execute( - '''%s %s_fid ON %s (formdata_id, id)''' - % (create_index, evolutions_table_name, evolutions_table_name) - ) + cur.execute( + '''%s %s_fid ON %s (formdata_id, id)''' % (create_index, evolutions_table_name, evolutions_table_name) + ) for attr in ('receipt_time', 'anonymised', 'user_id', 'status'): - if table_name + '_' + attr + '_idx' not in existing_indexes: - cur.execute( - '%(create_index)s %(table_name)s_%(attr)s_idx ON %(table_name)s (%(attr)s)' - % {'create_index': create_index, 'table_name': table_name, 'attr': attr} - ) + cur.execute( + '%(create_index)s %(table_name)s_%(attr)s_idx ON %(table_name)s (%(attr)s)' + % {'create_index': create_index, 'table_name': table_name, 'attr': attr} + ) for attr in ('concerned_roles_array', 'actions_roles_array'): idx_name = 'idx_' + attr + '_' + table_name cur.execute( - '%(create_index)s IF NOT EXISTS %(idx_name)s ON %(table_name)s USING gin (%(attr)s)' + '%(create_index)s %(idx_name)s ON %(table_name)s USING gin (%(attr)s)' % {'create_index': create_index, 'table_name': table_name, 'idx_name': idx_name, 'attr': attr} ) @@ -1222,20 +1194,11 @@ def do_user_table(): for field in existing_fields - needed_fields: cur.execute('''ALTER TABLE %s DROP COLUMN %s''' % (table_name, field)) + # create indexes + cur.execute('CREATE INDEX IF NOT EXISTS users_name_idx ON users (name)') + cur.execute('CREATE INDEX IF NOT EXISTS users_name_identifiers_idx ON users USING gin(name_identifiers)') + conn.commit() - - try: - cur.execute('CREATE INDEX users_name_idx ON users (name)') - conn.commit() - except psycopg2.ProgrammingError: - conn.rollback() - - try: - cur.execute('CREATE INDEX users_name_identifiers_idx ON users USING gin(name_identifiers)') - conn.commit() - except psycopg2.ProgrammingError: - conn.rollback() - cur.close() @@ -1448,17 +1411,9 @@ def do_custom_views_table(): # add indexes cur.execute( - '''SELECT indexname - FROM pg_indexes - WHERE schemaname = 'public' - AND tablename = %s''', - (table_name,), + '''CREATE INDEX IF NOT EXISTS %s_formdef_type_id ON %s(formdef_type, formdef_id)''' + % (table_name, table_name) ) - existing_indexes = {x[0] for x in cur.fetchall()} - if ('%s_formdef_type_id' % table_name) not in existing_indexes: - cur.execute( - '''CREATE INDEX %s_formdef_type_id ON %s(formdef_type, formdef_id)''' % (table_name, table_name) - ) conn.commit() cur.close() @@ -1476,7 +1431,7 @@ def do_snapshots_table(): ) if cur.fetchone()[0] == 0: cur.execute( - '''CREATE TABLE %s (id SERIAL, + '''CREATE TABLE %s (id SERIAL PRIMARY KEY, object_type VARCHAR, object_id VARCHAR, timestamp TIMESTAMP WITH TIME ZONE, @@ -1506,22 +1461,11 @@ def do_snapshots_table(): for field in existing_fields - needed_fields: cur.execute('''ALTER TABLE %s DROP COLUMN %s''' % (table_name, field)) - # add indexes + # add index cur.execute( - '''SELECT indexname - FROM pg_indexes - WHERE schemaname = 'public' - AND tablename = %s''', - (table_name,), + '''CREATE INDEX IF NOT EXISTS %s_object_by_date ON %s(object_type, object_id, timestamp DESC)''' + % (table_name, table_name) ) - existing_indexes = {x[0] for x in cur.fetchall()} - if ('%s_pkey' % table_name) not in existing_indexes: - cur.execute('''ALTER TABLE %s ADD PRIMARY KEY (id)''' % table_name) - if ('%s_object_by_date' % table_name) not in existing_indexes: - cur.execute( - '''CREATE INDEX %s_object_by_date ON %s(object_type, object_id, timestamp DESC)''' - % (table_name, table_name) - ) conn.commit() cur.close() @@ -1577,27 +1521,16 @@ def do_loggederrors_table(concurrently=False): for field in existing_fields - needed_fields: cur.execute('''ALTER TABLE %s DROP COLUMN %s''' % (table_name, field)) - create_index = 'CREATE INDEX' + create_index = 'CREATE INDEX IF NOT EXISTS' if concurrently: - create_index = 'CREATE INDEX CONCURRENTLY' + create_index = 'CREATE INDEX CONCURRENTLY IF NOT EXISTS' # build indexes - existing_indexes = set() - cur.execute( - '''SELECT indexname - FROM pg_indexes - WHERE schemaname = 'public' - AND tablename = %s''', - (table_name,), - ) - existing_indexes = {x[0] for x in cur.fetchall()} - for attr in ('formdef_id', 'workflow_id'): - if table_name + '_' + attr + '_idx' not in existing_indexes: - cur.execute( - '%(create_index)s %(table_name)s_%(attr)s_idx ON %(table_name)s (%(attr)s)' - % {'create_index': create_index, 'table_name': table_name, 'attr': attr} - ) + cur.execute( + '%(create_index)s %(table_name)s_%(attr)s_idx ON %(table_name)s (%(attr)s)' + % {'create_index': create_index, 'table_name': table_name, 'attr': attr} + ) conn.commit() cur.close() -- 2.39.2