diff --git a/Excel/幼儿入园.xlsx b/Excel/幼儿入园.xlsx new file mode 100644 index 00000000..d3cbadc8 Binary files /dev/null and b/Excel/幼儿入园.xlsx differ diff --git a/src/main/java/com/dsideal/base/Tools/ExportExcel.java b/src/main/java/com/dsideal/base/Tools/ExportExcel.java index c4026e69..2e6c0a57 100644 --- a/src/main/java/com/dsideal/base/Tools/ExportExcel.java +++ b/src/main/java/com/dsideal/base/Tools/ExportExcel.java @@ -4,20 +4,135 @@ import com.dsideal.base.Tools.Util.LocalMysqlConnectUtil; import com.jfinal.plugin.activerecord.Db; import com.jfinal.plugin.activerecord.Record; import com.jfinal.plugin.activerecord.SqlPara; +import org.apache.poi.ss.usermodel.*; +import org.apache.poi.ss.util.CellRangeAddress; +import org.apache.poi.xssf.usermodel.XSSFWorkbook; +import java.io.FileOutputStream; import java.util.List; import static com.dsideal.base.DataEase.Model.DataEaseModel.DB_NAME; public class ExportExcel { + static String excelFileName = "D:\\dsWork\\YunNanDsBase\\Excel\\幼儿入园.xlsx"; + + public static void exportToExcel(List records, String filePath) { + try (Workbook workbook = new XSSFWorkbook()) { + Sheet sheet = workbook.createSheet("数据统计"); + + // 创建标题行样式 + CellStyle headerStyle = workbook.createCellStyle(); + // 设置边框 + headerStyle.setBorderTop(BorderStyle.THIN); + headerStyle.setBorderBottom(BorderStyle.THIN); + headerStyle.setBorderLeft(BorderStyle.THIN); + headerStyle.setBorderRight(BorderStyle.THIN); + // 设置背景色 + headerStyle.setFillForegroundColor(IndexedColors.LIGHT_BLUE.getIndex()); + headerStyle.setFillPattern(FillPatternType.SOLID_FOREGROUND); + // 设置对齐方式 + headerStyle.setAlignment(HorizontalAlignment.CENTER); + headerStyle.setVerticalAlignment(VerticalAlignment.CENTER); + // 设置字体 + Font headerFont = workbook.createFont(); + headerFont.setBold(true); + headerFont.setFontName("黑体"); + headerFont.setFontHeightInPoints((short) 12); + headerStyle.setFont(headerFont); + + // 创建数据行样式 + CellStyle dataStyle = workbook.createCellStyle(); + // 设置边框 + dataStyle.setBorderTop(BorderStyle.THIN); + dataStyle.setBorderBottom(BorderStyle.THIN); + dataStyle.setBorderLeft(BorderStyle.THIN); + dataStyle.setBorderRight(BorderStyle.THIN); + // 设置背景色 + dataStyle.setFillForegroundColor(IndexedColors.WHITE.getIndex()); + dataStyle.setFillPattern(FillPatternType.SOLID_FOREGROUND); + // 设置对齐方式 + dataStyle.setAlignment(HorizontalAlignment.CENTER); + dataStyle.setVerticalAlignment(VerticalAlignment.CENTER); + + // 创建表头 + Row headerRow = sheet.createRow(0); + // 设置行高 + headerRow.setHeight((short) (28 * 20)); // 28像素 ≈ 28 * 20 缇 + String[] headers = {"行政区划", "分类", "2023", "2024", "2025", "2026", + "2027", "2028", "2029", "2030", "2031", "2032", "2033", "2034"}; + for (int i = 0; i < headers.length; i++) { + Cell cell = headerRow.createCell(i); + cell.setCellValue(headers[i]); + cell.setCellStyle(headerStyle); + sheet.setColumnWidth(i, 3500); // 设置列宽 + } + + // 写入数据并处理合并单元格 + int rowNum = 1; + String lastDistrict = ""; + int mergeStartRow = 1; + + for (Record record : records) { + Row row = sheet.createRow(rowNum); + // 设置行高 + row.setHeight((short) (28 * 20)); // 28像素 ≈ 28 * 20 缇 + + String currentDistrict = record.getStr("行政区划"); + + // 填充数据 + for (int i = 0; i < headers.length; i++) { + Cell cell = row.createCell(i); + cell.setCellStyle(dataStyle); + + if (i == 0) { + cell.setCellValue(currentDistrict); + } else if (i == 1) { + cell.setCellValue(record.getStr("分类")); + } else { + Double value = record.getDouble(headers[i]); + if (value != null) { + cell.setCellValue(value); + } + } + } + + // 处理合并单元格 + if (!currentDistrict.equals(lastDistrict)) { + if (rowNum > mergeStartRow) { + // 合并行政区划列 + sheet.addMergedRegion(new CellRangeAddress( + mergeStartRow, rowNum - 1, 0, 0)); + } + mergeStartRow = rowNum; + } + + lastDistrict = currentDistrict; + rowNum++; + } + + // 处理最后一组合并 + if (rowNum > mergeStartRow) { + sheet.addMergedRegion(new CellRangeAddress( + mergeStartRow, rowNum - 1, 0, 0)); + sheet.addMergedRegion(new CellRangeAddress( + mergeStartRow, rowNum - 1, 1, 1)); + } + + // 保存文件 + try (FileOutputStream fileOut = new FileOutputStream(filePath)) { + workbook.write(fileOut); + } + + } catch (Exception e) { + e.printStackTrace(); + } + } public static void main(String[] args) { LocalMysqlConnectUtil.Init(); SqlPara sqlPara = Db.getSqlPara("exportExcel.Xqry"); List list = Db.use(DB_NAME).find(sqlPara); - for (Record record : list) { - System.out.println(record); - } + exportToExcel(list, excelFileName); } } diff --git a/src/main/resources/Sql/ExportExcel.sql b/src/main/resources/Sql/ExportExcel.sql index d77778a7..6bf7989b 100644 --- a/src/main/resources/Sql/ExportExcel.sql +++ b/src/main/resources/Sql/ExportExcel.sql @@ -1,9 +1,10 @@ #namespace("exportExcel") -- 学前入园幼儿入园总量 #sql("Xqry") - (SELECT + -- 入园总量数据查询 + (SELECT 行政区划, - 上级行政区划, + '入园数' as 类型, '总入园数' as 分类, MAX(IF(年份 = 2023, 总量数值, NULL)) as '2023', MAX(IF(年份 = 2024, 总量数值, NULL)) as '2024', @@ -19,13 +20,13 @@ MAX(IF(年份 = 2034, 总量数值, NULL)) as '2034' FROM excel_学前幼儿入园总量_b25b1b09b0 WHERE 总量分类 = '总入园数' - GROUP BY 行政区划, 上级行政区划) + GROUP BY 行政区划) UNION ALL (SELECT 行政区划, - 上级行政区划, + '入园数' as 类型, '城区' as 分类, MAX(IF(年份 = 2023, 区域数值, NULL)) as '2023', MAX(IF(年份 = 2024, 区域数值, NULL)) as '2024', @@ -41,13 +42,13 @@ MAX(IF(年份 = 2034, 区域数值, NULL)) as '2034' FROM excel_学前幼儿入园总量_b25b1b09b0 WHERE 区域分类 = '城区' - GROUP BY 行政区划, 上级行政区划) + GROUP BY 行政区划) UNION ALL (SELECT 行政区划, - 上级行政区划, + '入园数' as 类型, '镇区' as 分类, MAX(IF(年份 = 2023, 区域数值, NULL)) as '2023', MAX(IF(年份 = 2024, 区域数值, NULL)) as '2024', @@ -63,13 +64,13 @@ MAX(IF(年份 = 2034, 区域数值, NULL)) as '2034' FROM excel_学前幼儿入园总量_b25b1b09b0 WHERE 区域分类 = '镇区' - GROUP BY 行政区划, 上级行政区划) + GROUP BY 行政区划) UNION ALL (SELECT 行政区划, - 上级行政区划, + '入园数' as 类型, '乡村' as 分类, MAX(IF(年份 = 2023, 区域数值, NULL)) as '2023', MAX(IF(年份 = 2024, 区域数值, NULL)) as '2024', @@ -85,14 +86,108 @@ MAX(IF(年份 = 2034, 区域数值, NULL)) as '2034' FROM excel_学前幼儿入园总量_b25b1b09b0 WHERE 区域分类 = '乡村' - GROUP BY 行政区划, 上级行政区划) + GROUP BY 行政区划) + + UNION ALL + + -- 在园总量数据查询 + (SELECT + 行政区划, + '在园数' as 类型, + '总在园数' as 分类, + MAX(IF(年份 = 2023, 总量数值, NULL)) as '2023', + MAX(IF(年份 = 2024, 总量数值, NULL)) as '2024', + MAX(IF(年份 = 2025, 总量数值, NULL)) as '2025', + MAX(IF(年份 = 2026, 总量数值, NULL)) as '2026', + MAX(IF(年份 = 2027, 总量数值, NULL)) as '2027', + MAX(IF(年份 = 2028, 总量数值, NULL)) as '2028', + MAX(IF(年份 = 2029, 总量数值, NULL)) as '2029', + MAX(IF(年份 = 2030, 总量数值, NULL)) as '2030', + MAX(IF(年份 = 2031, 总量数值, NULL)) as '2031', + MAX(IF(年份 = 2032, 总量数值, NULL)) as '2032', + MAX(IF(年份 = 2033, 总量数值, NULL)) as '2033', + MAX(IF(年份 = 2034, 总量数值, NULL)) as '2034' + FROM excel_学前幼儿在园总量_c04222fd74 + WHERE 总量分类 = '总在园数' + GROUP BY 行政区划) + + UNION ALL + + (SELECT + 行政区划, + '在园数' as 类型, + '城区' as 分类, + MAX(IF(年份 = 2023, 区域数值, NULL)) as '2023', + MAX(IF(年份 = 2024, 区域数值, NULL)) as '2024', + MAX(IF(年份 = 2025, 区域数值, NULL)) as '2025', + MAX(IF(年份 = 2026, 区域数值, NULL)) as '2026', + MAX(IF(年份 = 2027, 区域数值, NULL)) as '2027', + MAX(IF(年份 = 2028, 区域数值, NULL)) as '2028', + MAX(IF(年份 = 2029, 区域数值, NULL)) as '2029', + MAX(IF(年份 = 2030, 区域数值, NULL)) as '2030', + MAX(IF(年份 = 2031, 区域数值, NULL)) as '2031', + MAX(IF(年份 = 2032, 区域数值, NULL)) as '2032', + MAX(IF(年份 = 2033, 区域数值, NULL)) as '2033', + MAX(IF(年份 = 2034, 区域数值, NULL)) as '2034' + FROM excel_学前幼儿在园总量_c04222fd74 + WHERE 区域分类 = '城区' + GROUP BY 行政区划) + + UNION ALL + + (SELECT + 行政区划, + '在园数' as 类型, + '镇区' as 分类, + MAX(IF(年份 = 2023, 区域数值, NULL)) as '2023', + MAX(IF(年份 = 2024, 区域数值, NULL)) as '2024', + MAX(IF(年份 = 2025, 区域数值, NULL)) as '2025', + MAX(IF(年份 = 2026, 区域数值, NULL)) as '2026', + MAX(IF(年份 = 2027, 区域数值, NULL)) as '2027', + MAX(IF(年份 = 2028, 区域数值, NULL)) as '2028', + MAX(IF(年份 = 2029, 区域数值, NULL)) as '2029', + MAX(IF(年份 = 2030, 区域数值, NULL)) as '2030', + MAX(IF(年份 = 2031, 区域数值, NULL)) as '2031', + MAX(IF(年份 = 2032, 区域数值, NULL)) as '2032', + MAX(IF(年份 = 2033, 区域数值, NULL)) as '2033', + MAX(IF(年份 = 2034, 区域数值, NULL)) as '2034' + FROM excel_学前幼儿在园总量_c04222fd74 + WHERE 区域分类 = '镇区' + GROUP BY 行政区划) + + UNION ALL + + (SELECT + 行政区划, + '在园数' as 类型, + '乡村' as 分类, + MAX(IF(年份 = 2023, 区域数值, NULL)) as '2023', + MAX(IF(年份 = 2024, 区域数值, NULL)) as '2024', + MAX(IF(年份 = 2025, 区域数值, NULL)) as '2025', + MAX(IF(年份 = 2026, 区域数值, NULL)) as '2026', + MAX(IF(年份 = 2027, 区域数值, NULL)) as '2027', + MAX(IF(年份 = 2028, 区域数值, NULL)) as '2028', + MAX(IF(年份 = 2029, 区域数值, NULL)) as '2029', + MAX(IF(年份 = 2030, 区域数值, NULL)) as '2030', + MAX(IF(年份 = 2031, 区域数值, NULL)) as '2031', + MAX(IF(年份 = 2032, 区域数值, NULL)) as '2032', + MAX(IF(年份 = 2033, 区域数值, NULL)) as '2033', + MAX(IF(年份 = 2034, 区域数值, NULL)) as '2034' + FROM excel_学前幼儿在园总量_c04222fd74 + WHERE 区域分类 = '乡村' + GROUP BY 行政区划) - ORDER BY 上级行政区划, 行政区划, + ORDER BY 行政区划, + CASE 类型 + WHEN '入园数' THEN 1 + WHEN '在园数' THEN 2 + END, CASE 分类 WHEN '总入园数' THEN 1 + WHEN '总在园数' THEN 1 WHEN '城区' THEN 2 WHEN '镇区' THEN 3 WHEN '乡村' THEN 4 - END + END; #end #end \ No newline at end of file