Просмотр исходного кода

Merge pull request #15680 from surajshetty3416/fix-db-index

version-14
Suraj Shetty 3 лет назад
committed by GitHub
Родитель
Сommit
75245c25dc
Не найден GPG ключ соответствующий данной подписи Идентификатор GPG ключа: 4AEE18F83AFDEB23
6 измененных файлов: 157 добавлений и 49 удалений
  1. +9
    -2
      frappe/database/mariadb/database.py
  2. +25
    -9
      frappe/database/mariadb/schema.py
  3. +9
    -7
      frappe/database/postgres/database.py
  4. +58
    -26
      frappe/database/postgres/schema.py
  5. +5
    -4
      frappe/database/schema.py
  6. +51
    -1
      frappe/tests/test_db_update.py

+ 9
- 2
frappe/database/mariadb/database.py Просмотреть файл

@@ -245,9 +245,16 @@ class MariaDBDatabase(Database):
column_name as 'name',
column_type as 'type',
column_default as 'default',
column_key = 'MUL' as 'index',
COALESCE(
(select 1
from information_schema.statistics
where table_name="{table_name}"
and column_name=columns.column_name
and NON_UNIQUE=1
limit 1
), 0) as 'index',
column_key = 'UNI' as 'unique'
from information_schema.columns
from information_schema.columns as columns
where table_name = '{table_name}' '''.format(table_name=table_name), as_dict=1)

def has_index(self, table_name, index_name):


+ 25
- 9
frappe/database/mariadb/schema.py Просмотреть файл

@@ -58,18 +58,34 @@ class MariaDBTable(DBTable):
modify_column_query.append("MODIFY `{}` {}".format(col.fieldname, col.get_definition()))

for col in self.add_index:
# if index key not exists
if not frappe.db.sql("SHOW INDEX FROM `%s` WHERE key_name = %s" %
(self.table_name, '%s'), col.fieldname):
add_index_query.append("ADD INDEX `{}`(`{}`)".format(col.fieldname, col.fieldname))
# if index key does not exists
if not frappe.db.has_index(self.table_name, col.fieldname + '_index'):
add_index_query.append("ADD INDEX `{}_index`(`{}`)".format(col.fieldname, col.fieldname))

for col in self.drop_index:
for col in self.drop_index + self.drop_unique:
if col.fieldname != 'name': # primary key
current_column = self.current_columns.get(col.fieldname.lower())
unique_constraint_changed = current_column.unique != col.unique
if unique_constraint_changed and not col.unique:
# nosemgrep
unique_index_record = frappe.db.sql("""
SHOW INDEX FROM `{0}`
WHERE Key_name=%s
AND Non_unique=0
""".format(self.table_name), (col.fieldname), as_dict=1)
if unique_index_record:
drop_index_query.append("DROP INDEX `{}`".format(unique_index_record[0].Key_name))
index_constraint_changed = current_column.index != col.set_index
# if index key exists
if frappe.db.sql("""SHOW INDEX FROM `{0}`
WHERE key_name=%s
AND Non_unique=%s""".format(self.table_name), (col.fieldname, col.unique)):
drop_index_query.append("drop index `{}`".format(col.fieldname))
if index_constraint_changed and not col.set_index:
# nosemgrep
index_record = frappe.db.sql("""
SHOW INDEX FROM `{0}`
WHERE Key_name=%s
AND Non_unique=1
""".format(self.table_name), (col.fieldname + '_index'), as_dict=1)
if index_record:
drop_index_query.append("DROP INDEX `{}`".format(index_record[0].Key_name))

try:
for query_parts in [add_column_query, modify_column_query, add_index_query, drop_index_query]:


+ 9
- 7
frappe/database/postgres/database.py Просмотреть файл

@@ -77,11 +77,11 @@ class PostgresDatabase(Database):
"""Escape quotes and percent in given string."""
if isinstance(s, bytes):
s = s.decode('utf-8')
# MariaDB's driver treats None as an empty string
# So Postgres should do the same

if s is None:
if s is None:
s = ''

if percent:
@@ -308,18 +308,20 @@ class PostgresDatabase(Database):
WHEN 'timestamp without time zone' THEN 'timestamp'
ELSE a.data_type
END AS type,
COUNT(b.indexdef) AS Index,
BOOL_OR(b.index) AS index,
SPLIT_PART(COALESCE(a.column_default, NULL), '::', 1) AS default,
BOOL_OR(b.unique) AS unique
FROM information_schema.columns a
LEFT JOIN
(SELECT indexdef, tablename, indexdef LIKE '%UNIQUE INDEX%' AS unique
(SELECT indexdef, tablename,
indexdef LIKE '%UNIQUE INDEX%' AS unique,
indexdef NOT LIKE '%UNIQUE INDEX%' AS index
FROM pg_indexes
WHERE tablename='{table_name}') b
ON SUBSTRING(b.indexdef, '\(.*\)') LIKE CONCAT('%', a.column_name, '%')
ON SUBSTRING(b.indexdef, '(.*)') LIKE CONCAT('%', a.column_name, '%')
WHERE a.table_name = '{table_name}'
GROUP BY a.column_name, a.data_type, a.column_default, a.character_maximum_length;'''
.format(table_name=table_name), as_dict=1)
GROUP BY a.column_name, a.data_type, a.column_default, a.character_maximum_length;
'''.format(table_name=table_name), as_dict=1)

def get_database_list(self, target):
return [d[0] for d in self.sql("SELECT datname FROM pg_database;")]


+ 58
- 26
frappe/database/postgres/schema.py Просмотреть файл

@@ -11,8 +11,6 @@ class PostgresTable(DBTable):
column_defs = self.get_column_definitions()
if column_defs: add_text += ',\n'.join(column_defs)

# index
# index_defs = self.get_index_definitions()
# TODO: set docstatus length
# create table
frappe.db.sql("""create table `%s` (
@@ -28,8 +26,25 @@ class PostgresTable(DBTable):
idx bigint not null default '0',
%s)""".format(varchar_len=frappe.db.VARCHAR_LEN) % (self.table_name, add_text))

self.create_indexes()
frappe.db.commit()

def create_indexes(self):
create_index_query = ""
for key, col in self.columns.items():
if (col.set_index
and col.fieldtype in frappe.db.type_map
and frappe.db.type_map.get(col.fieldtype)[0]
not in ('text', 'longtext')):
create_index_query += 'CREATE INDEX IF NOT EXISTS "{index_name}" ON `{table_name}`(`{field}`);'.format(
index_name=col.fieldname,
table_name=self.table_name,
field=col.fieldname
)
if create_index_query:
# nosemgrep
frappe.db.sql(create_index_query)

def alter(self):
for col in self.columns.values():
col.build_for_alter_table(self.current_columns.get(col.fieldname.lower()))
@@ -52,8 +67,8 @@ class PostgresTable(DBTable):
query.append("ALTER COLUMN `{0}` TYPE {1} {2}".format(
col.fieldname,
get_definition(col.fieldtype, precision=col.precision, length=col.length),
using_clause)
)
using_clause
))

for col in self.set_default:
if col.fieldname=="name":
@@ -73,37 +88,54 @@ class PostgresTable(DBTable):

query.append("ALTER COLUMN `{}` SET DEFAULT {}".format(col.fieldname, col_default))

create_index_query = ""
create_contraint_query = ""
for col in self.add_index:
# if index key not exists
create_index_query += 'CREATE INDEX IF NOT EXISTS "{index_name}" ON `{table_name}`(`{field}`);'.format(
create_contraint_query += 'CREATE INDEX IF NOT EXISTS "{index_name}" ON `{table_name}`(`{field}`);'.format(
index_name=col.fieldname,
table_name=self.table_name,
field=col.fieldname)

drop_index_query = ""
for col in self.add_unique:
# if index key not exists
create_contraint_query += 'CREATE UNIQUE INDEX IF NOT EXISTS "unique_{index_name}" ON `{table_name}`(`{field}`);'.format(
index_name=col.fieldname,
table_name=self.table_name,
field=col.fieldname
)

drop_contraint_query = ""
for col in self.drop_index:
# primary key
if col.fieldname != 'name':
# if index key exists
if not frappe.db.has_index(self.table_name, col.fieldname):
drop_index_query += 'DROP INDEX IF EXISTS "{}" ;'.format(col.fieldname)
drop_contraint_query += 'DROP INDEX IF EXISTS "{}" ;'.format(col.fieldname)

if query:
try:
for col in self.drop_unique:
# primary key
if col.fieldname != 'name':
# if index key exists
drop_contraint_query += 'DROP INDEX IF EXISTS "unique_{}" ;'.format(col.fieldname)
try:
if query:
final_alter_query = "ALTER TABLE `{}` {}".format(self.table_name, ", ".join(query))
if final_alter_query: frappe.db.sql(final_alter_query)
if create_index_query: frappe.db.sql(create_index_query)
if drop_index_query: frappe.db.sql(drop_index_query)
except Exception as e:
# sanitize
if frappe.db.is_duplicate_fieldname(e):
frappe.throw(str(e))
elif frappe.db.is_duplicate_entry(e):
fieldname = str(e).split("'")[-2]
frappe.throw(_("""{0} field cannot be set as unique in {1},
as there are non-unique existing values""".format(
fieldname, self.table_name)))
raise e
else:
raise e
# nosemgrep
frappe.db.sql(final_alter_query)
if create_contraint_query:
# nosemgrep
frappe.db.sql(create_contraint_query)
if drop_contraint_query:
# nosemgrep
frappe.db.sql(drop_contraint_query)
except Exception as e:
# sanitize
if frappe.db.is_duplicate_fieldname(e):
frappe.throw(str(e))
elif frappe.db.is_duplicate_entry(e):
fieldname = str(e).split("'")[-2]
frappe.throw(
_("{0} field cannot be set as unique in {1}, as there are non-unique existing values")
.format(fieldname, self.table_name)
)
else:
raise e

+ 5
- 4
frappe/database/schema.py Просмотреть файл

@@ -21,6 +21,7 @@ class DBTable:
self.change_name = []
self.add_unique = []
self.add_index = []
self.drop_unique = []
self.drop_index = []
self.set_default = []

@@ -219,8 +220,10 @@ class DbColumn:
self.table.change_type.append(self)

# unique
if((self.unique and not current_def['unique']) and column_type not in ('text', 'longtext')):
if ((self.unique and not current_def['unique']) and column_type not in ('text', 'longtext')):
self.table.add_unique.append(self)
elif (current_def['unique'] and not self.unique):
self.table.drop_unique.append(self)

# default
if (self.default_changed(current_def)
@@ -230,9 +233,7 @@ class DbColumn:
self.table.set_default.append(self)

# index should be applied or dropped irrespective of type change
if ((current_def['index'] and not self.set_index and not self.unique)
or (current_def['unique'] and not self.unique)):
# to drop unique you have to drop index
if (current_def['index'] and not self.set_index):
self.table.drop_index.append(self)

elif (not current_def['index'] and self.set_index) and not (column_type in ('text', 'longtext')):


+ 51
- 1
frappe/tests/test_db_update.py Просмотреть файл

@@ -34,6 +34,52 @@ class TestDBUpdate(unittest.TestCase):
self.assertEqual(fieldtype, table_column.type)
self.assertIn(cstr(table_column.default) or 'NULL', [cstr(default), "'{}'".format(default)])

def test_index_and_unique_constraints(self):
doctype = "User"
frappe.reload_doctype('User', force=True)
frappe.model.meta.trim_tables('User')

make_property_setter(doctype, 'restrict_ip', 'unique', '1', 'Int')
frappe.db.updatedb(doctype)
restrict_ip_in_table = get_table_column("User", "restrict_ip")
self.assertTrue(restrict_ip_in_table.unique)

make_property_setter(doctype, 'restrict_ip', 'unique', '0', 'Int')
frappe.db.updatedb(doctype)
restrict_ip_in_table = get_table_column("User", "restrict_ip")
self.assertFalse(restrict_ip_in_table.unique)

make_property_setter(doctype, 'restrict_ip', 'search_index', '1', 'Int')
frappe.db.updatedb(doctype)
restrict_ip_in_table = get_table_column("User", "restrict_ip")
self.assertTrue(restrict_ip_in_table.index)

make_property_setter(doctype, 'restrict_ip', 'search_index', '0', 'Int')
frappe.db.updatedb(doctype)
restrict_ip_in_table = get_table_column("User", "restrict_ip")
self.assertFalse(restrict_ip_in_table.index)

make_property_setter(doctype, 'restrict_ip', 'search_index', '1', 'Int')
make_property_setter(doctype, 'restrict_ip', 'unique', '1', 'Int')
frappe.db.updatedb(doctype)
restrict_ip_in_table = get_table_column("User", "restrict_ip")
self.assertTrue(restrict_ip_in_table.index)
self.assertTrue(restrict_ip_in_table.unique)

make_property_setter(doctype, 'restrict_ip', 'search_index', '1', 'Int')
make_property_setter(doctype, 'restrict_ip', 'unique', '0', 'Int')
frappe.db.updatedb(doctype)
restrict_ip_in_table = get_table_column("User", "restrict_ip")
self.assertTrue(restrict_ip_in_table.index)
self.assertFalse(restrict_ip_in_table.unique)

make_property_setter(doctype, 'restrict_ip', 'search_index', '0', 'Int')
make_property_setter(doctype, 'restrict_ip', 'unique', '1', 'Int')
frappe.db.updatedb(doctype)
restrict_ip_in_table = get_table_column("User", "restrict_ip")
self.assertFalse(restrict_ip_in_table.index)
self.assertTrue(restrict_ip_in_table.unique)

def get_fieldtype_from_def(field_def):
fieldtuple = frappe.db.type_map.get(field_def.fieldtype, ('', 0))
fieldtype = fieldtuple[0]
@@ -69,4 +115,8 @@ def get_other_fields_meta(meta):
fields = dict(default_fields_map, **optional_fields_map)
field_map = [frappe._dict({'fieldname': field, 'fieldtype': _type, 'length': _length}) for field, (_type, _length) in fields.items()]

return field_map
return field_map

def get_table_column(doctype, fieldname):
table_columns = frappe.db.get_table_columns_description('tab{}'.format(doctype))
return find(table_columns, lambda d: d.get('name') == fieldname)

Загрузка…
Отмена
Сохранить