convertor.py 23 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798
  1. # encoding=utf8
  2. """芋道系统数据库迁移工具
  3. Author: dhb52 (https://gitee.com/dhb52)
  4. pip install simple-ddl-parser
  5. """
  6. import argparse
  7. import pathlib
  8. import re
  9. import time
  10. from abc import ABC, abstractmethod
  11. from typing import Dict, Generator, Optional, Tuple, Union
  12. from simple_ddl_parser import DDLParser
  13. PREAMBLE = """/*
  14. Yudao Database Transfer Tool
  15. Source Server Type : MySQL
  16. Target Server Type : {db_type}
  17. Date: {date}
  18. */
  19. """
  20. def load_and_clean(sql_file: str) -> str:
  21. """加载源 SQL 文件,并清理内容方便下一步 ddl 解析
  22. Args:
  23. sql_file (str): sql文件路径
  24. Returns:
  25. str: 清理后的sql文件内容
  26. """
  27. REPLACE_PAIR_LIST = (
  28. (" CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci ", " "),
  29. (" KEY `", " INDEX `"),
  30. ("UNIQUE INDEX", "UNIQUE KEY"),
  31. ("b'0'", "'0'"),
  32. ("b'1'", "'1'"),
  33. )
  34. content = open(sql_file).read()
  35. for replace_pair in REPLACE_PAIR_LIST:
  36. content = content.replace(*replace_pair)
  37. content = re.sub(r"ENGINE.*COMMENT", "COMMENT", content)
  38. content = re.sub(r"ENGINE.*;", ";", content)
  39. return content
  40. class Convertor(ABC):
  41. def __init__(self, src: str, db_type) -> None:
  42. self.src = src
  43. self.db_type = db_type
  44. self.content = load_and_clean(self.src)
  45. self.table_script_list = re.findall(r"CREATE TABLE [^;]*;", self.content)
  46. @abstractmethod
  47. def translate_type(self, type: str, size: Optional[Union[int, Tuple[int]]]) -> str:
  48. """字段类型转换
  49. Args:
  50. type (str): 字段类型
  51. size (Optional[Union[int, Tuple[int]]]): 字段长度描述, 如varchar(255), decimal(10,2)
  52. Returns:
  53. str: 类型定义
  54. """
  55. pass
  56. @abstractmethod
  57. def gen_create(self, table_ddl: Dict) -> str:
  58. """生成 create 脚本
  59. Args:
  60. table_ddl (Dict): 表DDL
  61. Returns:
  62. str: 生成脚本
  63. """
  64. pass
  65. @abstractmethod
  66. def gen_pk(self, table_name: str) -> str:
  67. """生成主键定义
  68. Args:
  69. table_name (str): 表名
  70. Returns:
  71. str: 生成脚本
  72. """
  73. pass
  74. @abstractmethod
  75. def gen_index(self, ddl: Dict) -> str:
  76. """生成索引定义
  77. Args:
  78. table_ddl (Dict): 表DDL
  79. Returns:
  80. str: 生成脚本
  81. """
  82. pass
  83. @abstractmethod
  84. def gen_comment(self, table_sql: str, table_name: str) -> str:
  85. """生成字段/表注释
  86. Args:
  87. table_sql (str): 原始表SQL
  88. table_name (str): 表名
  89. Returns:
  90. str: 生成脚本
  91. """
  92. pass
  93. @abstractmethod
  94. def gen_insert(self, table_name: str) -> str:
  95. """生成 insert 语句块
  96. Args:
  97. table_name (str): 表名
  98. Returns:
  99. str: 生成脚本
  100. """
  101. pass
  102. def gen_dual(self) -> str:
  103. """生成虚拟 dual 表
  104. Returns:
  105. str: 生成脚本, 默认返回空脚本, 表示当前数据库无需手工创建
  106. """
  107. return ""
  108. @staticmethod
  109. def inserts(table_name: str, script_content: str) -> Generator:
  110. PREFIX = f"INSERT INTO `{table_name}`"
  111. # 收集 `table_name` 对应的 insert 语句
  112. for line in script_content.split("\n"):
  113. if line.startswith(PREFIX):
  114. head, tail = line.replace(PREFIX, "").split(" VALUES ", maxsplit=1)
  115. head = head.strip().replace("`", "").lower()
  116. tail = tail.strip().replace(r"\"", '"')
  117. # tail = tail.replace("b'0'", "'0'").replace("b'1'", "'1'")
  118. yield f"INSERT INTO {table_name.lower()} {head} VALUES {tail}"
  119. @staticmethod
  120. def index(ddl: Dict) -> Generator:
  121. """生成索引定义
  122. Args:
  123. ddl (Dict): 表DDL
  124. Yields:
  125. Generator[str]: create index 语句
  126. """
  127. def generate_columns(columns):
  128. keys = [
  129. f"{col['name'].lower()}{' ' + col['order'].lower() if col['order'] != 'ASC' else ''}"
  130. for col in columns[0]
  131. ]
  132. return ", ".join(keys)
  133. for no, index in enumerate(ddl["index"], 1):
  134. columns = generate_columns(index["columns"])
  135. table_name = ddl["table_name"].lower()
  136. yield f"CREATE INDEX idx_{table_name}_{no:02d} ON {table_name} ({columns})"
  137. @staticmethod
  138. def filed_comments(table_sql: str) -> Generator:
  139. for line in table_sql.split("\n"):
  140. match = re.match(r"^`([^`]+)`.* COMMENT '([^']+)'", line.strip())
  141. if match:
  142. field = match.group(1)
  143. comment_string = match.group(2).replace("\\n", "\n")
  144. yield field, comment_string
  145. def table_comment(self, table_sql: str) -> str:
  146. match = re.search(r"COMMENT \= '([^']+)';", table_sql)
  147. return match.group(1) if match else None
  148. def print(self):
  149. """打印转换后的sql脚本到终端"""
  150. print(
  151. PREAMBLE.format(
  152. db_type=self.db_type,
  153. date=time.strftime("%Y-%m-%d %H:%M:%S"),
  154. )
  155. )
  156. dual = self.gen_dual()
  157. if dual:
  158. print(
  159. f"""-- ----------------------------
  160. -- Table structure for dual
  161. -- ----------------------------
  162. {dual}
  163. """
  164. )
  165. error_scripts = []
  166. for table_sql in self.table_script_list:
  167. ddl = DDLParser(table_sql.replace("`", "")).run()
  168. # 如果parse失败, 需要跟进
  169. if len(ddl) == 0:
  170. error_scripts.append(table_sql)
  171. continue
  172. table_ddl = ddl[0]
  173. table_name = table_ddl["table_name"]
  174. # 忽略 quartz 的内容
  175. if table_name.lower().startswith("qrtz"):
  176. continue
  177. # 为每个表生成个5个基本部分
  178. create = self.gen_create(table_ddl)
  179. pk = self.gen_pk(table_name)
  180. index = self.gen_index(table_ddl)
  181. comment = self.gen_comment(table_sql, table_name)
  182. inserts = self.gen_insert(table_name)
  183. # 组合当前表的DDL脚本
  184. script = f"""{create}
  185. {pk}
  186. {index}
  187. {comment}
  188. {inserts}
  189. """
  190. # 清理
  191. script = re.sub("\n{3,}", "\n\n", script).strip() + "\n"
  192. print(script)
  193. # 将parse失败的脚本打印出来
  194. if error_scripts:
  195. for script in error_scripts:
  196. print(script)
  197. class PostgreSQLConvertor(Convertor):
  198. def __init__(self, src):
  199. super().__init__(src, "PostgreSQL")
  200. def translate_type(self, type: str, size: Optional[Union[int, Tuple[int]]]):
  201. """类型转换"""
  202. type = type.lower()
  203. if type == "varchar":
  204. return f"varchar({size})"
  205. if type == "int":
  206. return "int4"
  207. if type == "bigint" or type == "bigint unsigned":
  208. return "int8"
  209. if type == "datetime":
  210. return "timestamp"
  211. if type == "bit":
  212. return "bool"
  213. if type in ("tinyint", "smallint"):
  214. return "int2"
  215. if type == "text":
  216. return "text"
  217. if type in ("blob", "mediumblob"):
  218. return "bytea"
  219. if type == "decimal":
  220. return (
  221. f"numeric({','.join(str(s) for s in size)})" if len(size) else "numeric"
  222. )
  223. def gen_create(self, ddl: Dict) -> str:
  224. """生成 create"""
  225. def _generate_column(col):
  226. name = col["name"].lower()
  227. if name == "deleted":
  228. return "deleted int2 NOT NULL DEFAULT 0"
  229. type = col["type"].lower()
  230. full_type = self.translate_type(type, col["size"])
  231. nullable = "NULL" if col["nullable"] else "NOT NULL"
  232. default = f"DEFAULT {col['default']}" if col["default"] is not None else ""
  233. return f"{name} {full_type} {nullable} {default}"
  234. table_name = ddl["table_name"].lower()
  235. columns = [f"{_generate_column(col).strip()}" for col in ddl["columns"]]
  236. filed_def_list = ",\n ".join(columns)
  237. script = f"""-- ----------------------------
  238. -- Table structure for {table_name}
  239. -- ----------------------------
  240. DROP TABLE IF EXISTS {table_name};
  241. CREATE TABLE {table_name} (
  242. {filed_def_list}
  243. );"""
  244. return script
  245. def gen_index(self, ddl: Dict) -> str:
  246. return "\n".join(f"{script};" for script in self.index(ddl))
  247. def gen_comment(self, table_sql: str, table_name: str) -> str:
  248. """生成字段及表的注释"""
  249. script = ""
  250. for field, comment_string in self.filed_comments(table_sql):
  251. script += (
  252. f"COMMENT ON COLUMN {table_name}.{field} IS '{comment_string}';" + "\n"
  253. )
  254. table_comment = self.table_comment(table_sql)
  255. if table_comment:
  256. script += f"COMMENT ON TABLE {table_name} IS '{table_comment}';\n"
  257. return script
  258. def gen_pk(self, table_name) -> str:
  259. """生成主键定义"""
  260. return f"ALTER TABLE {table_name} ADD CONSTRAINT pk_{table_name} PRIMARY KEY (id);\n"
  261. def gen_insert(self, table_name: str) -> str:
  262. """生成 insert 语句,以及根据最后的 insert id+1 生成 Sequence"""
  263. inserts = list(Convertor.inserts(table_name, self.content))
  264. ## 生成 insert 脚本
  265. script = ""
  266. last_id = 0
  267. if inserts:
  268. inserts_lines = "\n".join(inserts)
  269. script += f"""\n\n-- ----------------------------
  270. -- Records of {table_name.lower()}
  271. -- ----------------------------
  272. -- @formatter:off
  273. BEGIN;
  274. {inserts_lines}
  275. COMMIT;
  276. -- @formatter:on"""
  277. match = re.search(r"VALUES \((\d+),", inserts[-1])
  278. if match:
  279. last_id = int(match.group(1))
  280. # 生成 Sequence
  281. script += (
  282. "\n\n"
  283. + f"""DROP SEQUENCE IF EXISTS {table_name}_seq;
  284. CREATE SEQUENCE {table_name}_seq
  285. START {last_id + 1};"""
  286. )
  287. return script
  288. def gen_dual(self) -> str:
  289. return """DROP TABLE IF EXISTS dual;
  290. CREATE TABLE dual
  291. (
  292. id int2
  293. );
  294. COMMENT ON TABLE dual IS '数据库连接的表';
  295. -- ----------------------------
  296. -- Records of dual
  297. -- ----------------------------
  298. -- @formatter:off
  299. INSERT INTO dual VALUES (1);
  300. -- @formatter:on"""
  301. class OracleConvertor(Convertor):
  302. def __init__(self, src):
  303. super().__init__(src, "Oracle")
  304. def translate_type(self, type: str, size: Optional[Union[int, Tuple[int]]]):
  305. """类型转换"""
  306. type = type.lower()
  307. if type == "varchar":
  308. return f"varchar2({size if size < 4000 else 4000})"
  309. if type == "int":
  310. return "number"
  311. if type == "bigint" or type == "bigint unsigned":
  312. return "number"
  313. if type == "datetime":
  314. return "date"
  315. if type == "bit":
  316. return "number(1,0)"
  317. if type in ("tinyint", "smallint"):
  318. return "smallint"
  319. if type == "text":
  320. return "clob"
  321. if type in ("blob", "mediumblob"):
  322. return "blob"
  323. if type == "decimal":
  324. return (
  325. f"number({','.join(str(s) for s in size)})" if len(size) else "number"
  326. )
  327. def gen_create(self, ddl) -> str:
  328. """生成 CREATE 语句"""
  329. def generate_column(col):
  330. name = col["name"].lower()
  331. if name == "deleted":
  332. return "deleted number(1,0) DEFAULT 0 NOT NULL"
  333. type = col["type"].lower()
  334. full_type = self.translate_type(type, col["size"])
  335. nullable = "NULL" if col["nullable"] else "NOT NULL"
  336. default = f"DEFAULT {col['default']}" if col["default"] is not None else ""
  337. # Oracle 中 size 不能作为字段名
  338. field_name = '"size"' if name == "size" else name
  339. # Oracle DEFAULT 定义在 NULLABLE 之前
  340. return f"{field_name} {full_type} {default} {nullable}"
  341. table_name = ddl["table_name"].lower()
  342. columns = [f"{generate_column(col).strip()}" for col in ddl["columns"]]
  343. field_def_list = ",\n ".join(columns)
  344. script = f"""-- ----------------------------
  345. -- Table structure for {table_name}
  346. -- ----------------------------
  347. CREATE TABLE {table_name} (
  348. {field_def_list}
  349. );"""
  350. # oracle INSERT '' 不能通过 NOT NULL 校验
  351. script = script.replace("DEFAULT '' NOT NULL", "DEFAULT '' NULL")
  352. return script
  353. def gen_index(self, ddl: Dict) -> str:
  354. return "\n".join(f"{script};" for script in self.index(ddl))
  355. def gen_comment(self, table_sql: str, table_name: str) -> str:
  356. script = ""
  357. for field, comment_string in self.filed_comments(table_sql):
  358. script += (
  359. f"COMMENT ON COLUMN {table_name}.{field} IS '{comment_string}';" + "\n"
  360. )
  361. table_comment = self.table_comment(table_sql)
  362. if table_comment:
  363. script += f"COMMENT ON TABLE {table_name} IS '{table_comment}';\n"
  364. return script
  365. def gen_pk(self, table_name: str) -> str:
  366. """生成主键定义"""
  367. return f"ALTER TABLE {table_name} ADD CONSTRAINT pk_{table_name} PRIMARY KEY (id);\n"
  368. def gen_index(self, ddl: Dict) -> str:
  369. return "\n".join(f"{script};" for script in self.index(ddl))
  370. def gen_insert(self, table_name: str) -> str:
  371. """拷贝 INSERT 语句"""
  372. inserts = []
  373. for insert_script in Convertor.inserts(table_name, self.content):
  374. # 对日期数据添加 TO_DATE 转换
  375. insert_script = re.sub(
  376. r"('\d{4}-\d{2}-\d{2} \d{2}:\d{2}:\d{2}')",
  377. r"to_date(\g<1>, 'SYYYY-MM-DD HH24:MI:SS')",
  378. insert_script,
  379. )
  380. inserts.append(insert_script)
  381. ## 生成 insert 脚本
  382. script = ""
  383. last_id = 0
  384. if inserts:
  385. inserts_lines = "\n".join(inserts)
  386. script += f"""\n\n-- ----------------------------
  387. -- Records of {table_name.lower()}
  388. -- ----------------------------
  389. -- @formatter:off
  390. {inserts_lines}
  391. COMMIT;
  392. -- @formatter:on"""
  393. match = re.search(r"VALUES \((\d+),", inserts[-1])
  394. if match:
  395. last_id = int(match.group(1))
  396. # 生成 Sequence
  397. script += f"""
  398. CREATE SEQUENCE {table_name}_seq
  399. START WITH {last_id + 1};"""
  400. return script
  401. class SQLServerConvertor(Convertor):
  402. """_summary_
  403. Args:
  404. Convertor (_type_): _description_
  405. """
  406. def __init__(self, src):
  407. super().__init__(src, "Microsoft SQL Server")
  408. def translate_type(self, type: str, size: Optional[Union[int, Tuple[int]]]):
  409. """类型转换"""
  410. type = type.lower()
  411. if type == "varchar":
  412. return f"nvarchar({size if size < 4000 else 4000})"
  413. if type == "int":
  414. return "int"
  415. if type == "bigint" or type == "bigint unsigned":
  416. return "bigint"
  417. if type == "datetime":
  418. return "datetime2"
  419. if type == "bit":
  420. return "varchar(1)"
  421. if type in ("tinyint", "smallint"):
  422. return "tinyint"
  423. if type == "text":
  424. return "nvarchar(max)"
  425. if type in ("blob", "mediumblob"):
  426. return "varbinary(max)"
  427. if type == "decimal":
  428. return (
  429. f"numeric({','.join(str(s) for s in size)})" if len(size) else "numeric"
  430. )
  431. def gen_create(self, ddl: Dict) -> str:
  432. """生成 create"""
  433. def _generate_column(col):
  434. name = col["name"].lower()
  435. if name == "id":
  436. return "id bigint NOT NULL PRIMARY KEY IDENTITY"
  437. if name == "deleted":
  438. return "deleted bit DEFAULT 0 NOT NULL"
  439. type = col["type"].lower()
  440. full_type = self.translate_type(type, col["size"])
  441. nullable = "NULL" if col["nullable"] else "NOT NULL"
  442. default = f"DEFAULT {col['default']}" if col["default"] is not None else ""
  443. return f"{name} {full_type} {default} {nullable}"
  444. table_name = ddl["table_name"].lower()
  445. columns = [f"{_generate_column(col).strip()}" for col in ddl["columns"]]
  446. filed_def_list = ",\n ".join(columns)
  447. script = f"""-- ----------------------------
  448. -- Table structure for {table_name}
  449. -- ----------------------------
  450. DROP TABLE IF EXISTS {table_name}
  451. GO
  452. CREATE TABLE {table_name} (
  453. {filed_def_list}
  454. )
  455. GO"""
  456. return script
  457. def gen_comment(self, table_sql: str, table_name: str) -> str:
  458. """生成字段及表的注释"""
  459. script = ""
  460. for field, comment_string in self.filed_comments(table_sql):
  461. script += f"""EXEC sp_addextendedproperty
  462. 'MS_Description', N'{comment_string}',
  463. 'SCHEMA', N'dbo',
  464. 'TABLE', N'{table_name}',
  465. 'COLUMN', N'{field}'
  466. GO
  467. """
  468. table_comment = self.table_comment(table_sql)
  469. if table_comment:
  470. script += f"""EXEC sp_addextendedproperty
  471. 'MS_Description', N'{table_comment}',
  472. 'SCHEMA', N'dbo',
  473. 'TABLE', N'{table_name}'
  474. GO
  475. """
  476. return script
  477. def gen_pk(self, table_name: str) -> str:
  478. """生成主键定义"""
  479. return ""
  480. def gen_index(self, ddl: Dict) -> str:
  481. """生成 index"""
  482. return "\n".join(f"{script}\nGO" for script in self.index(ddl))
  483. def gen_insert(self, table_name: str) -> str:
  484. """生成 insert 语句"""
  485. # 收集 `table_name` 对应的 insert 语句
  486. inserts = []
  487. for insert_script in Convertor.inserts(table_name, self.content):
  488. # SQLServer: 字符串前加N,hack,是否存在替换字符串内容的风险
  489. insert_script = insert_script.replace(", '", ", N'").replace(
  490. "VALUES ('", "VALUES (N')"
  491. )
  492. # 删除 insert 的结尾分号
  493. insert_script = re.sub(";$", r"\nGO", insert_script)
  494. inserts.append(insert_script)
  495. ## 生成 insert 脚本
  496. script = ""
  497. if inserts:
  498. inserts_lines = "\n".join(inserts)
  499. script += f"""\n\n-- ----------------------------
  500. -- Records of {table_name.lower()}
  501. -- ----------------------------
  502. -- @formatter:off
  503. BEGIN TRANSACTION
  504. GO
  505. SET IDENTITY_INSERT {table_name.lower()} ON
  506. GO
  507. {inserts_lines}
  508. SET IDENTITY_INSERT {table_name.lower()} OFF
  509. GO
  510. COMMIT
  511. GO
  512. -- @formatter:on"""
  513. return script
  514. def gen_dual(self) -> str:
  515. return """DROP TABLE IF EXISTS dual
  516. GO
  517. CREATE TABLE dual
  518. (
  519. id int
  520. )
  521. GO
  522. EXEC sp_addextendedproperty
  523. 'MS_Description', N'数据库连接的表',
  524. 'SCHEMA', N'dbo',
  525. 'TABLE', N'dual'
  526. GO
  527. -- ----------------------------
  528. -- Records of dual
  529. -- ----------------------------
  530. -- @formatter:off
  531. INSERT INTO dual VALUES (1)
  532. GO
  533. -- @formatter:on"""
  534. class DM8Convertor(Convertor):
  535. def __init__(self, src):
  536. super().__init__(src, "DM8")
  537. def translate_type(self, type: str, size: Optional[Union[int, Tuple[int]]]):
  538. """类型转换"""
  539. type = type.lower()
  540. if type == "varchar":
  541. return f"varchar({size})"
  542. if type == "int":
  543. return "int"
  544. if type == "bigint" or type == "bigint unsigned":
  545. return "bigint"
  546. if type == "datetime":
  547. return "datetime"
  548. if type == "bit":
  549. return "bit"
  550. if type in ("tinyint", "smallint"):
  551. return "smallint"
  552. if type == "text":
  553. return "text"
  554. if type == "blob":
  555. return "blob"
  556. if type == "mediumblob":
  557. return "varchar(10240)"
  558. if type == "decimal":
  559. return (
  560. f"decimal({','.join(str(s) for s in size)})" if len(size) else "decimal"
  561. )
  562. def gen_create(self, ddl) -> str:
  563. """生成 CREATE 语句"""
  564. def generate_column(col):
  565. name = col["name"].lower()
  566. if name == "id":
  567. return "id bigint NOT NULL PRIMARY KEY IDENTITY"
  568. type = col["type"].lower()
  569. full_type = self.translate_type(type, col["size"])
  570. nullable = "NULL" if col["nullable"] else "NOT NULL"
  571. default = f"DEFAULT {col['default']}" if col["default"] is not None else ""
  572. return f"{name} {full_type} {default} {nullable}"
  573. table_name = ddl["table_name"].lower()
  574. columns = [f"{generate_column(col).strip()}" for col in ddl["columns"]]
  575. field_def_list = ",\n ".join(columns)
  576. script = f"""-- ----------------------------
  577. -- Table structure for {table_name}
  578. -- ----------------------------
  579. CREATE TABLE {table_name} (
  580. {field_def_list}
  581. );"""
  582. # oracle INSERT '' 不能通过 NOT NULL 校验
  583. script = script.replace("DEFAULT '' NOT NULL", "DEFAULT '' NULL")
  584. return script
  585. def gen_index(self, ddl: Dict) -> str:
  586. return "\n".join(f"{script};" for script in self.index(ddl))
  587. def gen_comment(self, table_sql: str, table_name: str) -> str:
  588. script = ""
  589. for field, comment_string in self.filed_comments(table_sql):
  590. script += (
  591. f"COMMENT ON COLUMN {table_name}.{field} IS '{comment_string}';" + "\n"
  592. )
  593. table_comment = self.table_comment(table_sql)
  594. if table_comment:
  595. script += f"COMMENT ON TABLE {table_name} IS '{table_comment}';\n"
  596. return script
  597. def gen_pk(self, table_name: str) -> str:
  598. """生成主键定义"""
  599. return ""
  600. def gen_index(self, ddl: Dict) -> str:
  601. return "\n".join(f"{script};" for script in self.index(ddl))
  602. def gen_insert(self, table_name: str) -> str:
  603. """拷贝 INSERT 语句"""
  604. inserts = list(Convertor.inserts(table_name, self.content))
  605. ## 生成 insert 脚本
  606. script = ""
  607. if inserts:
  608. inserts_lines = "\n".join(inserts)
  609. script += f"""\n\n-- ----------------------------
  610. -- Records of {table_name.lower()}
  611. -- ----------------------------
  612. -- @formatter:off
  613. SET IDENTITY_INSERT {table_name.lower()} ON;
  614. {inserts_lines}
  615. COMMIT;
  616. SET IDENTITY_INSERT {table_name.lower()} OFF;
  617. -- @formatter:on"""
  618. return script
  619. def main():
  620. parser = argparse.ArgumentParser(description="芋道系统数据库转换工具")
  621. parser.add_argument(
  622. "type",
  623. type=str,
  624. help="目标数据库类型",
  625. choices=["postgres", "oracle", "sqlserver", "dm8"],
  626. )
  627. args = parser.parse_args()
  628. sql_file = pathlib.Path("../mysql/ruoyi-vue-pro.sql").resolve().as_posix()
  629. convertor = None
  630. if args.type == "postgres":
  631. convertor = PostgreSQLConvertor(sql_file)
  632. elif args.type == "oracle":
  633. convertor = OracleConvertor(sql_file)
  634. elif args.type == "sqlserver":
  635. convertor = SQLServerConvertor(sql_file)
  636. elif args.type == "dm8":
  637. convertor = DM8Convertor(sql_file)
  638. else:
  639. raise NotImplementedError(f"不支持目标数据库类型: {args.type}")
  640. convertor.print()
  641. if __name__ == "__main__":
  642. main()