修改了数据库增删改查的方法。

This commit is contained in:
root 2025-05-27 17:01:35 +08:00
parent 8b9e0bc03f
commit e9de51f62d
2 changed files with 231 additions and 87 deletions

View File

@ -1155,16 +1155,155 @@ public class DatasetDataManage {
return tables;
}
public List<Map<String,Object>> getFieldsByTableId(Long id) throws Exception {
QueryWrapper<CoreDatasetTableField> wrapper = new QueryWrapper<>();
wrapper.select("id","origin_name","name","type","size");
wrapper.eq("dataset_table_id", id);
wrapper.eq("checked", true);
wrapper.isNull("chart_id");
List<Map<String,Object>> fields = coreDatasetTableFieldMapper.selectMaps(wrapper);
return fields;
public Map<String, Object> getFieldsByTableId(Long datasource_id, String tablename) throws Exception {
CoreDatasource coreDatasource = coreDatasourceMapper.selectById(datasource_id);
if (coreDatasource == null) {
DEException.throwException("数据源不存在");
}
DatasourceSchemaDTO datasourceSchemaDTO = new DatasourceSchemaDTO();
BeanUtils.copyBean(datasourceSchemaDTO, coreDatasource);
Provider provider = ProviderFactory.getProvider(coreDatasource.getType());
DatasourceRequest datasourceRequest = new DatasourceRequest();
datasourceRequest.setDsList(Map.of(datasourceSchemaDTO.getId(), datasourceSchemaDTO));
String dbType = datasourceSchemaDTO.getType().toLowerCase();
// 构建字段查询SQL带注释
String columnSql = buildColumnQuerySQL(dbType, tablename);
datasourceRequest.setQuery(columnSql);
Map<String, Object> columnData = provider.fetchResultField(datasourceRequest);
List<String[]> columnRows = (List<String[]>) columnData.get("data");
// 构建主键查询SQL
String pkSql = buildPrimaryKeyQuerySQL(dbType, tablename);
datasourceRequest.setQuery(pkSql);
Map<String, Object> pkData = provider.fetchResultField(datasourceRequest);
List<String[]> pkRows = (List<String[]>) pkData.get("data");
Set<String> primaryKeyFields = new HashSet<>();
for (String[] row : pkRows) {
if (row.length > 0 && StringUtils.isNotBlank(row[0])) {
primaryKeyFields.add(row[0]);
}
}
// 构建字段信息
List<Map<String, Object>> fields = new ArrayList<>();
for (String[] row : columnRows) {
String field = row[0];
String type = row[1];
int size = ObjectUtils.isNotEmpty(row[2])?Integer.parseInt(row[2]):0;
String comment = row.length > 3 ? row[3] : "";
Map<String, Object> fieldInfo = new HashMap<>();
fieldInfo.put("field", field);
fieldInfo.put("name", StringUtils.isNotBlank(comment) ? comment : field); // 注释优先
fieldInfo.put("type", type);
fieldInfo.put("size", size);
fieldInfo.put("iskey", primaryKeyFields.contains(field));
fields.add(fieldInfo);
}
// 返回结果
Map<String, Object> result = new HashMap<>();
result.put("keyfeilds", new ArrayList<>(primaryKeyFields));
result.put("fields", fields);
return result;
}
private String buildColumnQuerySQL(String dbType, String tablename) {
switch (dbType) {
case "mysql":
return String.format(
"SELECT COLUMN_NAME AS field, DATA_TYPE AS type, CHARACTER_MAXIMUM_LENGTH AS size, COLUMN_COMMENT AS comment " +
"FROM INFORMATION_SCHEMA.COLUMNS " +
"WHERE TABLE_NAME = '%s'", tablename);
case "mariadb":
return String.format(
"SELECT COLUMN_NAME AS field, DATA_TYPE AS type, COALESCE(CHARACTER_MAXIMUM_LENGTH, 0) AS size, COLUMN_COMMENT AS comment " +
"FROM INFORMATION_SCHEMA.COLUMNS " +
"WHERE TABLE_NAME = '%s'", tablename);
case "postgresql":
return String.format(
"SELECT a.attname AS field, " +
"pg_catalog.format_type(a.atttypid, a.atttypmod) AS type, " +
"COALESCE(a.attlen, 0) AS size, " +
"d.description AS comment " +
"FROM pg_attribute a " +
"LEFT JOIN pg_description d ON d.objoid = a.attrelid AND d.objsubid = a.attnum " +
"WHERE a.attrelid = '%s'::regclass AND a.attnum > 0 AND NOT a.attisdropped", tablename);
case "oracle":
return String.format(
"SELECT cols.column_name AS field, cols.data_type AS type, cols.data_length AS size, comm.comments AS comment " +
"FROM all_cons_columns cons, all_constraints c, all_col_comments comm, all_tab_cols cols " +
"WHERE cols.table_name = '%s' " +
"AND cols.column_name = comm.column_name(+) " +
"AND cols.table_name = comm.table_name(+) " +
"AND cols.owner = comm.owner(+)", tablename.toUpperCase());
case "sqlserver":
return String.format(
"SELECT c.name AS field, t.name AS type, c.max_length AS size, " +
"ep.value AS comment " +
"FROM sys.columns c " +
"JOIN sys.types t ON c.user_type_id = t.user_type_id " +
"LEFT JOIN sys.extended_properties ep ON ep.major_id = c.object_id AND ep.minor_id = c.column_id AND ep.name = 'MS_Description' " +
"WHERE c.object_id = OBJECT_ID('%s')", tablename);
default:
throw new UnsupportedOperationException("不支持的数据库类型:" + dbType);
}
}
private String buildPrimaryKeyQuerySQL(String dbType, String tablename) {
switch (dbType) {
case "mysql":
return String.format(
"SELECT COLUMN_NAME AS field " +
"FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE " +
"WHERE TABLE_NAME = '%s' AND CONSTRAINT_NAME IN (" +
"SELECT CONSTRAINT_NAME FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS " +
"WHERE TABLE_NAME = '%s' AND CONSTRAINT_TYPE = 'PRIMARY KEY'" +
")", tablename, tablename);
case "mariadb":
return String.format(
"SELECT COLUMN_NAME FROM INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE " +
"WHERE TABLE_NAME = '%s' AND CONSTRAINT_NAME IN (" +
"SELECT CONSTRAINT_NAME FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS " +
"WHERE TABLE_NAME = '%s' AND CONSTRAINT_TYPE = 'PRIMARY KEY'" +
")", tablename, tablename);
case "postgresql":
return String.format(
"SELECT a.attname AS field " +
"FROM pg_index i " +
"JOIN pg_attribute a ON a.attrelid = i.indrelid AND a.attnum = ANY(i.indkey) " +
"WHERE i.indrelid = '%s'::regclass AND i.indisprimary", tablename);
case "oracle":
return String.format(
"SELECT cols.column_name " +
"FROM all_constraints c, all_cons_columns cols " +
"WHERE c.owner = cols.owner " +
"AND c.constraint_name = cols.constraint_name " +
"AND c.constraint_type = 'P' " +
"AND cols.table_name = '%s'", tablename.toUpperCase());
case "sqlserver":
return String.format(
"SELECT COL_NAME(object_id, column_id) AS field " +
"FROM sys.key_constraints kc " +
"JOIN sys.index_columns ic ON kc.parent_object_id = ic.object_id AND kc.unique_index_id = ic.index_id " +
"WHERE kc.type = 'PK' AND kc.parent_object_id = OBJECT_ID('%s')", tablename);
default:
throw new UnsupportedOperationException("不支持的数据库类型:" + dbType);
}
}
public boolean addTableData(Long datasourceId, String tableData) throws Exception {
// 根据数据源 id 查询数据源信息调用通用数据源执行器
CoreDatasource coreDatasource = coreDatasourceMapper.selectById(datasourceId);
@ -1227,36 +1366,27 @@ public class DatasetDataManage {
return false;
}
}
public Map<String, Object> getTableDataByPk(Long datasourceId, String tableData) throws Exception {
public Map<String, Object> getTableDataByPk(Long datasourceId, String condtion) throws Exception {
// 获取数据源信息
CoreDatasource coreDatasource = coreDatasourceMapper.selectById(datasourceId);
if (coreDatasource == null) {
DEException.throwException("数据源不存在");
}
// 解析 JSON 数据
Map<String, Object> dataMap = JsonUtil.parseObject(tableData, Map.class);
//condtion={ \"tableName\": \"user\", key:[{ \"fieldName\": \"id\",\"fieldValue\": \"0001\"]
Map<String, Object> dataMap = JsonUtil.parseObject(condtion, Map.class);
String tableName = (String) dataMap.get("tableName");
String primaryKeyField = (String) dataMap.get("primaryKeyField");
Object primaryKeyValue = dataMap.get("primaryKeyValue");
// 参数校验
if (StringUtils.isBlank(tableName)) {
DEException.throwException("表名不能为空");
}
if (StringUtils.isBlank(primaryKeyField) || primaryKeyValue == null) {
List<Map<String, Object>> keyFields = (List<Map<String, Object>>) dataMap.get("key");
if (CollectionUtils.isEmpty(keyFields)) {
DEException.throwException("主键字段或值不能为空");
}
// 构建 SELECT 语句
String whereClause;
if (primaryKeyValue instanceof String) {
whereClause = String.format("%s = '%s'", primaryKeyField, primaryKeyValue);
} else {
whereClause = String.format("%s = %s", primaryKeyField, primaryKeyValue);
}
String whereClause = buildWhereCondition(keyFields);
String sql = String.format("SELECT * FROM %s WHERE %s", tableName, whereClause);
// 执行查询操作
DatasourceSchemaDTO datasourceSchemaDTO = new DatasourceSchemaDTO();
BeanUtils.copyBean(datasourceSchemaDTO, coreDatasource);
@ -1289,6 +1419,35 @@ public class DatasetDataManage {
}
return resultMap;
}
/**
* 构建 WHERE 条件字符串用于多字段主键查询/更新/删除操作
*
* @param keyFields 主键字段列表格式如{ "fieldName": "id", "fieldValue": "0001" }
* @return SQL WHERE 子句字符串
*/
private String buildWhereCondition(List<Map<String, Object>> keyFields) {
StringBuilder whereClause = new StringBuilder();
for (int i = 0; i < keyFields.size(); i++) {
Map<String, Object> keyField = keyFields.get(i);
String fieldName = (String) keyField.get("fieldName");
Object fieldValue = keyField.get("fieldValue");
if (i > 0) {
whereClause.append(" AND ");
}
if (fieldValue == null) {
whereClause.append(fieldName).append(" IS NULL");
} else if (fieldValue instanceof String) {
whereClause.append(String.format("%s = '%s'", fieldName, fieldValue));
} else {
whereClause.append(String.format("%s = %s", fieldName, fieldValue));
}
}
return whereClause.toString();
}
public boolean updateTableData(Long datasourceId, String tableData) throws Exception {
// 获取数据源信息
@ -1296,24 +1455,21 @@ public class DatasetDataManage {
if (coreDatasource == null) {
DEException.throwException("数据源不存在");
}
//String tableDataJson = "{ \"tableName\": \"user\", \"primaryKeyField\": \"id\", \"primaryKeyValue\": \"0001\", \"data\": [ { \"fieldName\": \"name\", \"fieldType\": \"varchar\", \"fieldValue\": \"李四\" } ] }";
//String tableDataJson = "{ \"tableName\": \"user\", key:[{ \"fieldName\": \"id\",\"fieldValue\": \"0001\"], \"data\": [ { \"fieldName\": \"name\", \"fieldType\": \"varchar\", \"fieldValue\": \"李四\" } ] }";
// 解析 JSON 数据
Map<String, Object> dataMap = JsonUtil.parseObject(tableData, Map.class);
String tableName = (String) dataMap.get("tableName");
String primaryKeyField = (String) dataMap.get("primaryKeyField");
Object primaryKeyValue = dataMap.get("primaryKeyValue");
List<Map<String, Object>> fieldList = (List<Map<String, Object>>) dataMap.get("data");
if (fieldList == null || fieldList.isEmpty()) {
DEException.throwException("没有可更新的数据字段");
}
if (StringUtils.isBlank(tableName)) {
DEException.throwException("表名不能为空");
}
if (StringUtils.isBlank(primaryKeyField) || primaryKeyValue == null) {
List<Map<String, Object>> keyFields = (List<Map<String, Object>>) dataMap.get("key");
if (CollectionUtils.isEmpty(keyFields)) {
DEException.throwException("主键字段或值不能为空");
}
List<Map<String, Object>> fieldList = (List<Map<String, Object>>) dataMap.get("data");
if (fieldList == null || fieldList.isEmpty()) {
DEException.throwException("没有可更新的数据字段");
}
// 构建 UPDATE 语句
StringBuilder setClause = new StringBuilder();
for (int i = 0; i < fieldList.size(); i++) {
@ -1331,15 +1487,8 @@ public class DatasetDataManage {
}
}
String whereClause = String.format("%s = ", primaryKeyField);
if (primaryKeyValue instanceof String) {
whereClause += String.format("'%s'", primaryKeyValue);
} else {
whereClause += primaryKeyValue;
}
String sql = String.format("UPDATE %s SET %s WHERE %s", tableName, setClause.toString(), whereClause);
String whereClause = buildWhereCondition(keyFields);
String sql = String.format("UPDATE %s SET %s WHERE %s", tableName, setClause, whereClause);
// 调用执行器执行 SQL
DatasourceSchemaDTO datasourceSchemaDTO = new DatasourceSchemaDTO();
BeanUtils.copyBean(datasourceSchemaDTO, coreDatasource);
@ -1360,37 +1509,25 @@ public class DatasetDataManage {
return false;
}
}
public boolean deleteTableData(Long datasourceId, String whereJson) throws Exception {
public boolean deleteTableData(Long datasourceId, String condtion) throws Exception {
// 获取数据源信息
CoreDatasource coreDatasource = coreDatasourceMapper.selectById(datasourceId);
if (coreDatasource == null) {
DEException.throwException("数据源不存在");
}
DEException.throwException("数据源不存在"); }
// 解析 JSON 数据
//String tableDataJson = "{ \"tableName\": \"user\", \"primaryKeyField\": \"id\", \"primaryKeyValue\": \"0001\" }";
Map<String, Object> dataMap = JsonUtil.parseObject(whereJson, Map.class);
//String tableDataJson = "{ \"tableName\": \"user\", key:[{ \"fieldName\": \"id\",\"fieldValue\": \"0001\"] }";
Map<String, Object> dataMap = JsonUtil.parseObject(condtion, Map.class);
String tableName = (String) dataMap.get("tableName");
String primaryKeyField = (String) dataMap.get("primaryKeyField");
Object primaryKeyValue = dataMap.get("primaryKeyValue");
if (StringUtils.isBlank(tableName)) {
DEException.throwException("表名不能为空");
}
if (StringUtils.isBlank(primaryKeyField) || primaryKeyValue == null) {
List<Map<String, Object>> keyFields = (List<Map<String, Object>>) dataMap.get("key");
if (CollectionUtils.isEmpty(keyFields)) {
DEException.throwException("主键字段或值不能为空");
}
// 构建 DELETE 语句
String whereClause = String.format("%s = ", primaryKeyField);
if (primaryKeyValue instanceof String) {
whereClause += String.format("'%s'", primaryKeyValue);
} else {
whereClause += primaryKeyValue;
}
String whereClause = buildWhereCondition(keyFields);
String sql = String.format("DELETE FROM %s WHERE %s", tableName, whereClause);
// 调用执行器执行 SQL
DatasourceSchemaDTO datasourceSchemaDTO = new DatasourceSchemaDTO();
BeanUtils.copyBean(datasourceSchemaDTO, coreDatasource);
@ -1412,16 +1549,15 @@ public class DatasetDataManage {
}
}
public Page<Map<String, Object>> queryTableDataPaged(Long datasourceId, String queryJson) throws Exception {
public Page<Map<String, Object>> queryTableDataPaged(Long datasourceId, String condition) throws Exception {
// 获取数据源信息
CoreDatasource coreDatasource = coreDatasourceMapper.selectById(datasourceId);
if (coreDatasource == null) {
DEException.throwException("数据源不存在");
}
//String queryJson = "{ \"tableName\": \"user\", \"conditions\": [ { \"field\": \"name\", \"operator\": \"like\", \"value\": \"\" }, { \"field\": \"id\", \"operator\": \"in\", \"value\": [1, 2, 3] } ], \"pageNum\": 1, \"pageSize\": 10 }";
// 解析 JSON 查询参
Map<String, Object> dataMap = JsonUtil.parseObject(queryJson, Map.class);
// 解析 condition JSON
Map<String, Object> dataMap = JsonUtil.parseObject(condition, Map.class);
String tableName = (String) dataMap.get("tableName");
List<Map<String, Object>> conditionList = (List<Map<String, Object>>) dataMap.get("conditions");
@ -1434,20 +1570,18 @@ public class DatasetDataManage {
// 构建 WHERE 条件子句
StringBuilder whereClause = new StringBuilder();
if (conditionList != null && !conditionList.isEmpty()) {
whereClause.append(" WHERE ");
for (int i = 0; i < conditionList.size(); i++) {
Map<String, Object> condition = conditionList.get(i);
String field = (String) condition.get("field");
String operator = ((String) condition.get("operator")).toLowerCase();
Object value = condition.get("value");
Map<String, Object> cond = conditionList.get(i);
String field = (String) cond.get("field");
String operator = ((String) cond.get("operator")).toLowerCase();
Object value = cond.get("value");
if (i > 0) {
whereClause.append(" AND ");
}
// 处理不同类型的条件
switch (operator) {
case "like":
whereClause.append(String.format("%s LIKE '%%%s%%'", field, value));
@ -1487,43 +1621,53 @@ public class DatasetDataManage {
}
}
// 构建基础查询语句
// 构建基础 SQL
String baseSql = String.format("SELECT * FROM %s%s", tableName, whereClause);
// 根据数据库类型生成分页语句
String dbType = coreDatasource.getType().toLowerCase();
String pagedSql = buildPagedSQL(baseSql, dbType, pageNum, pageSize);
// 构建 COUNT 查询语句用于分页计算
String countSql = String.format("SELECT COUNT(*) FROM %s%s", tableName, whereClause);
// 执行查询
DatasourceSchemaDTO schemaDTO = new DatasourceSchemaDTO();
BeanUtils.copyBean(schemaDTO, coreDatasource);
Provider provider = ProviderFactory.getProvider(coreDatasource.getType());
DatasourceRequest request = new DatasourceRequest();
request.setDsList(Map.of(schemaDTO.getId(), schemaDTO));
// 1. 查询分页数据
// 查询分页数据
request.setQuery(pagedSql);
Map<String, Object> result = provider.fetchResultField(request);
List<Map<String, Object>> dataList = (List<Map<String, Object>>) result.get("data");
List<String[]> dataList = (List<String[]>) result.get("data");
List<TableField> fields = (List<TableField>) result.get("fields");
// 2. 查询总记录数
// 查询总记录数
request.setQuery(countSql);
Map<String, Object> countResult = provider.fetchResultField(request);
long total = Long.parseLong(((List<String[]>) countResult.get("data")).get(0)[0]);
// 封装分页结果
// 将数据封装为 Map 形式
List<Map<String, Object>> records = new ArrayList<>();
if (!CollectionUtils.isEmpty(dataList)) {
for (String[] row : dataList) {
Map<String, Object> rowMap = new LinkedHashMap<>();
for (int i = 0; i < fields.size() && i < row.length; i++) {
String fieldName = fields.get(i).getOriginName();
String fieldValue = row[i];
rowMap.put(fieldName, fieldValue);
}
records.add(rowMap);
}
}
// 返回分页结果
Page<Map<String, Object>> page = new Page<>();
page.setCurrent(pageNum);
page.setSize(pageSize);
page.setTotal(total);
page.setRecords(dataList);
page.setRecords(records);
return page;
}
}
private void appendValue(StringBuilder sb, String field, Object value, String op) {
if (value instanceof String) {

View File

@ -116,8 +116,8 @@ public class DatasetDataServer implements DatasetDataApi {
return result;
}
@GetMapping("getFieldsByTableId")
public List<Map<String,Object>> getFieldsByTableId(Long id) throws Exception {
List<Map<String,Object>> result = datasetDataManage.getFieldsByTableId(id);
public Map<String, Object> getFieldsByTableId(Long datasourceId,String tablename) throws Exception {
Map<String, Object> result = datasetDataManage.getFieldsByTableId(datasourceId,tablename);
return result;
}
@PostMapping("addTableData")