Non puoi selezionare più di 25 argomenti Gli argomenti devono iniziare con una lettera o un numero, possono includere trattini ('-') e possono essere lunghi fino a 35 caratteri.
 
 
 
 
 
 

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