convertor.py 28 KB

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