You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 
 
 
 

610 lines
18 KiB

  1. # Copyright (c) 2015, Frappe Technologies Pvt. Ltd. and Contributors
  2. # MIT License. See license.txt
  3. from __future__ import unicode_literals
  4. """
  5. Syncs a database table to the `DocType` (metadata)
  6. .. note:: This module is only used internally
  7. """
  8. import re
  9. import os
  10. import frappe
  11. from frappe import _
  12. from frappe.utils import cstr, cint, flt
  13. import MySQLdb
  14. class InvalidColumnName(frappe.ValidationError): pass
  15. varchar_len = '140'
  16. standard_varchar_columns = ('name', 'owner', 'modified_by', 'parent', 'parentfield', 'parenttype')
  17. type_map = {
  18. 'Currency': ('decimal', '18,6')
  19. ,'Int': ('int', '11')
  20. ,'Float': ('decimal', '18,6')
  21. ,'Percent': ('decimal', '18,6')
  22. ,'Check': ('int', '1')
  23. ,'Small Text': ('text', '')
  24. ,'Long Text': ('longtext', '')
  25. ,'Code': ('longtext', '')
  26. ,'Text Editor': ('longtext', '')
  27. ,'Date': ('date', '')
  28. ,'Datetime': ('datetime', '6')
  29. ,'Time': ('time', '6')
  30. ,'Text': ('text', '')
  31. ,'Data': ('varchar', varchar_len)
  32. ,'Link': ('varchar', varchar_len)
  33. ,'Dynamic Link':('varchar', varchar_len)
  34. ,'Password': ('varchar', varchar_len)
  35. ,'Select': ('varchar', varchar_len)
  36. ,'Read Only': ('varchar', varchar_len)
  37. ,'Attach': ('text', '')
  38. ,'Attach Image':('text', '')
  39. }
  40. default_columns = ['name', 'creation', 'modified', 'modified_by', 'owner',
  41. 'docstatus', 'parent', 'parentfield', 'parenttype', 'idx']
  42. optional_columns = ["_user_tags", "_comments", "_assign", "_liked_by"]
  43. default_shortcuts = ['_Login', '__user', '_Full Name', 'Today', '__today', "now", "Now"]
  44. def updatedb(dt, meta=None):
  45. """
  46. Syncs a `DocType` to the table
  47. * creates if required
  48. * updates columns
  49. * updates indices
  50. """
  51. res = frappe.db.sql("select issingle from tabDocType where name=%s", (dt,))
  52. if not res:
  53. raise Exception, 'Wrong doctype "%s" in updatedb' % dt
  54. if not res[0][0]:
  55. tab = DbTable(dt, 'tab', meta)
  56. tab.validate()
  57. frappe.db.commit()
  58. tab.sync()
  59. frappe.db.begin()
  60. class DbTable:
  61. def __init__(self, doctype, prefix = 'tab', meta = None):
  62. self.doctype = doctype
  63. self.name = prefix + doctype
  64. self.columns = {}
  65. self.current_columns = {}
  66. self.meta = meta
  67. if not self.meta:
  68. self.meta = frappe.get_meta(self.doctype)
  69. # lists for change
  70. self.add_column = []
  71. self.change_type = []
  72. self.add_index = []
  73. self.drop_index = []
  74. self.set_default = []
  75. # load
  76. self.get_columns_from_docfields()
  77. def validate(self):
  78. """Check if change in varchar length isn't truncating the columns"""
  79. if self.is_new():
  80. return
  81. self.get_columns_from_db()
  82. columns = [frappe._dict({"fieldname": f, "fieldtype": "Data"}) for f in standard_varchar_columns]
  83. columns += self.columns.values()
  84. for col in columns:
  85. if len(col.fieldname) >= 64:
  86. frappe.throw(_("Fieldname is limited to 64 characters ({0})").format(frappe.bold(col.fieldname)))
  87. if col.fieldtype in type_map and type_map[col.fieldtype][0]=="varchar":
  88. # validate length range
  89. new_length = cint(col.length) or cint(varchar_len)
  90. if not (1 <= new_length <= 255):
  91. frappe.throw(_("Length of {0} should be between 1 and 255").format(col.fieldname))
  92. try:
  93. # check for truncation
  94. max_length = frappe.db.sql("""select max(char_length(`{fieldname}`)) from `tab{doctype}`"""\
  95. .format(fieldname=col.fieldname, doctype=self.doctype))
  96. except MySQLdb.OperationalError, e:
  97. if e.args[0]==1054:
  98. # Unknown column 'column_name' in 'field list'
  99. continue
  100. else:
  101. raise
  102. if max_length and max_length[0][0] > new_length:
  103. current_type = self.current_columns[col.fieldname]["type"]
  104. current_length = re.findall('varchar\(([\d]+)\)', current_type)
  105. if not current_length:
  106. # case when the field is no longer a varchar
  107. continue
  108. current_length = current_length[0]
  109. if col.fieldname in self.columns:
  110. self.columns[col.fieldname].length = current_length
  111. frappe.msgprint(_("Reverting length to {0} for '{1}' in '{2}'; Setting the length as {3} will cause truncation of data.")\
  112. .format(current_length, col.fieldname, self.doctype, new_length))
  113. def sync(self):
  114. if self.is_new():
  115. self.create()
  116. else:
  117. self.alter()
  118. def is_new(self):
  119. return self.name not in DbManager(frappe.db).get_tables_list(frappe.db.cur_db_name)
  120. def create(self):
  121. add_text = ''
  122. # columns
  123. column_defs = self.get_column_definitions()
  124. if column_defs: add_text += ',\n'.join(column_defs) + ',\n'
  125. # index
  126. index_defs = self.get_index_definitions()
  127. if index_defs: add_text += ',\n'.join(index_defs) + ',\n'
  128. # create table
  129. frappe.db.sql("""create table `%s` (
  130. name varchar({varchar_len}) not null primary key,
  131. creation datetime(6),
  132. modified datetime(6),
  133. modified_by varchar({varchar_len}),
  134. owner varchar({varchar_len}),
  135. docstatus int(1) not null default '0',
  136. parent varchar({varchar_len}),
  137. parentfield varchar({varchar_len}),
  138. parenttype varchar({varchar_len}),
  139. idx int(8) not null default '0',
  140. %sindex parent(parent))
  141. ENGINE={engine}
  142. ROW_FORMAT=COMPRESSED
  143. CHARACTER SET=utf8mb4
  144. COLLATE=utf8mb4_unicode_ci""".format(varchar_len=varchar_len,
  145. engine=self.meta.engine or 'InnoDB') % (self.name, add_text))
  146. def get_column_definitions(self):
  147. column_list = [] + default_columns
  148. ret = []
  149. for k in self.columns.keys():
  150. if k not in column_list:
  151. d = self.columns[k].get_definition()
  152. if d:
  153. ret.append('`'+ k+ '` ' + d)
  154. column_list.append(k)
  155. return ret
  156. def get_index_definitions(self):
  157. ret = []
  158. for key, col in self.columns.items():
  159. if col.set_index and not col.unique and col.fieldtype in type_map and \
  160. type_map.get(col.fieldtype)[0] not in ('text', 'longtext'):
  161. ret.append('index `' + key + '`(`' + key + '`)')
  162. return ret
  163. def get_columns_from_docfields(self):
  164. """
  165. get columns from docfields and custom fields
  166. """
  167. fl = frappe.db.sql("SELECT * FROM tabDocField WHERE parent = %s", self.doctype, as_dict = 1)
  168. lengths = {}
  169. precisions = {}
  170. uniques = {}
  171. # optional fields like _comments
  172. if not self.meta.istable:
  173. for fieldname in optional_columns:
  174. fl.append({
  175. "fieldname": fieldname,
  176. "fieldtype": "Text"
  177. })
  178. # add _seen column if track_seen
  179. if getattr(self.meta, 'track_seen', False):
  180. fl.append({
  181. 'fieldname': '_seen',
  182. 'fieldtype': 'Text'
  183. })
  184. if not frappe.flags.in_install_db and frappe.flags.in_install != "frappe":
  185. custom_fl = frappe.db.sql("""\
  186. SELECT * FROM `tabCustom Field`
  187. WHERE dt = %s AND docstatus < 2""", (self.doctype,), as_dict=1)
  188. if custom_fl: fl += custom_fl
  189. # apply length, precision and unique from property setters
  190. for ps in frappe.get_all("Property Setter", fields=["field_name", "property", "value"],
  191. filters={
  192. "doc_type": self.doctype,
  193. "doctype_or_field": "DocField",
  194. "property": ["in", ["precision", "length", "unique"]]
  195. }):
  196. if ps.property=="length":
  197. lengths[ps.field_name] = cint(ps.value)
  198. elif ps.property=="precision":
  199. precisions[ps.field_name] = cint(ps.value)
  200. elif ps.property=="unique":
  201. uniques[ps.field_name] = cint(ps.value)
  202. for f in fl:
  203. self.columns[f['fieldname']] = DbColumn(self, f['fieldname'],
  204. f['fieldtype'], lengths.get(f["fieldname"]) or f.get('length'), f.get('default'), f.get('search_index'),
  205. f.get('options'), uniques.get(f["fieldname"], f.get('unique')), precisions.get(f['fieldname']) or f.get('precision'))
  206. def get_columns_from_db(self):
  207. self.show_columns = frappe.db.sql("desc `%s`" % self.name)
  208. for c in self.show_columns:
  209. self.current_columns[c[0]] = {'name': c[0],
  210. 'type':c[1], 'index':c[3]=="MUL", 'default':c[4], "unique":c[3]=="UNI"}
  211. # GET foreign keys
  212. def get_foreign_keys(self):
  213. fk_list = []
  214. txt = frappe.db.sql("show create table `%s`" % self.name)[0][1]
  215. for line in txt.split('\n'):
  216. if line.strip().startswith('CONSTRAINT') and line.find('FOREIGN')!=-1:
  217. try:
  218. fk_list.append((line.split('`')[3], line.split('`')[1]))
  219. except IndexError:
  220. pass
  221. return fk_list
  222. # Drop foreign keys
  223. def drop_foreign_keys(self):
  224. if not self.drop_foreign_key:
  225. return
  226. fk_list = self.get_foreign_keys()
  227. # make dictionary of constraint names
  228. fk_dict = {}
  229. for f in fk_list:
  230. fk_dict[f[0]] = f[1]
  231. # drop
  232. for col in self.drop_foreign_key:
  233. frappe.db.sql("set foreign_key_checks=0")
  234. frappe.db.sql("alter table `%s` drop foreign key `%s`" % (self.name, fk_dict[col.fieldname]))
  235. frappe.db.sql("set foreign_key_checks=1")
  236. def alter(self):
  237. for col in self.columns.values():
  238. col.build_for_alter_table(self.current_columns.get(col.fieldname, None))
  239. query = []
  240. for col in self.add_column:
  241. query.append("add column `{}` {}".format(col.fieldname, col.get_definition()))
  242. for col in self.change_type:
  243. query.append("change `{}` `{}` {}".format(col.fieldname, col.fieldname, col.get_definition()))
  244. for col in self.add_index:
  245. # if index key not exists
  246. if not frappe.db.sql("show index from `%s` where key_name = %s" %
  247. (self.name, '%s'), col.fieldname):
  248. query.append("add index `{}`(`{}`)".format(col.fieldname, col.fieldname))
  249. for col in self.drop_index:
  250. if col.fieldname != 'name': # primary key
  251. # if index key exists
  252. if frappe.db.sql("""show index from `{0}`
  253. where key_name=%s
  254. and Non_unique=%s""".format(self.name), (col.fieldname, 1 if col.unique else 0)):
  255. query.append("drop index `{}`".format(col.fieldname))
  256. for col in self.set_default:
  257. if col.fieldname=="name":
  258. continue
  259. if col.fieldtype in ("Check", "Int"):
  260. col_default = cint(col.default)
  261. elif col.fieldtype in ("Currency", "Float", "Percent"):
  262. col_default = flt(col.default)
  263. elif not col.default:
  264. col_default = "null"
  265. else:
  266. col_default = '"{}"'.format(col.default.replace('"', '\\"'))
  267. query.append('alter column `{}` set default {}'.format(col.fieldname, col_default))
  268. if query:
  269. try:
  270. frappe.db.sql("alter table `{}` {}".format(self.name, ", ".join(query)))
  271. except Exception, e:
  272. # sanitize
  273. if e.args[0]==1060:
  274. frappe.throw(str(e))
  275. elif e.args[0]==1062:
  276. fieldname = str(e).split("'")[-2]
  277. frappe.throw(_("{0} field cannot be set as unique in {1}, as there are non-unique existing values".format(fieldname, self.name)))
  278. else:
  279. raise e
  280. class DbColumn:
  281. def __init__(self, table, fieldname, fieldtype, length, default,
  282. set_index, options, unique, precision):
  283. self.table = table
  284. self.fieldname = fieldname
  285. self.fieldtype = fieldtype
  286. self.length = length
  287. self.set_index = set_index
  288. self.default = default
  289. self.options = options
  290. self.unique = unique
  291. self.precision = precision
  292. def get_definition(self, with_default=1):
  293. column_def = get_definition(self.fieldtype, precision=self.precision, length=self.length)
  294. if not column_def:
  295. return column_def
  296. if self.fieldtype in ("Check", "Int"):
  297. default_value = cint(self.default) or 0
  298. column_def += ' not null default {0}'.format(default_value)
  299. elif self.fieldtype in ("Currency", "Float", "Percent"):
  300. default_value = flt(self.default) or 0
  301. column_def += ' not null default {0}'.format(default_value)
  302. elif self.default and (self.default not in default_shortcuts) \
  303. and not self.default.startswith(":") and column_def not in ('text', 'longtext'):
  304. column_def += ' default "' + self.default.replace('"', '\"') + '"'
  305. if self.unique and (column_def not in ('text', 'longtext')):
  306. column_def += ' unique'
  307. return column_def
  308. def build_for_alter_table(self, current_def):
  309. column_def = get_definition(self.fieldtype, self.precision, self.length)
  310. # no columns
  311. if not column_def:
  312. return
  313. # to add?
  314. if not current_def:
  315. self.fieldname = validate_column_name(self.fieldname)
  316. self.table.add_column.append(self)
  317. return
  318. # type
  319. if (current_def['type'] != column_def) or \
  320. ((self.unique and not current_def['unique']) and column_def not in ('text', 'longtext')):
  321. self.table.change_type.append(self)
  322. else:
  323. # default
  324. if (self.default_changed(current_def) \
  325. and (self.default not in default_shortcuts) \
  326. and not cstr(self.default).startswith(":") \
  327. and not (column_def in ['text','longtext'])):
  328. self.table.set_default.append(self)
  329. # index should be applied or dropped irrespective of type change
  330. if ( (current_def['index'] and not self.set_index and not self.unique)
  331. or (current_def['unique'] and not self.unique) ):
  332. # to drop unique you have to drop index
  333. self.table.drop_index.append(self)
  334. elif (not current_def['index'] and self.set_index) and not (column_def in ('text', 'longtext')):
  335. self.table.add_index.append(self)
  336. def default_changed(self, current_def):
  337. if "decimal" in current_def['type']:
  338. return self.default_changed_for_decimal(current_def)
  339. else:
  340. return current_def['default'] != self.default
  341. def default_changed_for_decimal(self, current_def):
  342. try:
  343. if current_def['default'] in ("", None) and self.default in ("", None):
  344. # both none, empty
  345. return False
  346. elif current_def['default'] in ("", None):
  347. try:
  348. # check if new default value is valid
  349. float(self.default)
  350. return True
  351. except ValueError:
  352. return False
  353. elif self.default in ("", None):
  354. # new default value is empty
  355. return True
  356. else:
  357. # NOTE float() raise ValueError when "" or None is passed
  358. return float(current_def['default'])!=float(self.default)
  359. except TypeError:
  360. return True
  361. class DbManager:
  362. """
  363. Basically, a wrapper for oft-used mysql commands. like show tables,databases, variables etc...
  364. #TODO:
  365. 0. Simplify / create settings for the restore database source folder
  366. 0a. Merge restore database and extract_sql(from frappe_server_tools).
  367. 1. Setter and getter for different mysql variables.
  368. 2. Setter and getter for mysql variables at global level??
  369. """
  370. def __init__(self,db):
  371. """
  372. Pass root_conn here for access to all databases.
  373. """
  374. if db:
  375. self.db = db
  376. def get_current_host(self):
  377. return self.db.sql("select user()")[0][0].split('@')[1]
  378. def get_variables(self,regex):
  379. """
  380. Get variables that match the passed pattern regex
  381. """
  382. return list(self.db.sql("SHOW VARIABLES LIKE '%s'"%regex))
  383. def get_table_schema(self,table):
  384. """
  385. Just returns the output of Desc tables.
  386. """
  387. return list(self.db.sql("DESC `%s`"%table))
  388. def get_tables_list(self,target=None):
  389. """get list of tables"""
  390. if target:
  391. self.db.use(target)
  392. return [t[0] for t in self.db.sql("SHOW TABLES")]
  393. def create_user(self, user, password, host=None):
  394. #Create user if it doesn't exist.
  395. if not host:
  396. host = self.get_current_host()
  397. if password:
  398. self.db.sql("CREATE USER '%s'@'%s' IDENTIFIED BY '%s';" % (user[:16], host, password))
  399. else:
  400. self.db.sql("CREATE USER '%s'@'%s';" % (user[:16], host))
  401. def delete_user(self, target, host=None):
  402. if not host:
  403. host = self.get_current_host()
  404. try:
  405. self.db.sql("DROP USER '%s'@'%s';" % (target, host))
  406. except Exception, e:
  407. if e.args[0]==1396:
  408. pass
  409. else:
  410. raise
  411. def create_database(self,target):
  412. if target in self.get_database_list():
  413. self.drop_database(target)
  414. self.db.sql("CREATE DATABASE `%s` ;" % target)
  415. def drop_database(self,target):
  416. self.db.sql("DROP DATABASE IF EXISTS `%s`;"%target)
  417. def grant_all_privileges(self, target, user, host=None):
  418. if not host:
  419. host = self.get_current_host()
  420. self.db.sql("GRANT ALL PRIVILEGES ON `%s`.* TO '%s'@'%s';" % (target,
  421. user, host))
  422. def grant_select_privilges(self, db, table, user, host=None):
  423. if not host:
  424. host = self.get_current_host()
  425. if table:
  426. self.db.sql("GRANT SELECT ON %s.%s to '%s'@'%s';" % (db, table, user, host))
  427. else:
  428. self.db.sql("GRANT SELECT ON %s.* to '%s'@'%s';" % (db, user, host))
  429. def flush_privileges(self):
  430. self.db.sql("FLUSH PRIVILEGES")
  431. def get_database_list(self):
  432. """get list of databases"""
  433. return [d[0] for d in self.db.sql("SHOW DATABASES")]
  434. def restore_database(self,target,source,user,password):
  435. from frappe.utils import make_esc
  436. esc = make_esc('$ ')
  437. os.system("mysql -u %s -p%s -h%s %s < %s" % \
  438. (esc(user), esc(password), esc(frappe.db.host), esc(target), source))
  439. def drop_table(self,table_name):
  440. """drop table if exists"""
  441. if not table_name in self.get_tables_list():
  442. return
  443. self.db.sql("DROP TABLE IF EXISTS %s "%(table_name))
  444. def validate_column_name(n):
  445. n = n.replace(' ','_').strip().lower()
  446. special_characters = re.findall("[\W]", n, re.UNICODE)
  447. if special_characters:
  448. special_characters = ", ".join('"{0}"'.format(c) for c in special_characters)
  449. frappe.throw(_("Fieldname {0} cannot have special characters like {1}").format(cstr(n), special_characters), InvalidColumnName)
  450. return n
  451. def remove_all_foreign_keys():
  452. frappe.db.sql("set foreign_key_checks = 0")
  453. frappe.db.commit()
  454. for t in frappe.db.sql("select name from tabDocType where issingle=0"):
  455. dbtab = DbTable(t[0])
  456. try:
  457. fklist = dbtab.get_foreign_keys()
  458. except Exception, e:
  459. if e.args[0]==1146:
  460. fklist = []
  461. else:
  462. raise
  463. for f in fklist:
  464. frappe.db.sql("alter table `tab%s` drop foreign key `%s`" % (t[0], f[1]))
  465. def get_definition(fieldtype, precision=None, length=None):
  466. d = type_map.get(fieldtype)
  467. if not d:
  468. return
  469. coltype = d[0]
  470. size = None
  471. if d[1]:
  472. size = d[1]
  473. if size:
  474. if fieldtype in ["Float", "Currency", "Percent"] and cint(precision) > 6:
  475. size = '21,9'
  476. if coltype == "varchar" and length:
  477. size = length
  478. if size is not None:
  479. coltype = "{coltype}({size})".format(coltype=coltype, size=size)
  480. return coltype
  481. def add_column(doctype, column_name, fieldtype, precision=None):
  482. if column_name in frappe.db.get_table_columns(doctype):
  483. # already exists
  484. return
  485. frappe.db.commit()
  486. frappe.db.sql("alter table `tab%s` add column %s %s" % (doctype,
  487. column_name, get_definition(fieldtype, precision)))