一个html实现数据库自定义查询

发布于:2025-06-04 ⋅ 阅读:(26) ⋅ 点赞:(0)

使用场景

应用上线后甲方频繁的找开发查询数据库数据,且没有固定的查询规律,产品经理也没有规划报表需求。

实现方案

后端开放自定义sql查询,屏蔽所有数据库的高危操作,将常用查询的sql放在一个html中的js中直接查询,功能满足以下需求:

  • 可动态设置接口地址,方便查看测试和正式数据库
  • 可预设常用查询sql
  • 支持cte查询,支持sql注释
  • 动态表头,分页显示总条数
  • 保留查询历史记录
  • 预览长文本支持单机常看详情
  • 最重要的,尽量简单,单页面实现,无其他依赖

效果图

在这里插入图片描述
在这里插入图片描述
在这里插入图片描述
在这里插入图片描述

实现代码

后端java接口

	@Autowired
    private JdbcTemplate jdbcTemplate;

    @PostMapping("/query/sql/page")
    @Operation(summary = "通用SQL分页查询", description = "仅允许执行SELECT语句并支持分页")
    public ResponseResult<PageResponse> executePagedQuery(@RequestBody SqlQueryRequest request) {
        String sql = request.getSql();
        Integer pageSize = request.getPageSize();
        Integer pageIndex = request.getPageIndex();

        try {
            // 校验参数
            if (sql == null || sql.trim().isEmpty() || !isSafeSelectSql(sql)) {
                return ResponseResult.fail(400, "无效的SQL语句或非SELECT查询");
            }
            if (pageSize == null || pageSize <= 0) {
                pageSize = 10;
            }
            if (pageIndex == null || pageIndex < 1) {
                pageIndex = 1;
            }

            // 构建 count SQL
            // 修改 executePagedQuery 方法中调用 buildCountSql 的部分:
            String safeSql = removeSingleLineComments(sql);
            String countSql = buildCountSql(safeSql);

            // 执行 count 查询
            Long total = jdbcTemplate.queryForObject(countSql, Long.class);

            // 添加分页条件
            String pagedSql = safeSql + " LIMIT " + pageSize + " OFFSET " + ((pageIndex - 1) * pageSize);

            // 执行分页查询
            List<Map<String, Object>> result = jdbcTemplate.queryForList(pagedSql);

            // 返回分页结果
            return ResponseResult.success(PageResponse.of(result, total, pageIndex, pageSize));
        } catch (Exception e) {
            log.error("执行分页SQL失败: {}", e.getMessage(), e);
            return ResponseResult.fail(500, "SQL执行异常:" + e.getMessage());
        }
    }


    // 构建 COUNT SQL
    private String buildCountSql(String originalSql) {
        return "SELECT COUNT(*) FROM (" + originalSql + ") AS tmp";
    }
    /**
     * 移除 SQL 中的单行注释(以 "--" 开头的部分)
     */
    private String removeSingleLineComments(String sql) {
        if (sql == null) {
            return null;
        }
        // 使用正则表达式匹配 "--" 注释并移除整行
        return sql.replaceAll("--[^\n]*", "");
    }
    /**
     * 判断是否为安全的 SELECT 查询(支持 CTE)
     */
    private boolean isSafeSelectSql(String sql) {
        if (sql == null || sql.trim().isEmpty()) {
            return false;
        }

        String trimmedSql = sql.trim().toLowerCase();

        // 使用正则判断是否是以 SELECT 或 WITH 开头,并且不包含危险关键词
        return trimmedSql.matches("(?s:^(select|with).*$)")
               && !containsForbiddenKeywords(trimmedSql);
    }

    /**
     * 检查 SQL 是否包含非法关键字
     */
    private boolean containsForbiddenKeywords(String sql) {
        List<String> forbiddenKeywords = Arrays.asList(
            "\\b(delete|update|insert|drop|truncate|merge|exec|execute|create|alter|grant|revoke|call|load|replace|upsert|copy)\\b",
            "into",
            "for update"
        );

        for (String pattern : forbiddenKeywords) {
            if (Pattern.compile(pattern, Pattern.CASE_INSENSITIVE).matcher(sql).find()) {
                return true;
            }
        }
        return false;
    }

