开心一刻 今天坐沙发上看电视,旁边的老婆拿着手机贴了过来 老婆:老公,这次出门旅游,机票我准备买了哈 我:嗯 老婆:你、我、你爸妈、我爸妈,一共六张票 老婆:这上面还有意外保险,要不要买? 我:都特么团灭了,还买啥保险? 异构数据源同步 概念介绍 数据源,不只是包含关系型数据库,还包括 NoSQL、
今天坐沙发上看电视,旁边的老婆拿着手机贴了过来
老婆:老公,这次出门旅游,机票我准备买了哈
我:嗯
老婆:你、我、你爸妈、我爸妈,一共六张票
老婆:这上面还有意外保险,要不要买?
我:都特么团灭了,还买啥保险?
所以,异构数据源同步就是指在不同类型或格式的数据源之间传输和同步数据的过程
主要有两种同步策略:
离线同步
与
实时同步
,各有其特点和适用场景
但是,这些我今天都不讲,就吊吊你们胃口
如果你们想了解,自己去查吧
今天我就要逆袭一把,将
离线同步
中的一个小配角转正成主角!
在
异构数据源同步
整个主线剧情中,
数据同步
才是真正的主角
而
表结构同步
只能算活不过三集的那种配角
但今天不拍主线剧情,我要拍个番外篇来重点讲
表结构同步
,我是导演嘛,当然我说了算
主要是针对关系型数据库,当目标数据源的表不存在时,则先在目标数据源创建目标表,然后进行数据的同步
比如:从
MySQL
的表
tbl_t1
同步到
SQL Server
的表
tbl_tt
,若
tbl_tt
不存在,则根据
tbl_t1
的表结构创建
tbl_tt
所以这里就涉及到表结构的同步,也正是本文的主角!
通过
jdbc
来实现,具体实现步骤如下
通过
jdbc
获取元数据信息:表元数据、列元数据、主键元数据、索引元数据
根据元数据拼接目标表的建表 SQL
通过
jdbc
,根据建表 SQL,在目标数据源创建目标表
第 3 步实现比较容易,难得是第 1、2步
虽然前路坑很多,但你们不要慌,我已经替你们趟掉很多了
我们以
MySQL
为例,假设我们库
test
下有表
tbl_sync
CREATE TABLE `tbl_sync` (
`c_bigint_auto` bigint unsigned NOT NULL AUTO_INCREMENT COMMENT 'bigint 类型',
`c_bigint` bigint DEFAULT NULL COMMENT 'bigint 类型',
`c_vachar` varchar(100) NOT NULL COMMENT 'varchar 类型',
`c_char` char(32) NOT NULL COMMENT 'char 类型',
`c_text` text NOT NULL COMMENT 'text 类型',
`c_decimal_4` decimal(15,4) NOT NULL DEFAULT '5000.0000' COMMENT 'decimal 类型',
`c_decimal_0` decimal(10,0) DEFAULT NULL COMMENT 'decimal 类型',
`c_blob` blob COMMENT 'blob 类型',
`c_bit` bit(1) DEFAULT NULL COMMENT 'bit 类型',
`c_tinyint` tinyint DEFAULT NULL COMMENT 'tinyint 类型',
`c_binary` binary(10) DEFAULT NULL COMMENT 'binary 类型',
`c_float` float(13,0) DEFAULT NULL COMMENT 'float 类型',
`c_double` double(23,0) DEFAULT NULL COMMENT 'double 类型',
`c_varbinary` varbinary(20) DEFAULT NULL COMMENT 'varbinary 类型',
`c_longblob` longblob COMMENT 'longblob 类型',
`c_longtext` longtext COMMENT 'longtext 类型',
`c_json` json DEFAULT NULL COMMENT 'json 类型',
`c_date` date DEFAULT NULL COMMENT 'date 类型',
`c_time` time(2) DEFAULT NULL COMMENT 'time 类型',
`c_datetime` datetime(3) DEFAULT NULL COMMENT 'datetime 类型',
`c_timestamp` timestamp(4) NULL DEFAULT NULL COMMENT 'timestamp 类型',
`c_year` year DEFAULT NULL COMMENT 'year 类型',
PRIMARY KEY (`c_vachar`,`c_char`,`c_bigint_auto`),
UNIQUE KEY `uk_id` (`c_bigint_auto`),
KEY `idx_name_salary` (`c_vachar`,`c_decimal_4`)
) COMMENT='包含各种类型列的同步表';
现在需要将其同步到另一个
MySQL
库
obj_db
中
表的元信息比较少,包括表名、表类型、表说明(表注释)等,其他的,类似字符集、排序规则等,就继承数据库的
表名,我想你们都知道,也就是对应上面的
tbl_sync
表说明(表注释)你们肯定也知道,对应上面的
包含各种类型列的同步表
那表类型是什么,你们还知道吗?
我们通常说的表是狭义上的表,也就是
基本表
,是最常见的表类型,用于存储具有明确定义的列和数据类型的数据
tbl_sync
就是
基本表
,但广义上的表还包括
视图
、
临时表
、
系统表
等等
下文都是基于
基本表
,大家需要注意这个前提
通过 jdbc 获取 表元数据,非常简单,直接看代码
Connection connection = dataSource.getConnection();
DatabaseMetaData databaseMetaData = connection.getMetaData();
ResultSet tableResultSet = databaseMetaData.getTables(connection.getCatalog(), connection.getSchema(),
"tbl_sync", new String[]{"TABLE"});
while (tableResultSet.next()) {
System.out.println("tableCatalog = " + tableResultSet.getString("TABLE_CAT"));
System.out.println("tableSchema = " + tableResultSet.getString("TABLE_SCHEM"));
System.out.println("tableName = " + tableResultSet.getString("TABLE_NAME"));
System.out.println("tableType = " + tableResultSet.getString("TABLE_TYPE"));
System.out.println("remarks = " + tableResultSet.getString("REMARKS"));
}
输出结果
tableCatalog = test
tableSchema = null
tableName = tbl_sync
tableType = TABLE
remarks = 包含各种类型列的同步表
一般我们只需要关注:
TABLE_NAME
、
TABLE_TYPE
、
REMARKS
我们看下
java.sql.DatabaseMetaData#getTables
说明
/**
* Retrieves a description of the tables available in the given catalog.
* Only table descriptions matching the catalog, schema, table
* name and type criteria are returned. They are ordered by
* TABLE_TYPE
, TABLE_CAT
,
* TABLE_SCHEM
and TABLE_NAME
.
*
* Each table description has the following columns:
*
* - TABLE_CAT String {@code =>} table catalog (may be
null
)
* - TABLE_SCHEM String {@code =>} table schema (may be
null
)
* - TABLE_NAME String {@code =>} table name
*
- TABLE_TYPE String {@code =>} table type. Typical types are "TABLE",
* "VIEW", "SYSTEM TABLE", "GLOBAL TEMPORARY",
* "LOCAL TEMPORARY", "ALIAS", "SYNONYM".
*
- REMARKS String {@code =>} explanatory comment on the table
*
- TYPE_CAT String {@code =>} the types catalog (may be
null
)
* - TYPE_SCHEM String {@code =>} the types schema (may be
null
)
* - TYPE_NAME String {@code =>} type name (may be
null
)
* - SELF_REFERENCING_COL_NAME String {@code =>} name of the designated
* "identifier" column of a typed table (may be
null
)
* - REF_GENERATION String {@code =>} specifies how values in
* SELF_REFERENCING_COL_NAME are created. Values are
* "SYSTEM", "USER", "DERIVED". (may be
null
)
*
*
* Note: Some databases may not return information for
* all tables.
*
* @param catalog a catalog name; must match the catalog name as it
* is stored in the database; "" retrieves those without a catalog;
* null
means that the catalog name should not be used to narrow
* the search
* @param schemaPattern a schema name pattern; must match the schema name
* as it is stored in the database; "" retrieves those without a schema;
* null
means that the schema name should not be used to narrow
* the search
* @param tableNamePattern a table name pattern; must match the
* table name as it is stored in the database
* @param types a list of table types, which must be from the list of table types
* returned from {@link #getTableTypes},to include; null
returns
* all types
* @return ResultSet
- each row is a table description
* @exception SQLException if a database access error occurs
* @see #getSearchStringEscape
*/
相信你们都能看懂,我只强调下
TABLE_TYPE
其值包括
列元信息比较多一点,包括列名、列类型、列类型名、是否自增、是否允许NULL、列大小、小数位数、默认值、列说明(列注释)等
通过 jdbc 获取 列元数据 也很简单,直接看代码
Connection connection = dataSource.getConnection();
DatabaseMetaData databaseMetaData = connection.getMetaData();
ResultSet columnResultSet = databaseMetaData.getColumns(connection.getCatalog(), connection.getSchema(),
"tbl_sync", null);
while (columnResultSet.next()) {
System.out.println("ColumnName = " + columnResultSet.getString("COLUMN_NAME"));
System.out.println("ColumnType = " + columnResultSet.getInt("DATA_TYPE"));
System.out.println("ColumnTypeName = " + columnResultSet.getString("TYPE_NAME"));
System.out.println("isAutoIncrement = " + columnResultSet.getString("IS_AUTOINCREMENT"));
System.out.println("isNullable = " + columnResultSet.getString("IS_NULLABLE"));
System.out.println("Precision = " + columnResultSet.getInt("COLUMN_SIZE"));
System.out.println("Scale = " + columnResultSet.getInt("DECIMAL_DIGITS"));
System.out.println("DefaultValue = " + columnResultSet.getString("COLUMN_DEF"));
System.out.println("Remarks = " + columnResultSet.getString("REMARKS"));
System.out.println("===================================");
}
输出结果
ColumnName = c_bigint_auto
ColumnType = -5
ColumnTypeName = BIGINT UNSIGNED
isAutoIncrement = YES
isNullable = NO
Precision = 20
Scale = 0
DefaultValue = null
Remarks = bigint 类型
===================================
ColumnName = c_bigint
ColumnType = -5
ColumnTypeName = BIGINT
isAutoIncrement = NO
isNullable = YES
Precision = 19
Scale = 0
DefaultValue = null
Remarks = bigint 类型
===================================
ColumnName = c_vachar
ColumnType = 12
ColumnTypeName = VARCHAR
isAutoIncrement = NO
isNullable = NO
Precision = 100
Scale = 0
DefaultValue = null
Remarks = varchar 类型
===================================
...
ColumnType
的值是
java.sql.Types
,
-5
即是
java.sql.Types#BIGINT
那是不是根据
ColumnType
就可以推断出数据库列类型了?
我们看下如下输出
ColumnName = c_longtext
ColumnType = -1
ColumnTypeName = LONGTEXT
isAutoIncrement = NO
isNullable = YES
Precision = 2147483647
Scale = 0
DefaultValue = null
Remarks = longtext 类型
===================================
ColumnName = c_json
ColumnType = -1
ColumnTypeName = JSON
isAutoIncrement = NO
isNullable = YES
Precision = 1073741824
Scale = 0
DefaultValue = null
Remarks = json 类型
===================================
ColumnType = -1
是对应
LONGTEXT
,还是对应
JSON
?
我们再看一个
ColumnName = c_datetime
ColumnType = 93
ColumnTypeName = DATETIME
isAutoIncrement = NO
isNullable = YES
Precision = 23
Scale = 0
DefaultValue = null
Remarks = datetime 类型
===================================
ColumnName = c_timestamp
ColumnType = 93
ColumnTypeName = TIMESTAMP
isAutoIncrement = NO
isNullable = YES
Precision = 24
Scale = 0
DefaultValue = null
Remarks = timestamp 类型
===================================
ColumnType = 93
是对应
DATETIME
,还是对应
TIMESTAMP
?
这说明不能通过
java.sql.Types
精准确认列的数据库类型!!!
那怎么办?
我相信你们已经看到了列的另一个元数据:
ColumnTypeName
它不就是
源数据源
中列列类型吗?
比如列
c_timestamp
的类型不就是
TIMESTAMP
吗,丝毫不差,准确的很!
但是我们不能忘了我们的初衷:拼接目标表的建表 SQL
通过
ColumnTypeName
能不能对应到目标表的列类型?
直接使用,肯定是不行的,关系型数据库之间的类型不是完全一一对应的,比如
MySQL
的
DATETIME
,
Oracle
是没有的
那可不可以通过
ColumnTypeName
来映射了,比如
DATETIME
映射到
Oracle
的
DATE
?
理论上来说是可行的,但是,问题又来了!
我们是通过
jdbc
来完成映射的,它只提供了
int
类型的
java.sql.Types
,并未提供
String
类型的
java.sql.Types
莫非你要自实现
String
类型的
java.sql.Types
? 你穷举的过来吗?
所以我们需要根据
java.sql.Types
对源数据源的列类型最大兼容性获取,而不是百分之百的精准获取
例如:
java.sql.Types#LONGVARCHAR
就当作列类型
LONGTEXT
,然后向目标数据源映射
如果想更精准,则再结合
ColumnTypeName
的值向目标数据源映射
总之一句话:
ColumnType
主导,
ColumnTypeName
辅助,完成目标数据源列映射
java.sql.DatabaseMetaData#getColumns
能获取的元数据不局限于上述示例中的那些
大家可以去看下其源码注释,因为太长了,我就不贴了,我们重点看下
COLUMN_SIZE
* The COLUMN_SIZE column specifies the column size for the given column.
* For numeric data, this is the maximum precision. For character data, this is the length in characters.
* For datetime datatypes, this is the length in characters of the String representation (assuming the
* maximum allowed precision of the fractional seconds component). For binary data, this is the length in bytes. For the ROWID datatype,
* this is the length in bytes. Null is returned for data types where the
* column size is not applicable.
我给你们逐行翻译下
/**
* For numeric data, this is the maximum precision => 对于数值数据,表示最大精度
* For character data, this is the length in characters => 对于字符数据,表示字符长度
* For datetime datatypes, this is the length in characters of the String representation(assuming the maximum allowed precision of the fractional seconds component )
* => 对于日期时间数据类型,表示字符串表示形式的最大长度(假设最大允许的分秒小数部分的精度)
* 例如:"2024-04-30 14:00:00" => 19,"2024-04-30 14:00:00.234" => 23
* "14:00:00" => 8,"14:00:00.234" => 11
* For binary data, this is the length in bytes => 对于二进制数据,表示字节长度
* For the ROWID datatype, this is the length in bytes => 对于 ROWID 类型,表示字节长度
* 0 is returned for data types where the column size is not applicable => 对于列大小不适用的数据类型,返回0
*/
主键元信息就比较少了,我们一般只关注主键名、列名、列序号
通过 jdbc 代码获取,示例代码如下
Connection connection = dataSource.getConnection();
DatabaseMetaData databaseMetaData = connection.getMetaData();
ResultSet primaryKeysResultSet = databaseMetaData.getPrimaryKeys(connection.getCatalog(), connection.getSchema(), "tbl_sync");
while (primaryKeysResultSet.next()) {
String columnName = primaryKeysResultSet.getString("COLUMN_NAME");
short keySeq = primaryKeysResultSet.getShort("KEY_SEQ");
String pkName = primaryKeysResultSet.getString("PK_NAME");
System.out.println(columnName + " - " + keySeq + " - " + pkName);
}
输出结果
c_vachar - 1 - PRIMARY
c_char - 2 - PRIMARY
c_bigint_auto - 3 - PRIMARY
不用过多说明了吧,你们肯定都能看懂
与主键元数据类似,关注的元数据主要包括索引名、列名、列序号,同时多了一个 是否非唯一
通过 jdbc 获取,代码如下
Connection connection = dataSource.getConnection();
DatabaseMetaData databaseMetaData = connection.getMetaData();
ResultSet indexResultSet = databaseMetaData.getIndexInfo(connection.getCatalog(), connection.getSchema(), "tbl_sync", false, false);
while (indexResultSet.next()) {
String indexName = indexResultSet.getString("INDEX_NAME");
String columnName = indexResultSet.getString("COLUMN_NAME");
boolean nonUnique = indexResultSet.getBoolean("NON_UNIQUE");
short ordinalPosition = indexResultSet.getShort("ORDINAL_POSITION");
System.out.println(columnName + " - " + ordinalPosition + " - " + indexName + " - " + nonUnique);
}
输出结果
c_vachar - 1 - PRIMARY - false
c_char - 2 - PRIMARY - false
c_bigint_auto - 3 - PRIMARY - false
c_bigint_auto - 1 - uk_id - false
c_vachar - 1 - idx_name_salary - true
c_decimal_4 - 2 - idx_name_salary - true
当相关元数据都获取到之后,就万事俱备,只欠东风了
我们将
test
库下的表
tbl_sync
同步到另一个
MySQL
库
obj_db
中
SQL 拼接如下
public String getCreateTableSql(String schemaName, TableMeta tableMeta, List columnMetas,
IndexMeta primaryKeyMeta, Map indexMetaMap) {
StringBuilder createSql = new StringBuilder("CREATE TABLE " + schemaName + "." + tableMeta.getTableName() + " ( ");
for (ColumnMeta columnMeta : columnMetas) {
createSql.append(columnMeta.getColumnName()).append(" ").append(getColumnType(columnMeta));
if (columnMeta.getIfUnsigned()) {
createSql.append(" UNSIGNED");
}
if (columnMeta.getIfNullable() == 0) {
createSql.append(" NOT NULL");
}
if (StrUtil.isNotBlank(columnMeta.getDefaultValue())) {
createSql.append(" DEFAULT '").append(columnMeta.getDefaultValue()).append("'");
}
if (columnMeta.getIfAutoIncrement()) {
createSql.append(" AUTO_INCREMENT");
}
if (StrUtil.isNotBlank(columnMeta.getRemarks())) {
createSql.append(" COMMENT '").append(columnMeta.getRemarks()).append("'");
}
createSql.append(",");
}
// 主键处理
if (ObjectUtil.isNotNull(primaryKeyMeta)) {
List indexColumns = primaryKeyMeta.getIndexColumns();
indexColumns.sort(Comparator.comparingInt(IndexColumnMeta::getOrdinalPosition));
createSql.append(" PRIMARY KEY (");
for (int i=0; i0) {
createSql.append(",");
}
createSql.append(indexColumns.get(i).getColumnName());
}
createSql.append("),");
}
if (CollectionUtil.isNotEmpty(indexMetaMap)) {
for (IndexMeta indexMeta : indexMetaMap.values()) {
if (indexMeta.getIndexType() == IndexTypeEnum.UNIQUE) {
// 唯一索引
createSql.append("UNIQUE ");
}
createSql.append("KEY ").append(indexMeta.getIndexName()).append(" (");
List indexColumns = indexMeta.getIndexColumns();
indexColumns.sort(Comparator.comparingInt(IndexColumnMeta::getOrdinalPosition));
for (int i=0; i0) {
createSql.append(",");
}
createSql.append(indexColumns.get(i).getColumnName());
}
createSql.append("),");
}
}
// 删除最后一个逗号
createSql.deleteCharAt(createSql.length()-1);
createSql.append(")");
if (StrUtil.isNotBlank(tableMeta.getRemarks())) {
createSql.append(" COMMENT '").append(tableMeta.getRemarks()).append("'");
}
return createSql.toString();
}
/**
* 获取表 列类型
* @param columnMeta 列元数据
* @return mysql 列类型
*/
private String getColumnType(ColumnMeta columnMeta) {
switch (columnMeta.getColumnType()) {
// 数值类型
case Types.TINYINT:
return "TINYINT";
case Types.SMALLINT:
return "SMALLINT";
case Types.INTEGER:
return "INT";
case Types.BIGINT:
return "BIGINT";
case Types.FLOAT:
case Types.REAL:
return columnMeta.getPrecision() > 0 ? "FLOAT(" + columnMeta.getPrecision() + "," + columnMeta.getScale() + ")" : "FLOAT";
case Types.DOUBLE:
return columnMeta.getPrecision() > 0 ? "DOUBLE(" + columnMeta.getPrecision() + "," + columnMeta.getScale() + ")" : "DOUBLE";
case Types.DECIMAL:
return "DECIMAL(" + columnMeta.getPrecision() + "," + columnMeta.getScale() + ")";
case Types.NUMERIC:
return columnMeta.getScale() <= 0 ? "BIGINT" : "DECIMAL(" + columnMeta.getPrecision() + "," + columnMeta.getScale() + ")";
// 字符与字符串类型
case Types.CHAR:
case Types.NCHAR:
return columnMeta.getPrecision() > 0 ? "CHAR(" + columnMeta.getPrecision() + ")" : "CHAR";
case Types.VARCHAR:
case Types.NVARCHAR:
return columnMeta.getPrecision() > 0 ? "VARCHAR(" + columnMeta.getPrecision() + ")" : "VARCHAR";
case Types.LONGVARCHAR:
case Types.LONGNVARCHAR:
switch (columnMeta.getColumnTypeName()) {
case "TINYTEXT":
return "TINYTEXT";
case "MEDIUMTEXT":
return "MEDIUMTEXT";
case "LONGTEXT":
return "LONGTEXT";
case "JSON":
return "JSON";
default:
return "TEXT";
}
case Types.CLOB:
case Types.NCLOB:
return "LONGTEXT";
// 日期和时间类型
case Types.DATE:
switch (columnMeta.getColumnTypeName()) {
case "YEAR":
return "YEAR";
default:
return "DATE";
}
case Types.TIME:
return "TIME" + (columnMeta.getPrecision() > 8 ? "(" + (columnMeta.getPrecision() - 9) + ")" : "");
case Types.TIMESTAMP:
switch (columnMeta.getColumnTypeName()) {
case "DATETIME":
return "DATETIME" + (columnMeta.getPrecision() > 19 ? "(" + (columnMeta.getPrecision() - 20) + ")" : "");
case "DATE":
// oracle 的 DATE
return "DATETIME";
default:
return "TIMESTAMP"+ (columnMeta.getPrecision() > 19 ? "(" + (columnMeta.getPrecision() - 20) + ")" : "");
}
// 二进制类型
case Types.BIT:
case Types.BOOLEAN:
return columnMeta.getPrecision() > 0 ? "BIT(" + columnMeta.getPrecision() + ")" : "BIT";
case Types.BINARY:
return columnMeta.getPrecision() > 0 ? "BINARY(" + columnMeta.getPrecision() + ")" : "BINARY";
case Types.VARBINARY:
return columnMeta.getPrecision() > 0 ? "VARBINARY(" + columnMeta.getPrecision() + ")" : "VARBINARY";
case Types.BLOB:
case Types.LONGVARBINARY:
switch (columnMeta.getColumnTypeName()) {
case "TINYBLOB":
return "TINYBLOB";
case "MEDIUMBLOB":
return "MEDIUMBLOB";
case "LONGBLOB":
return "LONGBLOB";
default:
return "BLOB";
}
case Types.OTHER:
if (columnMeta.getColumnTypeName().contains("VARCHAR")) {
return "VARCHAR" + (columnMeta.getPrecision() > 0 ? "(" + columnMeta.getPrecision() + ")" : "");
} else if (columnMeta.getColumnTypeName().contains("TIMESTAMP")) {
return "TIMESTAMP" + (columnMeta.getScale() > 0 ? "(" + columnMeta.getScale() + ")" : "");
}
else {
throw new SyncException("不支持的类型:" + columnMeta.getColumnTypeName());
}
default:
throw new SyncException("不支持的类型:" + columnMeta.getColumnTypeName());
}
}
结合元数据的获取
@Test
public void getMySQLCreateTableSql() throws SQLException {
Connection connection = dataSource.getConnection();
DatabaseMetaData databaseMetaData = connection.getMetaData();
ResultSet tableResultSet = databaseMetaData.getTables(connection.getCatalog(), connection.getSchema(), "tbl_sync", new String[]{"TABLE"});
TableMeta tableMeta = new TableMeta();
while (tableResultSet.next()) {
tableMeta.setTableName(tableResultSet.getString("TABLE_NAME"));
tableMeta.setTableType(tableResultSet.getString("TABLE_TYPE"));
tableMeta.setRemarks(tableResultSet.getString("REMARKS"));
}
// 获取列元数据
ResultSet columnResultSet = databaseMetaData.getColumns(connection.getCatalog(), connection.getSchema(), "tbl_sync", null);
List columnMetas = new ArrayList<>();
while (columnResultSet.next()) {
ColumnMeta columnMeta = new ColumnMeta();
columnMeta.setColumnName(columnResultSet.getString("COLUMN_NAME"));
columnMeta.setColumnType(columnResultSet.getInt("DATA_TYPE"));
columnMeta.setColumnTypeName(columnResultSet.getString("TYPE_NAME"));
columnMeta.setIfAutoIncrement("YES".equalsIgnoreCase(columnResultSet.getString("IS_AUTOINCREMENT")));
columnMeta.setIfNullable("YES".equalsIgnoreCase(columnResultSet.getString("IS_NULLABLE")) ? 1 : 0);
columnMeta.setPrecision(columnResultSet.getInt("COLUMN_SIZE"));
columnMeta.setScale(columnResultSet.getInt("DECIMAL_DIGITS"));
columnMeta.setDefaultValue(columnResultSet.getString("COLUMN_DEF"));
columnMeta.setRemarks(columnResultSet.getString("REMARKS"));
columnMeta.setIfUnsigned(columnMeta.getColumnTypeName().contains("UNSIGNED"));
columnMetas.add(columnMeta);
}
columnResultSet.close();
// 获取主键元数据
ResultSet primaryKeyResultSet = databaseMetaData.getPrimaryKeys(connection.getCatalog(), connection.getSchema(), "tbl_sync");
IndexMeta primaryKeyMeta = new IndexMeta();
while (primaryKeyResultSet.next()) {
IndexColumnMeta indexColumnMeta = new IndexColumnMeta(primaryKeyResultSet.getString("COLUMN_NAME"), primaryKeyResultSet.getShort("KEY_SEQ"));
primaryKeyMeta.setIndexName(primaryKeyResultSet.getString("PK_NAME"));
primaryKeyMeta.getIndexColumns().add(indexColumnMeta);
}
primaryKeyResultSet.close();
// 获取索引元数据
ResultSet indexResultSet = databaseMetaData.getIndexInfo(connection.getCatalog(), connection.getSchema(), "tbl_sync", false, false);
Map indexMetaMap = new HashMap<>();
while (indexResultSet.next()) {
String indexName = indexResultSet.getString("INDEX_NAME");
if (indexName.equals(primaryKeyMeta.getIndexName())) {
continue;
}
IndexMeta indexMeta = indexMetaMap.get(indexName);
if (ObjectUtil.isNull(indexMeta)) {
indexMeta = new IndexMeta(indexName);
indexMetaMap.put(indexName, indexMeta);
}
indexMeta.setIndexType(indexResultSet.getBoolean("NON_UNIQUE") ? IndexTypeEnum.NORMAL : IndexTypeEnum.UNIQUE);
indexMeta.getIndexColumns().add(new IndexColumnMeta(indexResultSet.getString("COLUMN_NAME"), indexResultSet.getShort("ORDINAL_POSITION")));
}
indexResultSet.close();
MysqlSql mysqlSql = new MysqlSql();
String createTableSql = mysqlSql.getCreateTableSql("obj_db", tableMeta, columnMetas, primaryKeyMeta, indexMetaMap);
System.out.println(SQLUtils.formatMySql(createTableSql));
}
得到的建表 SQL 如下
CREATE TABLE obj_db.tbl_sync (
c_bigint_auto BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT 'bigint 类型',
c_bigint BIGINT COMMENT 'bigint 类型',
c_vachar VARCHAR(100) NOT NULL COMMENT 'varchar 类型',
c_char CHAR(32) NOT NULL COMMENT 'char 类型',
c_text TEXT NOT NULL COMMENT 'text 类型',
c_decimal_4 DECIMAL(15, 4) NOT NULL DEFAULT '5000.0000' COMMENT 'decimal 类型',
c_decimal_0 DECIMAL(10, 0) COMMENT 'decimal 类型',
c_blob BLOB COMMENT 'blob 类型',
c_bit BIT(1) COMMENT 'bit 类型',
c_tinyint TINYINT COMMENT 'tinyint 类型',
c_binary BINARY(10) COMMENT 'binary 类型',
c_float FLOAT(13, 0) COMMENT 'float 类型',
c_double DOUBLE(23, 0) COMMENT 'double 类型',
c_varbinary VARBINARY(20) COMMENT 'varbinary 类型',
c_longblob LONGBLOB COMMENT 'longblob 类型',
c_longtext LONGTEXT COMMENT 'longtext 类型',
c_json JSON COMMENT 'json 类型',
c_date DATE COMMENT 'date 类型',
c_time TIME(2) COMMENT 'time 类型',
c_datetime DATETIME(3) COMMENT 'datetime 类型',
c_timestamp TIMESTAMP(4) COMMENT 'timestamp 类型',
c_year YEAR COMMENT 'year 类型',
PRIMARY KEY (c_vachar, c_char, c_bigint_auto),
UNIQUE KEY uk_id (c_bigint_auto),
KEY idx_name_salary (c_vachar, c_decimal_4)
) COMMENT '包含各种类型列的同步表'
可以看出,与原表的结构是一致的!
此处应该有掌声
何谓同源?
就是数据库类型相同的数据源,例如从 MySQL 同步到 MySQL
这种情况还有必要进行 SQL 拼接吗?
还记得怎么查看 MySQL 表的完整定义吗
SHOW CREATE TABLE test.tbl_sync
这是不是就可以获取到表的
DDL
了
所以同源的表结构同步,就不用拼接 SQL 那么复杂了,直接获取
DDL
后在目标数据源建表即可
java.sql.DatabaseMetaData
DDL
COLUMN_SIZE
针对不同的列类型,它的含义不同,文中已经详细说明,值得大家注意
mifun 官网版 1.4 50.03 MB
下载
湘ICP备2022002427号-10 湘公网安备:43070202000427号
© 2013~2024 haote.com 好特网