为了解决跨域问题,还需要添加如下代码

@Configuration
public class WebMvcConfig implements WebMvcConfigurer {
    @Override
    public void addCorsMappings(CorsRegistry registry) {
        registry.addMapping("/test/**")     // 允许跨域的路径
                .allowedOrigins("*")       // 允许所有来源
                .allowedMethods("GET", "POST", "PUT", "OPTIONS")
                .allowedHeaders("*")       // 允许所有头部
                .exposedHeaders("*")
                .allowCredentials(false)    // 关闭凭据支持
                .maxAge(3600);             // 预检请求的有效期

    }
}

单页面

<!DOCTYPE html>
<html lang="zh-CN">
<head>
    <meta charset="UTF-8"/>
    <title>通用SQL查询页面</title>
    <!-- 引入 Element Plus 样式 -->
    <link rel="stylesheet" href="https://unpkg.com/element-plus/dist/index.css"/>
    <style>
        body {
            margin: 20px;
        }

        .form-container {
            margin-bottom: 20px;
        }

        .table-wrapper {
            max-height: 500px;
            overflow-y: auto;
        }

        .split-container {
            display: flex;
            gap: 20px;
        }

        .left-panel {
            flex: 1;
        }

        .right-panel {
            margin-top: 1rem;
            width: 100px;
            display: flex;
            flex-direction: column;
            gap: 15px;
            align-items: center;
        }
    </style>
</head>
<body>
<div id="app">
    <!-- SQL 查询表单 -->
    <el-card class="form-container">
        <el-form label-position="top" :model="form" @submit.prevent="fetchData">
            <div class="split-container">
                <!-- 左边 SQL 输入区 -->
                <div class="left-panel">
                    <el-form-item label="SQL语句" style="margin-bottom: 0;">
                        <template #label>
                            SQL语句
                            <span style="color: red; font-size: 12px; margin-left: 10px;">
                              (不可输入任何修改和删除相关的语句)
                            </span>
                            <span style="color: #00d28c; font-size: 12px; margin-left: 10px;">
                              (“--” 可以忽略单行语句,移除可添加筛选条件)
                            </span>
                        </template>
                        <el-input v-model="form.sql" type="textarea" rows="8" placeholder="请输入SQL语句"></el-input>
                    </el-form-item>
                </div>

                <!-- 右边参数+按钮 -->
                <div class="right-panel">
                    <el-button type="primary" @click="showApiRootDialog = true" style="width: 100%;">接口地址
                    </el-button>

                    <!-- 内置查询按钮 -->
                    <el-popover placement="left" trigger="click" width="250px">
                        <template #reference>
                            <el-button type="primary" style="width: 100%;">内置查询</el-button>
                        </template>
                        <div>
                            <h4 style="margin-top: 0;">预设查询列表</h4>
                            <ul style="list-style: none; padding-left: 0;">
                                <li v-for="(preset, index) in presetQueries" :key="index">
                                    <el-link @click="usePresetQuery(preset)" type="primary">{{ preset.name }}</el-link>
                                </li>
                            </ul>
                        </div>
                    </el-popover>

                    <!-- 历史按钮 -->
                    <el-button plain @click="showHistoryDialog = true" style="width: 100%;">历史查询</el-button>

                    <!-- 查询按钮 -->
                    <el-button type="success" native-type="submit" style="width: 100%;">查询</el-button>

                </div>
            </div>

        </el-form>
    </el-card>

    <!-- 表格展示 -->
    <el-table :data="tableData" border class="table-wrapper" v-loading="loading">
        <el-table-column v-for="(col, index) in columns" :key="index" :label="col">
            <template #default="scope">
          <span
                  :title="scope.row[col]"
                  @click="showFullContentDialog(scope.row[col])"
                  style="display: inline-block; max-width: 300px; white-space: nowrap; overflow: hidden; text-overflow: ellipsis; cursor: pointer;"
          >
            {{ scope.row[col] }}
          </span>
            </template>
        </el-table-column>
    </el-table>

    <!-- 查看完整内容弹窗 -->
    <el-dialog v-model="showContentDialog" title="完整内容" width="60%">
        <pre style="white-space: pre-wrap; word-wrap: break-word;">{{ fullContent }}</pre>
    </el-dialog>
    <!-- 分页组件 -->
  <div style="display: flex; justify-content: flex-end; align-items: center; margin-top: 20px;">
    <span style="margin-right: 15px; font-size: 14px;">共 {{ pageInfo.total }} 条</span>
    <el-pagination
            layout="prev, pager, next"
            :total="pageInfo.total"
            v-model:current-page="form.pageIndex"
            :page-size="form.pageSize"
            @current-change="handlePageChange"
            background
    />
  </div>
    <!-- 接口设置弹窗 -->
    <el-dialog v-model="showApiRootDialog" title="api设置">
        <el-form label-position="top">
            <!-- 接口地址 -->
            <el-form-item label="后端接口地址">
                <el-input v-model="apiUrl" placeholder="请输入后端接口地址"></el-input>
            </el-form-item>

            <!-- 每页条数 + 历史缓存条数 并排布局 -->
            <div style="display: flex; gap: 10px;">
                <el-form-item label="每页条数" style="flex: 1;">
                    <el-input-number v-model="form.pageSize" :min="1" :max="100" style="width: 100%;"></el-input-number>
                </el-form-item>
                <el-form-item label="历史缓存条数" style="flex: 1;">
                    <el-input-number v-model="historyCacheSize" :min="1" :max="50" style="width: 100%;"></el-input-number>
                </el-form-item>
            </div>
        </el-form>
        <template #footer>
            <el-button @click="showApiRootDialog = false">取消</el-button>
            <el-button type="primary" @click="saveRootPath">确定</el-button>
        </template>
    </el-dialog>

    <!-- 历史记录弹窗 -->
    <el-dialog v-model="showHistoryDialog" title="历史查询记录">
        <el-scrollbar style="height: 300px;">
            <ul style="list-style: none; padding-left: 0; margin: 0;">
                <li v-for="(item, index) in historyList" :key="index" style="padding: 8px 0 4px;">
                    <el-link @click="useHistory(item)" type="primary">{{ item }}</el-link>
                    <div v-if="index < historyList.length - 1"
                         style="border-bottom: 1px solid #eee; margin: 4px 0;"></div>
                </li>
            </ul>
        </el-scrollbar>
        <template #footer>
            <el-button @click="clearHistory">清空历史</el-button>
            <el-button @click="showHistoryDialog = false">关闭</el-button>
        </template>
    </el-dialog>
</div>

<!-- 引入 Vue 3 -->
<script src="https://unpkg.com/vue@3.4.15/dist/vue.global.prod.js"></script>
<!-- 引入 axios -->
<script src="https://unpkg.com/axios/dist/axios.min.js"></script>
<!-- 引入 Element Plus 组件库 -->
<script src="https://unpkg.com/element-plus/dist/index.full.min.js"></script>

<script>
    const {createApp} = Vue;

    createApp({
        data() {

            // 预设查询
            const presetQueries = [
                {name: "设施查询", sql: "  SELECT a.id AS \"设施Id\",a.name AS \"设施名称\",bt.name AS \"设施类型\",cc.CITY_NAME AS \"城市名称\",a.PROPERTIES as \"详细属性\",a.DISTRICT AS \"区县\"\n" +
                        "    FROM building a\n" +
                        "     LEFT JOIN BUILDING_TYPE bt ON a.TYPE=bt.ID\n" +
                        "     LEFT JOIN CITY_CONFIG cc ON a.city = cc.city_code\n" +
                        "     -- where bt.name = '供水厂'"},
                {name: "城市信息", sql: "  SELECT city_code AS \"城市编码\",city_name AS \"城市名称\",DISTRICTS AS \"区县\",CITY_CONFIG.SMS_ENABLE AS \"短信开关\"\n" +
                        "   FROM city_config"},
                {name: "指定时间区间预警数量统计", sql: "SELECT \"LEVEL\" AS \"预警等级\" ,count(1) AS \"触发次数\"\n" +
                        "FROM FORECAST_RAIN_LOG frl  \n" +
                        "WHERE frl.CREATE_TIME BETWEEN '2025-06-01 22:00:00.000' AND '2025-06-02 01:00:00.000' \n" +
                        "-- AND frl.\"LEVEL\" >0\n" +
                        "-- AND frl.RAIN_ID = 184\n" +
                        "GROUP BY frl.LEVEL"},
                {name: "短信发送记录", sql: "SELECT sl.CITY_CODE AS \"城市编码\",sl.CITY_NAME AS \"城市\",TO_CHAR(sl.SEND_TIME, 'YYYY-MM-DD HH24:MI:SS') AS \"发送时间\",sl.USERNAME AS \"接收人\",sl.PHONE AS \"手机号\",sl.CONTENT AS \"短信内容\",sl.WARNING_LEVEL AS \"预警等级\"\n" +
                        "FROM SMS_LOG sl\n" +
                        "WHERE 1=1 \n" +
                        "-- AND sl.CITY_NAME  = '百色市' \n" +
                        "-- AND sl.SEND_TIME BETWEEN '2025-05-01 22:00:00.000' AND '2025-06-02 01:00:00.000'\n" +
                        "-- AND sl.USERNAME = '黄科谕'\n" +
                        "ORDER BY sl.SEND_TIME DESC"},
                {name: "设施降雨预警历史记录", sql: "SELECT \n" +
                        "    b.id AS \"设施id\",b.name AS \"设施名称\",\n" +
                        "    a.val AS \"降雨量\", a.LEVEL AS \"预警等级\",\n" +
                        "    TO_CHAR(a.CREATE_TIME, 'yyyy-MM-dd HH24:mi:ss') as \"预警时间\",\n" +
                        "    cc.CITY_NAME AS \"城市\", cc.city_code AS \"城市编码\"\n" +
                        "FROM FORECAST_RAIN_LOG a   \n" +
                        "LEFT JOIN building b ON a.RAIN_ID = b.id\n" +
                        "LEFT JOIN CITY_CONFIG cc ON cc.city_code = b.city\n" +
                        "WHERE a.create_time > '2025-06-01 09:30:00' \n" +
                        "  AND a.create_time < '2025-06-03 14:30:30' \n" +
                        "  AND a.level > 0\n" +
                        "  --筛选i设施\n" +
                        "  -- AND b.id = 826\n" +
                        "  --筛选预警等级\n" +
                        "  -- AND a.level = 2\n" +
                        "ORDER BY a.CREATE_TIME ASC"},
                {name: "指定时间区间发生预警的设施", sql: "SELECT b.id AS \"设施id\",cc.CITY_NAME AS \"城市\",b.name AS \"设施名称\",b.PROPERTIES AS \"详细属性\"\n" +
                        "FROM building b \n" +
                        "LEFT JOIN CITY_CONFIG cc ON b.city = cc.CITY_CODE\n" +
                        "WHERE b.id in (\n" +
                        "\tSELECT DISTINCT frl.RAIN_ID  FROM FORECAST_RAIN_LOG frl \n" +
                        "WHERE frl.\"LEVEL\" >0  AND frl.CREATE_TIME BETWEEN '2025-06-01 22:00:00.000' AND '2025-06-02 01:00:00.000' \n" +
                        ")\n" +
                        "ORDER BY CITY_NAME"},
                {name: "当前触发短信预警的设施", sql: "WITH three_hour_records AS (\n" +
                        "                SELECT\n" +
                        "                    frl.*,\n" +
                        "                    ROW_NUMBER() OVER (PARTITION BY frl.RAIN_ID ORDER BY frl.CREATE_TIME DESC) as rn\n" +
                        "                FROM FORECAST_RAIN_LOG frl\n" +
                        "                WHERE frl.DURATION = 3\n" +
                        "                  -- 筛选最近3小时的数据\n" +
                        "                  AND frl.CREATE_TIME >= DATEADD(HOUR, -3, SYSDATE)\n" +
                        "            )\n" +
                        "         -- 查询降雨预警>0且三小时内没发短信的设施\n" +
                        "        ,constant_alert AS (\n" +
                        "            SELECT\n" +
                        "            t.RAIN_ID\n" +
                        "            FROM three_hour_records t\n" +
                        "            -- 最新预警等级大于0\n" +
                        "            WHERE t.rn =1 and t.LEVEL > 0\n" +
                        "            -- 且三小时内没有短信记录\n" +
                        "            AND NOT EXISTS (\n" +
                        "            SELECT 1 FROM SMS_LOG s\n" +
                        "            WHERE s.SEND_TIME >= DATEADD(HOUR, -3, SYSDATE)\n" +
                        "            AND s.building_ids LIKE '%'||t.RAIN_ID||'%'\n" +
                        "            )\n" +
                        "        )\n" +
                        "        -- 检测最新预警等级大于3小时内已发短信的预警等级的设施\n" +
                        "        ,risk_increased AS (\n" +
                        "          SELECT\n" +
                        "            l1.RAIN_ID\n" +
                        "            FROM three_hour_records l1\n" +
                        "            LEFT JOIN (\n" +
                        "                SELECT \n" +
                        "                    building_ids,\n" +
                        "                    WARNING_LEVEL,\n" +
                        "                    ROW_NUMBER() OVER (PARTITION BY building_ids ORDER BY SEND_TIME DESC) as sms_rn\n" +
                        "                FROM SMS_LOG\n" +
                        "                WHERE SEND_TIME >= DATEADD(HOUR, -3, SYSDATE)\n" +
                        "            ) s ON s.building_ids LIKE '%'||l1.RAIN_ID||'%' AND s.sms_rn = 1\n" +
                        "            WHERE l1.rn = 1\n" +
                        "            AND l1.LEVEL > s.WARNING_LEVEL\n" +
                        "        )\n" +
                        "        -- 合并两类需要发送短信的设施\n" +
                        "        SELECT\n" +
                        "            b.id, b.city AS cityCode, c.CITY_NAME AS cityName,\n" +
                        "            b.name, b.PROPERTIES,\n" +
                        "            lr.CREATE_TIME AS updatedAt,\n" +
                        "            lr.val as val,\n" +
                        "            lr.level as level\n" +
                        "        FROM building b\n" +
                        "        INNER JOIN (\n" +
                        "        \t-- 设施ID去重合并\n" +
                        "            SELECT RAIN_ID FROM risk_increased\n" +
                        "            UNION\n" +
                        "            SELECT RAIN_ID FROM constant_alert\n" +
                        "        ) combined ON b.id = combined.RAIN_ID\n" +
                        "        INNER JOIN three_hour_records lr ON b.id = lr.RAIN_ID AND lr.rn = 1\n" +
                        "        LEFT JOIN city_config c ON b.city = c.CITY_CODE\n" +
                        "        -- 只给内涝设施发送短信且城市开关打开\n" +
                        "        where b.type in (3,36) and c.sms_enable = 1"},
            ];
            // 获取本地缓存的 SQL,默认为空字符串
            const lastSql = localStorage.getItem('lastSql') || '';

            // 获取默认 SQL:优先用本地缓存,否则用第一个预设 SQL
            const defaultSql = lastSql || (presetQueries.length >  0 ? presetQueries[0].sql : '');

            return {
                apiUrl: localStorage.getItem('apiUrl') || 'http://192.168.10.160:9876/test/query/sql/page',
                form: {
                    sql: defaultSql,
                    pageSize: parseInt(localStorage.getItem('pageSize')) || 10,
                    pageIndex: 1
                },
                tableData: [],
                columns: [],
                pageInfo: {
                    total: 0,
                    pages: 0
                },
                loading: false,
                presetQueries: presetQueries,

                // 控制弹窗
                showApiRootDialog: false,
                showHistoryDialog: false,

                // 历史查询
                historyList: JSON.parse(localStorage.getItem('historySqls') || '[]'),
                historyCacheSize: parseInt(localStorage.getItem('historyCacheSize')) || 10,

                //单元格详情
                fullContent: '',
                showContentDialog: false
            };
        },
        methods: {
            async fetchData() {
                this.loading = true;

                if (!this.apiUrl || !this.form.sql.trim()) {
                    this.$message.warning("请填写完整的后端地址和SQL语句");
                    this.loading = false;
                    return;
                }

                try {
                    const res = await axios.post(this.apiUrl, {
                        sql: this.form.sql,
                        pageSize: this.form.pageSize,
                        pageIndex: this.form.pageIndex
                    });

                    if (res.data.code === 0 && res.data.data) {
                        this.tableData = res.data.data.records || [];
                        this.pageInfo.total = res.data.data.total || 0;
                        this.pageInfo.pages = res.data.data.pages || 0;
                        this.columns = this.tableData.length > 0 ? Object.keys(this.tableData[0]) : [];

                        // 只有在 SQL 不同的情况下才添加历史
                        const lastSql = localStorage.getItem('lastSql');
                        if (this.form.sql.trim() !== (lastSql || '')) {
                            this.addToHistory(this.form.sql);
                            localStorage.setItem('lastSql', this.form.sql);
                        }
                    } else {
                        this.$message.error(res.data.msg || '查询失败');
                    }
                } catch (err) {
                    this.$message.error('接口调用失败,请检查网络或SQL语句');
                    console.error(err);
                } finally {
                    this.loading = false;
                }
            },
            handlePageChange(page) {
                this.form.pageIndex = page;
                this.fetchData();
            },
            saveRootPath() {
                localStorage.setItem('apiUrl', this.apiUrl);
                localStorage.setItem('pageSize', this.form.pageSize);
                localStorage.setItem('historyCacheSize', this.historyCacheSize);
                this.showApiRootDialog = false;
            },
            useHistory(sql) {
                this.form.sql = sql;
                this.showHistoryDialog = false;
                this.fetchData();
            },
            showFullContentDialog(content) {
                this.fullContent = content;
                this.showContentDialog = true;
            },
            addToHistory(sql) {
                let index = this.historyList.indexOf(sql);
                if (index !== -1) {
                    this.historyList.splice(index, 1); // 移除旧的
                }
                this.historyList.unshift(sql);

                // 使用 historyCacheSize 控制最大缓存条数
                this.historyList = this.historyList.slice(0, this.historyCacheSize);

                localStorage.setItem('historySqls', JSON.stringify(this.historyList));
            },
            clearHistory() {
                this.historyList = [];
                localStorage.removeItem('historySqls');
            },
            usePresetQuery(preset) {
                this.form.sql = preset.sql;
                this.fetchData(); // 可选:点击即自动查询
            },
        }
    }).use(ElementPlus).mount('#app');
</script>
</body>
</html>


网站公告

今日签到

点亮在社区的每一天
去签到