You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

44 KiB

RFID 读取记录分表查询设计说明

说明:本文件聚焦 “读取记录(rfid_read_record)按日期分表 + 分页/列表查询/采样查询” 的完整实现链路。

  • 前端:Cambodia-TBR-RFID-ui/src/views/rfid/rfidReadRecord/index.vue
  • 后端工具类:RfidReadRecordTableHelper
  • ServiceRfidReadRecordServiceImpl
  • MapperRfidReadRecordMapper.xml 中与分表/分页/采样直接相关的 SQL

其余与 UI 展示或通用 CRUD 相关但不影响分表逻辑的代码在原文件中可查看,这里只保留与“分表查询”强相关的关键代码,并在代码中补充注释。


1. 分表设计与整体调用链

1.1 分表策略

  • 按天分表
    • 物理表名格式:rfid_read_record_yyyyMMdd,例如:rfid_read_record_20251126
    • 基础表名常量:RfidReadRecordTableHelper.BASE_TABLE_NAME = "rfid_read_record"
  • 路由规则
    • 写入(新增/修改):根据记录的 recordTime 计算出表名。
    • 读取/删除:
      • 列表/分页:根据 beginRecordTime ~ endRecordTime 算出涉及到的日期区间,再映射为多个分表名,并过滤掉数据库中不存在的分表。
      • 按主键查询/删除:前端必须携带一个 查询日期 queryDate(由前端从 recordTime 截取 yyyy-MM-dd 得到),后端据此定位具体分表。
  • 表存在校验与缓存
    • 通过 information_schema.tables 检查表是否存在,并在内存中做 5 分钟缓存,避免频繁访问元数据。

1.2 前后端调用链总览

  1. 前端页面 rfidReadRecord/index.vue

    • 用户在查询表单中选择:设备、读取状态、条码、时间范围(dateRange)、告警标志等条件。
    • 点击“搜索”时,前端把 dateRange 拆成 beginRecordTime / endRecordTime 放入 queryParams,调用 listRfidReadRecord 接口获取分页数据。
    • 选中行时,前端会把被选中记录的 recordTime(取日期部分)缓存到 selectedRecordTimes,用于后续 修改/删除 操作时传给后端作为 queryDate 参数,精确定位分表。
  2. Service 层 RfidReadRecordServiceImpl

    • 列表/分页查询:
      • 使用 RfidReadRecordTableHelper.getExistingTableNames(beginRecordTime, endRecordTime) 得到实际存在的分表列表。
      • 若只涉及一张分表,则走单表查询 SQL若涉及多张分表则走多表 UNION ALL 聚合查询 SQL。
    • 单条查询/删除:
      • 根据前端传入的 queryDate 计算表名,再调用 Mapper 对应的单表 SQL。
    • 新增/修改:
      • 根据实体中的 recordTime 计算表名,路由到对应分表执行 insert/update。
  3. 分表工具类 RfidReadRecordTableHelper

    • 对日期与表名之间的映射做统一封装:
      • getTableName(Date) / getTableName(LocalDate) / getTodayTableName()
      • getTableNames(beginDate, endDate):生成日期区间内所有候选表名。
      • checkTableExists(tableName) / getExistingTableNames(beginDate, endDate):通过 information_schema + 本地缓存过滤出 实际存在 的分表。
  4. Mapper XML RfidReadRecordMapper.xml

    • 所有 SQL 都通过 ${tableName}${tbl} 动态引用具体分表名,避免硬编码。
    • 针对单表 / 多表 / 采样查询提供不同的 SQL
      • 单表:selectCustomRfidReadRecordVoPage / selectCustomRfidReadRecordVoList / insertRfidReadRecord / updateRfidReadRecordById / deleteCustomRfidReadRecordByIds
      • 多表 UNIONselectCustomRfidReadRecordVoPageMultiTable / selectCustomRfidReadRecordVoListMultiTable / countCustomRfidReadRecordMultiTable
      • 采样查询:selectWithSampling / selectWithSamplingMultiTable,通过时间槽 time_slot 减少大数据量查询的记录数。

2. 前端实现:rfidReadRecord/index.vue

本节只贴出与 分表查询 强相关的前端代码:

  • 查询条件中关于“记录时间”的部分(dateRange)。
  • 脚本中对 dateRange 的处理(拆分成 beginRecordTime / endRecordTime)。
  • 列表多选时记录每行的 recordTime,并存入 selectedRecordTimes
  • 修改 / 删除时,将选中行的日期部分作为 queryDate 传给后端。

2.1 模板中与时间/选择相关的片段

<!-- file: Cambodia-TBR-RFID-ui/src/views/rfid/rfidReadRecord/index.vue -->
<template>
  <div class="p-2">
    <!-- 查询区域包含记录时间范围影响分表范围 -->
    <transition :enter-active-class="proxy?.animate.searchAnimate.enter" :leave-active-class="proxy?.animate.searchAnimate.leave">
      <div v-show="showSearch" class="mb-[10px]">
        <el-card shadow="hover">
          <el-form ref="queryFormRef" :model="queryParams" :inline="true">
            <!-- 设备名称、省略部分字段 -->

            <!-- 记录时间使用 datetimerange前端负责选定一个时间区间 -->
            <el-form-item label="记录时间" style="width: 308px">
              <el-date-picker
                v-model="dateRange"                  <!-- 绑定到本地状态 dateRange -->
                value-format="YYYY-MM-DD HH:mm:ss"   <!-- 与后端期望的时间字符串格式一致 -->
                type="datetimerange"
                range-separator="-"
                start-placeholder="开始日期"
                end-placeholder="结束日期"
                :default-time="[new Date(2000, 1, 1, 0, 0, 0), new Date(2000, 1, 1, 23, 59, 59)]"
              />
            </el-form-item>

            <!-- 搜索/重置按钮 -->
            <el-form-item>
              <el-button type="primary" icon="Search" @click="handleQuery">搜索</el-button>
              <el-button icon="Refresh" @click="resetQuery">重置</el-button>
            </el-form-item>
          </el-form>
        </el-card>
      </div>
    </transition>

    <!-- 列表区域 -->
    <el-card shadow="never">
      <template #header>
        <el-row :gutter="10" class="mb8">
          <!-- 这里只保留导出按钮及右侧工具栏,新增/修改/删除按钮已按需注释 -->
          <el-col :span="1.5">
            <el-button type="warning" plain icon="Download" @click="handleExport" v-hasPermi="['rfid:rfidReadRecord:export']">导出</el-button>
          </el-col>
          <right-toolbar v-model:showSearch="showSearch" :columns="columns" :search="true" @queryTable="getList" />
        </el-row>
      </template>

      <!-- 表格:展示记录时间、设备信息等 -->
      <el-table v-loading="loading" border :data="rfidReadRecordList" @selection-change="handleSelectionChange">
        <el-table-column type="selection" width="55" align="center" />
        <el-table-column type="index" width="55" align="center" label="序号" />
        <!-- 省略部分列定义,仅保留与分表无关的展示逻辑 -->
        <el-table-column label="记录时间" align="center" prop="recordTime" width="180" v-if="columns[4].visible">
          <template #default="scope">
            <!-- 使用 parseTime 将后端时间戳格式化为字符串展示 -->
            <span>{{ parseTime(scope.row.recordTime, '{y}-{m}-{d} {h}:{i}:{s}') }}</span>
          </template>
        </el-table-column>
      </el-table>

      <!-- 分页组件 queryParams.pageNum / pageSize 双向绑定 -->
      <pagination
        v-show="total > 0"
        :total="total"
        v-model:page="queryParams.pageNum"
        v-model:limit="queryParams.pageSize"
        @pagination="getList"
      />
    </el-card>
  </div>
</template>

2.2 脚本逻辑:时间范围拆分、分表日期传递

// file: Cambodia-TBR-RFID-ui/src/views/rfid/rfidReadRecord/index.vue
<script setup name="RfidReadRecord" lang="ts">
import { listRfidReadRecord, getRfidReadRecord, delRfidReadRecord, addRfidReadRecord, updateRfidReadRecord } from "@/api/rfid/rfidReadRecord";
import { RfidReadRecordVO, RfidReadRecordQuery, RfidReadRecordForm } from '@/api/rfid/rfidReadRecord/types';
import { getRfidDeviceList } from "@/api/rfid/rfidDevice";
import type { RfidDeviceVO } from '@/api/rfid/rfidDevice/types';

const { proxy } = getCurrentInstance() as ComponentInternalInstance;
const { read_status, alarm_level, alarm_flag } = toRefs<any>(proxy?.useDict('read_status', 'alarm_level', 'alarm_flag'));

// 列表数据 & 状态
const rfidReadRecordList = ref<RfidReadRecordVO[]>([]);
const buttonLoading = ref(false);
const loading = ref(true);
const showSearch = ref(true);

// 勾选的主键 ID 列表
const ids = ref<Array<string | number>>([]);

// 当前选中行的记录时间(仅取日期部分 yyyy-MM-dd用于后端分表定位 queryDate
const selectedRecordTimes = ref<string[]>([]);

const single = ref(true);
const multiple = ref(true);
const total = ref(0);

// 查询参数 + 表单
const columns = ref<FieldOption[]>([ /* 省略列配置 */ ]);

const queryFormRef = ref<ElFormInstance>();
const rfidReadRecordFormRef = ref<ElFormInstance>();

const dialog = reactive<DialogOption>({
  visible: false,
  title: ''
});

const deviceOptions = ref<RfidDeviceVO[]>([]);

// 记录时间范围(默认当天),用于前端控制查询时间区间,从而影响后端分表范围
const dateRange = ref<[string, string] | []>([]);

/**
 * 初始化默认时间范围:当天 00:00:00 ~ 23:59:59
 *
 * 业务含义:如果用户不主动选择时间,则默认只查“当天分表”,
 * 减少跨表查询的数据量,提高性能。
 */
const initDefaultDateRange = () => {
  const today = new Date();
  const year = today.getFullYear();
  const month = String(today.getMonth() + 1).padStart(2, '0');
  const day = String(today.getDate()).padStart(2, '0');
  const dateStr = `${year}-${month}-${day}`;
  dateRange.value = [`${dateStr} 00:00:00`, `${dateStr} 23:59:59`];
};

// 查询参数对象,包含 beginRecordTime / endRecordTime 两个字段,供后端计算分表范围
const initFormData: RfidReadRecordForm = {
  id: undefined,
  deviceId: undefined,
  readStatus: undefined,
  barcode: undefined,
  recordTime: undefined,
  alarmFlag: undefined,
  alarmLevel: undefined,
  alarmType: undefined,
  alarmAction: undefined
};

const data = reactive<PageData<RfidReadRecordForm, RfidReadRecordQuery>>({
  form: { ...initFormData },
  queryParams: {
    pageNum: 1,
    pageSize: 10,
    deviceId: undefined,
    readStatus: undefined,
    barcode: undefined,
    // 这两个字段会在 getList 中根据 dateRange 自动赋值
    beginRecordTime: undefined,
    endRecordTime: undefined,
    alarmFlag: undefined,
    alarmLevel: undefined,
    alarmType: undefined,
    alarmAction: undefined,
    params: {}
  },
  rules: { /* 省略与分表无关的校验规则 */ }
});

const { queryParams, form, rules } = toRefs(data);

/**
 * 查询读取记录列表(分页)
 *
 * 关键:在调用后端接口前,根据 dateRange 设置 bo.beginRecordTime / bo.endRecordTime
 *       后端将用这两个字段决定要访问哪些分表。
 */
const getList = async () => {
  loading.value = true;
  // 处理日期范围参数:如果选择了时间区间,则填充 beginRecordTime / endRecordTime
  if (dateRange.value && dateRange.value.length === 2) {
    queryParams.value.beginRecordTime = dateRange.value[0];
    queryParams.value.endRecordTime = dateRange.value[1];
  } else {
    // 未选择时间时,清空时间条件,由后端决定默认行为(通常是查询当天)
    queryParams.value.beginRecordTime = undefined;
    queryParams.value.endRecordTime = undefined;
  }

  // 调用后端分页接口,后端会基于 beginRecordTime/endRecordTime 动态路由到一个或多个分表
  const res = await listRfidReadRecord(queryParams.value);
  rfidReadRecordList.value = res.rows;
  total.value = res.total;
  loading.value = false;
};

/**
 * 多选框选中数据
 *
 * 关键:保存选中行的 recordTime只取日期部分后续修改/删除时用来作为 queryDate
 *       传给后端,使后端能精确定位主键所在的物理分表。
 */
const handleSelectionChange = (selection: RfidReadRecordVO[]) => {
  ids.value = selection.map(item => item.id);
  // 保存选中行的记录时间yyyy-MM-dd用于分表定位
  selectedRecordTimes.value = selection.map(item => item.recordTime?.substring(0, 10) || '');
  single.value = selection.length != 1;
  multiple.value = !selection.length;
};

/** 查询按钮操作:重置页码并发起查询 */
const handleQuery = () => {
  queryParams.value.pageNum = 1;
  getList();
};

/** 重置按钮:重置条件并默认查询当天 */
const resetQuery = () => {
  initDefaultDateRange();
  queryFormRef.value?.resetFields();
  handleQuery();
};

/**
 * 修改按钮操作
 *
 * 关键:在调用 getRfidReadRecord 时,除了 id 以外,还传递 queryDate
 *       后端使用该日期来计算分表表名rfid_read_record_yyyyMMdd */
const handleUpdate = async (row?: RfidReadRecordVO) => {
  reset();
  const _id = row?.id || ids.value[0];
  // 获取查询日期(用于分表定位):优先使用行数据的 recordTime其次使用已选中的日期
  const queryDate = row?.recordTime?.substring(0, 10) || selectedRecordTimes.value[0];

  // 调用后端查询单条记录接口,参数包含 id + queryDate
  const res = await getRfidReadRecord(_id, queryDate);
  Object.assign(form.value, res.data);
  dialog.visible = true;
  dialog.title = "修改读取记录";
};

/**
 * 删除按钮操作
 *
 * 同样需要 queryDate 用于定位分表,否则后端无法确定主键所在物理表。
 */
const handleDelete = async (row?: RfidReadRecordVO) => {
  const _ids = row?.id || ids.value;
  const queryDate = row?.recordTime?.substring(0, 10) || selectedRecordTimes.value[0];
  try {
    await proxy?.$modal.confirm('是否确认删除读取记录编号为"' + _ids + '"的数据项?');
    loading.value = true;
    // 调用删除接口时同时传递 ids + queryDate
    await delRfidReadRecord(_ids, queryDate);
    proxy?.$modal.msgSuccess("删除成功");
    await getList();
  } finally {
    loading.value = false;
  }
};

/** 页面加载时:初始化默认时间范围并立即查询 */
onMounted(() => {
  initDefaultDateRange();
  getList();
  loadDeviceOptions();
});

</script>

3. 分表工具类:RfidReadRecordTableHelper

该工具类封装了 日期 ↔ 分表表名 的转换逻辑,以及基于 information_schema 的表存在检查与本地缓存,供 Service 在查询/写入前使用。

下面只摘取与分表查询强相关的核心方法,并在代码中加上注释。

// file: rfid-middleware/ruoyi-modules/hw-rfid/src/main/java/org/dromara/rfid/helper/RfidReadRecordTableHelper.java
package org.dromara.rfid.helper;

import cn.hutool.core.date.DateUtil;
import cn.hutool.core.util.StrUtil;
import lombok.extern.slf4j.Slf4j;
import org.dromara.common.core.utils.SpringUtils;

import javax.sql.DataSource;
import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.time.LocalDate;
import java.time.format.DateTimeFormatter;
import java.util.ArrayList;
import java.util.Date;
import java.util.List;
import java.util.Map;
import java.util.concurrent.ConcurrentHashMap;
import java.util.stream.Collectors;

/**
 * RFID 读取记录分表工具类
 *
 * 按日期分表表名格式rfid_read_record_yyyyMMdd
 */
@Slf4j
public class RfidReadRecordTableHelper {

    /** 基础表名,不带日期后缀 */
    public static final String BASE_TABLE_NAME = "rfid_read_record";

    /** 日期格式yyyyMMdd用于拼接表名后缀 */
    private static final DateTimeFormatter DATE_FORMATTER = DateTimeFormatter.ofPattern("yyyyMMdd");

    /**
     * 表存在缓存key = 表名value = 是否存在。
     *
     * 只缓存“存在”的表,避免后续每次都查 information_schema
     * 不缓存“不存在”的表,以便新建分表后能够尽快被识别到。
     */
    private static final Map<String, Boolean> TABLE_EXISTS_CACHE = new ConcurrentHashMap<>(64);

    /** 上次刷新缓存的时间戳 */
    private static volatile long lastCacheRefreshTime = System.currentTimeMillis();

    /** 缓存有效期5 分钟 */
    private static final long CACHE_EXPIRE_MS = 5 * 60 * 1000L;

    private RfidReadRecordTableHelper() {
    }

    /** 手动清理缓存(例如新建分表后可调用) */
    public static void clearTableExistsCache() {
        TABLE_EXISTS_CACHE.clear();
        lastCacheRefreshTime = System.currentTimeMillis();
        log.debug("分表缓存已清除");
    }

    /**
     * 根据 java.util.Date 获取表名
     *
     * @param date 记录时间
     * @return 物理表名,如 rfid_read_record_20251126
     */
    public static String getTableName(Date date) {
        if (date == null) {
            date = new Date(); // 为空时默认当天
        }
        String dateSuffix = DateUtil.format(date, "yyyyMMdd");
        return BASE_TABLE_NAME + "_" + dateSuffix;
    }

    /**
     * 根据 LocalDate 获取表名
     */
    public static String getTableName(LocalDate localDate) {
        if (localDate == null) {
            localDate = LocalDate.now();
        }
        return BASE_TABLE_NAME + "_" + localDate.format(DATE_FORMATTER);
    }

    /** 获取当天对应的分表表名 */
    public static String getTodayTableName() {
        return getTableName(LocalDate.now());
    }

    /**
     * 根据日期范围获取所有候选表名列表(不做存在性校验)
     *
     * 场景:分页/列表查询,先根据 beginRecordTime / endRecordTime 确定日期区间,
     * 然后再交给 getExistingTableNames 过滤出真实存在的分表。
     */
    public static List<String> getTableNames(Date beginDate, Date endDate) {
        List<String> tableNames = new ArrayList<>();

        if (beginDate == null && endDate == null) {
            // 如果前端未传时间,默认只查当天分表
            tableNames.add(getTodayTableName());
            return tableNames;
        }

        // 处理单边日期为空的情况:缺失一端则默认为当天
        LocalDate start = beginDate != null
            ? DateUtil.toLocalDateTime(beginDate).toLocalDate()
            : LocalDate.now();
        LocalDate end = endDate != null
            ? DateUtil.toLocalDateTime(endDate).toLocalDate()
            : LocalDate.now();

        // 确保 start <= end
        if (start.isAfter(end)) {
            LocalDate temp = start;
            start = end;
            end = temp;
        }

        // 按天递增遍历,依次拼接表名
        LocalDate current = start;
        while (!current.isAfter(end)) {
            tableNames.add(getTableName(current));
            current = current.plusDays(1);
        }

        return tableNames;
    }

    /**
     * 从表名中解析日期后缀(例如 rfid_read_record_20251126 → 20251126
     */
    public static String parseDateSuffix(String tableName) {
        if (StrUtil.isBlank(tableName) || !tableName.startsWith(BASE_TABLE_NAME + "_")) {
            return null;
        }
        return tableName.substring((BASE_TABLE_NAME + "_").length());
    }

    /**
     * 检查表是否存在(带缓存)
     *
     * 1. 先判断缓存是否过期,过期则清空缓存;
     * 2. 若缓存中已有该表名,则直接返回;
     * 3. 否则访问 information_schema 做一次真实校验,并仅缓存“存在”的表。
     */
    public static boolean checkTableExists(String tableName) {
        long now = System.currentTimeMillis();
        if (now - lastCacheRefreshTime > CACHE_EXPIRE_MS) {
            // 缓存过期,清除后重新统计
            TABLE_EXISTS_CACHE.clear();
            lastCacheRefreshTime = now;
        }

        // 先从缓存中读取
        Boolean cached = TABLE_EXISTS_CACHE.get(tableName);
        if (cached != null) {
            return cached;
        }

        // 执行真实检查
        boolean exists = doCheckTableExists(tableName);

        // 只缓存“存在”的表
        if (exists) {
            TABLE_EXISTS_CACHE.put(tableName, Boolean.TRUE);
        }

        return exists;
    }

    /**
     * 通过 information_schema 查询表是否存在
     */
    private static boolean doCheckTableExists(String tableName) {
        try {
            DataSource dataSource = SpringUtils.getBean(DataSource.class);
            try (Connection conn = dataSource.getConnection()) {
                String sql = "SELECT 1 FROM information_schema.tables WHERE table_schema = DATABASE() AND table_name = ? LIMIT 1";
                try (PreparedStatement stmt = conn.prepareStatement(sql)) {
                    stmt.setString(1, tableName);
                    try (ResultSet rs = stmt.executeQuery()) {
                        return rs.next();
                    }
                }
            }
        } catch (Exception e) {
            log.warn("检查表 {} 是否存在时出错: {}", tableName, e.getMessage());
            return false;
        }
    }

    /**
     * 根据日期范围获取所有实际存在的表名列表
     *
     * Service 层在分页/列表查询前调用本方法,避免访问不存在的分表导致 SQL 报错。
     */
    public static List<String> getExistingTableNames(Date beginDate, Date endDate) {
        List<String> allTableNames = getTableNames(beginDate, endDate);
        return allTableNames.stream()
            .filter(RfidReadRecordTableHelper::checkTableExists)
            .collect(Collectors.toList());
    }
}

4. Service 层:RfidReadRecordServiceImpl

RfidReadRecordServiceImpl 是业务入口,负责:

  • 通过 RfidReadRecordTableHelper 决定要访问的分表;
  • 调用 Mapper 中的单表/多表/采样 SQL
  • 在新增/修改/删除时根据 recordTimequeryDate 精确定位物理表。
// file: rfid-middleware/ruoyi-modules/hw-rfid/src/main/java/org/dromara/rfid/service/impl/RfidReadRecordServiceImpl.java
package org.dromara.rfid.service.impl;

import cn.hutool.core.collection.CollUtil;
import cn.hutool.core.util.IdUtil;
import org.dromara.common.core.exception.ServiceException;
import org.dromara.common.core.utils.MapstructUtils;
import org.dromara.common.core.utils.StringUtils;
import org.dromara.common.mybatis.core.page.TableDataInfo;
import org.dromara.common.mybatis.core.page.PageQuery;
import com.baomidou.mybatisplus.extension.plugins.pagination.Page;
import com.baomidou.mybatisplus.core.conditions.query.LambdaQueryWrapper;
import com.baomidou.mybatisplus.core.toolkit.Wrappers;
import lombok.RequiredArgsConstructor;
import lombok.extern.slf4j.Slf4j;
import org.dromara.rfid.helper.RfidReadRecordTableHelper;
import org.springframework.stereotype.Service;
import org.springframework.transaction.annotation.Transactional;
import org.dromara.rfid.domain.bo.RfidReadRecordBo;
import org.dromara.rfid.domain.vo.RfidReadRecordVo;
import org.dromara.rfid.domain.RfidReadRecord;
import org.dromara.rfid.mapper.RfidReadRecordMapper;
import org.dromara.rfid.service.IRfidReadRecordService;

import java.util.Date;
import java.util.List;
import java.util.Collection;

/**
 * 读取记录 Service 实现
 *
 * 支持按日期分表表名格式rfid_read_record_yyyyMMdd
 */
@Slf4j
@RequiredArgsConstructor
@Service
public class RfidReadRecordServiceImpl implements IRfidReadRecordService {

    private final RfidReadRecordMapper baseMapper;

    /**
     * 根据主键 + 查询日期查询单条记录
     *
     * @param id        主键
     * @param queryDate 查询日期yyyy-MM-dd由前端从 recordTime 截取而来
     */
    @Override
    public RfidReadRecordVo queryById(Long id, Date queryDate) {
        // 通过查询日期计算分表表名
        String tableName = RfidReadRecordTableHelper.getTableName(queryDate);
        return baseMapper.selectCustomRfidReadRecordVoById(tableName, id);
    }

    /**
     * 分页查询读取记录列表
     *
     * 根据 beginRecordTime / endRecordTime 计算涉及到的分表列表,
     * 无表则直接返回空分页;单表使用单表分页 SQL多表则使用 UNION ALL 聚合 SQL。
     */
    @Override
    public TableDataInfo<RfidReadRecordVo> queryPageList(RfidReadRecordBo bo, PageQuery pageQuery) {
        // 1. 根据时间范围计算实际存在的分表列表
        List<String> tableNames = RfidReadRecordTableHelper.getExistingTableNames(
            bo.getBeginRecordTime(), bo.getEndRecordTime());

        // 2. 没有任何分表存在,直接返回空分页
        if (CollUtil.isEmpty(tableNames)) {
            return TableDataInfo.build(new Page<>());
        }

        // 3. 构建 MyBatis-Plus 查询条件(仅负责 WHERE不负责 ORDER BY
        LambdaQueryWrapper<RfidReadRecord> lqw = buildQueryWrapper(bo);

        // 4. 根据分表数量选择单表 or 多表分页 SQL
        Page<RfidReadRecordVo> result = tableNames.size() == 1
            ? baseMapper.selectCustomRfidReadRecordVoPage(tableNames.get(0), pageQuery.build(), lqw)
            : baseMapper.selectCustomRfidReadRecordVoPageMultiTable(tableNames, pageQuery.build(), lqw);

        return TableDataInfo.build(result);
    }

    /**
     * 查询符合条件的读取记录列表(非分页)
     *
     * 支持采样查询:当 samplingInterval > 1 时,按 N 分钟一个时间槽进行抽样,
     * 降低大数据量查询时的返回记录数。
     */
    @Override
    public List<RfidReadRecordVo> queryList(RfidReadRecordBo bo) {
        // 1. 获取时间范围内实际存在的分表
        List<String> tableNames = RfidReadRecordTableHelper.getExistingTableNames(
            bo.getBeginRecordTime(), bo.getEndRecordTime());

        if (CollUtil.isEmpty(tableNames)) {
            return List.of();
        }

        LambdaQueryWrapper<RfidReadRecord> lqw = buildQueryWrapper(bo);

        // 2. 判断是否使用采样查询
        Integer samplingInterval = bo.getSamplingInterval();
        if (samplingInterval != null && samplingInterval > 1) {
            // 采样查询:每 N 分钟取一条最新记录作为代表
            return tableNames.size() == 1
                ? baseMapper.selectWithSampling(tableNames.get(0), samplingInterval, lqw)
                : baseMapper.selectWithSamplingMultiTable(tableNames, samplingInterval, lqw);
        }

        // 3. 普通查询:按单表 / 多表分别调用不同 SQL
        return tableNames.size() == 1
            ? baseMapper.selectCustomRfidReadRecordVoList(tableNames.get(0), lqw)
            : baseMapper.selectCustomRfidReadRecordVoListMultiTable(tableNames, lqw);
    }

    /**
     * 构建查询条件 Wrapper
     *
     * 说明:
     * - 索引字段优先device_id, record_time
     * - 其他条件按需追加Mapper XML 中的 ${ew.customSqlSegment} 会拼接到 WHERE 之后。
     */
    private LambdaQueryWrapper<RfidReadRecord> buildQueryWrapper(RfidReadRecordBo bo) {
        LambdaQueryWrapper<RfidReadRecord> lqw = Wrappers.lambdaQuery();
        // 索引字段:设备 ID
        lqw.eq(bo.getDeviceId() != null, RfidReadRecord::getDeviceId, bo.getDeviceId());

        // 索引字段:记录时间范围
        if (bo.getBeginRecordTime() != null && bo.getEndRecordTime() != null) {
            lqw.between(RfidReadRecord::getRecordTime, bo.getBeginRecordTime(), bo.getEndRecordTime());
        } else {
            lqw.ge(bo.getBeginRecordTime() != null, RfidReadRecord::getRecordTime, bo.getBeginRecordTime());
            lqw.le(bo.getEndRecordTime() != null, RfidReadRecord::getRecordTime, bo.getEndRecordTime());
        }

        // 其他非必选条件
        lqw.eq(StringUtils.isNotBlank(bo.getReadStatus()), RfidReadRecord::getReadStatus, bo.getReadStatus());
        lqw.eq(StringUtils.isNotBlank(bo.getBarcode()), RfidReadRecord::getBarcode, bo.getBarcode());
        lqw.eq(StringUtils.isNotBlank(bo.getAlarmFlag()), RfidReadRecord::getAlarmFlag, bo.getAlarmFlag());
        lqw.eq(StringUtils.isNotBlank(bo.getAlarmLevel()), RfidReadRecord::getAlarmLevel, bo.getAlarmLevel());
        lqw.eq(StringUtils.isNotBlank(bo.getAlarmType()), RfidReadRecord::getAlarmType, bo.getAlarmType());
        lqw.eq(StringUtils.isNotBlank(bo.getAlarmAction()), RfidReadRecord::getAlarmAction, bo.getAlarmAction());
        return lqw;
    }

    /**
     * 新增读取记录:根据 recordTime 路由到对应分表
     */
    @Override
    @Transactional(rollbackFor = Exception.class)
    public Boolean insertByBo(RfidReadRecordBo bo) {
        RfidReadRecord add = MapstructUtils.convert(bo, RfidReadRecord.class);
        validEntityBeforeSave(add);

        // 自定义 SQL 不会自动生成 ID需要手动生成雪花 ID
        if (add.getId() == null) {
            add.setId(IdUtil.getSnowflakeNextId());
        }

        // 根据记录时间路由到具体分表
        String tableName = RfidReadRecordTableHelper.getTableName(add.getRecordTime());
        boolean flag = baseMapper.insertRfidReadRecord(tableName, add) > 0;
        if (flag) {
            bo.setId(add.getId());
        }
        return flag;
    }

    /**
     * 修改读取记录:同样根据 recordTime 路由到对应分表
     */
    @Override
    @Transactional(rollbackFor = Exception.class)
    public Boolean updateByBo(RfidReadRecordBo bo) {
        RfidReadRecord update = MapstructUtils.convert(bo, RfidReadRecord.class);
        validEntityBeforeSave(update);

        String tableName = RfidReadRecordTableHelper.getTableName(update.getRecordTime());
        return baseMapper.updateRfidReadRecordById(tableName, update) > 0;
    }

    /**
     * 基础校验:空对象校验 + 条码非空校验
     */
    private void validEntityBeforeSave(RfidReadRecord entity) {
        if (entity == null) {
            throw new ServiceException("读取记录不能为空");
        }

        if (entity.getBarcode() != null) {
            entity.setBarcode(entity.getBarcode().trim());
        }

        // 读取成功readStatus = 1时条码必须有值
        if ("1".equals(entity.getReadStatus()) && StringUtils.isBlank(entity.getBarcode())) {
            throw new ServiceException("读取成功时条码信息不能为空");
        }
    }

    /**
     * 批量删除:根据 queryDate 决定分表
     */
    @Override
    @Transactional(rollbackFor = Exception.class)
    public Boolean deleteWithValidByIds(Collection<Long> ids, Date queryDate, Boolean isValid) {
        if (CollUtil.isEmpty(ids)) {
            return Boolean.TRUE;
        }
        String tableName = RfidReadRecordTableHelper.getTableName(queryDate);
        return baseMapper.deleteCustomRfidReadRecordByIds(tableName, ids) > 0;
    }
}

5. Mapper XMLRfidReadRecordMapper.xml(分表相关 SQL

本节仅保留与分表查询和分页/采样直接相关的 SQL其他看板/统计类 SQL 因与分表模式相同,读取时可类推。

5.1 单表查询/分页

<!-- file: rfid-middleware/ruoyi-modules/hw-rfid/src/main/resources/mapper/rfid/RfidReadRecordMapper.xml -->
<mapper namespace="org.dromara.rfid.mapper.RfidReadRecordMapper">

    <!-- 通用结果映射(字段在 SQL 中直接显式列出) -->
    <resultMap type="org.dromara.rfid.domain.vo.RfidReadRecordVo" id="RfidReadRecordResult">
    </resultMap>

    <!-- 查询列表(单表) -->
    <select id="selectCustomRfidReadRecordVoList" resultMap="RfidReadRecordResult">
        select t.id,
               t.device_id,
               d.device_code as deviceCode,
               d.device_name as deviceName,
               t.read_status,
               t.barcode,
               t.record_time,
               t.alarm_flag,
               t.alarm_level,
               t.alarm_type,
               t.alarm_action
        from ${tableName} t                      <!-- 由 Service 传入具体分表名,如 rfid_read_record_20251126 -->
        left join rfid_device d on t.device_id = d.id
        <if test="ew != null">
            ${ew.customSqlSegment}              <!-- 拼接 MyBatis-Plus 生成的 WHERE 条件 -->
        </if>
        order by t.record_time desc
    </select>

    <!-- 分页查询(单表) -->
    <select id="selectCustomRfidReadRecordVoPage" resultMap="RfidReadRecordResult">
        select t.id,
               t.device_id,
               d.device_code as deviceCode,
               d.device_name as deviceName,
               t.read_status,
               t.barcode,
               t.record_time,
               t.alarm_flag,
               t.alarm_level,
               t.alarm_type,
               t.alarm_action
        from ${tableName} t
        left join rfid_device d on t.device_id = d.id
        <if test="ew != null">
            ${ew.customSqlSegment}
        </if>
        order by t.record_time desc
    </select>

    <!-- 根据 ID 查询详情(单表) -->
    <select id="selectCustomRfidReadRecordVoById" resultMap="RfidReadRecordResult">
        select t.id,
               t.device_id,
               d.device_code as deviceCode,
               d.device_name as deviceName,
               t.read_status,
               t.barcode,
               t.record_time,
               t.alarm_flag,
               t.alarm_level,
               t.alarm_type,
               t.alarm_action
        from ${tableName} t
        left join rfid_device d on t.device_id = d.id
        where t.id = #{id}
    </select>

    <!-- 单条插入:由 Service 根据 recordTime 传入对应分表名 -->
    <insert id="insertRfidReadRecord">
        insert into ${tableName}(
            id,
            device_id,
            read_status,
            barcode,
            record_time,
            alarm_flag,
            alarm_level,
            alarm_type,
            alarm_action
        )
        values (
            #{entity.id},
            #{entity.deviceId},
            #{entity.readStatus},
            #{entity.barcode},
            #{entity.recordTime},
            #{entity.alarmFlag},
            #{entity.alarmLevel},
            #{entity.alarmType},
            #{entity.alarmAction}
        )
    </insert>

    <!-- 单条更新:根据主键更新当前分表中的记录 -->
    <update id="updateRfidReadRecordById">
        update ${tableName}
        <set>
            <if test="entity.deviceId != null">
                device_id = #{entity.deviceId},
            </if>
            <if test="entity.readStatus != null and entity.readStatus != ''">
                read_status = #{entity.readStatus},
            </if>
            <if test="entity.barcode != null">
                barcode = #{entity.barcode},
            </if>
            <if test="entity.recordTime != null">
                record_time = #{entity.recordTime},
            </if>
            <if test="entity.alarmFlag != null">
                alarm_flag = #{entity.alarmFlag},
            </if>
            <if test="entity.alarmLevel != null">
                alarm_level = #{entity.alarmLevel},
            </if>
            <if test="entity.alarmType != null">
                alarm_type = #{entity.alarmType},
            </if>
            <if test="entity.alarmAction != null">
                alarm_action = #{entity.alarmAction},
            </if>
        </set>
        where id = #{entity.id}
    </update>

    <!-- 根据 ID 列表批量删除(单表) -->
    <delete id="deleteCustomRfidReadRecordByIds">
        delete from ${tableName}
        where id in
        <foreach collection="ids" item="id" open="(" separator="," close=")">
            #{id}
        </foreach>
    </delete>

5.2 多表 UNION 查询/分页

    <!-- 查询列表(多表联合查询,跨日期范围) -->
    <!-- 思路:先在子查询中按分表 + 条件过滤数据,再统一 LEFT JOIN 设备表,最后做整体排序。 -->
    <select id="selectCustomRfidReadRecordVoListMultiTable" resultMap="RfidReadRecordResult">
        select combined.id,
               combined.device_id,
               d.device_code as deviceCode,
               d.device_name as deviceName,
               combined.read_status,
               combined.barcode,
               combined.record_time,
               combined.alarm_flag,
               combined.alarm_level,
               combined.alarm_type,
               combined.alarm_action
        from (
            <foreach collection="tableNames" item="tbl" separator=" UNION ALL ">
                select t.id,
                       t.device_id,
                       t.read_status,
                       t.barcode,
                       t.record_time,
                       t.alarm_flag,
                       t.alarm_level,
                       t.alarm_type,
                       t.alarm_action
                from ${tbl} t
                <if test="ew != null">
                    ${ew.customSqlSegment}
                </if>
            </foreach>
        ) combined
        left join rfid_device d on combined.device_id = d.id
        order by combined.record_time desc
    </select>

    <!-- 分页查询(多表联合查询,跨日期范围) -->
    <select id="selectCustomRfidReadRecordVoPageMultiTable" resultMap="RfidReadRecordResult">
        select combined.id,
               combined.device_id,
               d.device_code as deviceCode,
               d.device_name as deviceName,
               combined.read_status,
               combined.barcode,
               combined.record_time,
               combined.alarm_flag,
               combined.alarm_level,
               combined.alarm_type,
               combined.alarm_action
        from (
            <foreach collection="tableNames" item="tbl" separator=" UNION ALL ">
                select t.id,
                       t.device_id,
                       t.read_status,
                       t.barcode,
                       t.record_time,
                       t.alarm_flag,
                       t.alarm_level,
                       t.alarm_type,
                       t.alarm_action
                from ${tbl} t
                <if test="ew != null">
                    ${ew.customSqlSegment}
                </if>
            </foreach>
        ) combined
        left join rfid_device d on combined.device_id = d.id
        order by combined.record_time desc
    </select>

    <!-- 统计查询(多表):用于分页总数统计 -->
    <select id="countCustomRfidReadRecordMultiTable" resultType="java.lang.Long">
        select sum(cnt)
        from (
            <foreach collection="tableNames" item="tbl" separator=" UNION ALL ">
                select count(1) as cnt from ${tbl} t
                <if test="ew != null">
                    ${ew.customSqlSegment}
                </if>
            </foreach>
        ) tmp
    </select>

5.3 采样查询(大数据量优化)

    <!-- 采样查询(单表):每 N 分钟取一条代表数据 -->
    <select id="selectWithSampling" resultMap="RfidReadRecordResult">
        select t1.id,
               t1.device_id,
               d.device_code as deviceCode,
               d.device_name as deviceName,
               t1.read_status,
               t1.barcode,
               t1.record_time,
               t1.alarm_flag,
               t1.alarm_level,
               t1.alarm_type,
               t1.alarm_action
        from ${tableName} t1
        left join rfid_device d on t1.device_id = d.id
        inner join (
            -- 子查询:按 device_id + time_slot 分组,取每个时间槽的最新记录
            select
                t.device_id,
                -- 使用 UNIX_TIMESTAMP 将时间转成秒,除以采样间隔(分钟 * 60并取 FLOOR得到离散时间槽编号
                FLOOR(UNIX_TIMESTAMP(t.record_time) / (#{samplingInterval} * 60)) as time_slot,
                MAX(t.record_time) as max_time
            from ${tableName} t
            <if test="ew != null">
                ${ew.customSqlSegment}
            </if>
            group by t.device_id, time_slot
        ) t2 on t1.device_id = t2.device_id and t1.record_time = t2.max_time
        order by t1.device_id asc, t1.record_time desc
    </select>

    <!-- 采样查询(多表):每 N 分钟取一条代表数据,跨多张分表时通过 UNION ALL 聚合 -->
    <select id="selectWithSamplingMultiTable" resultMap="RfidReadRecordResult">
        select sampled.id,
               sampled.device_id,
               d.device_code as deviceCode,
               d.device_name as deviceName,
               sampled.read_status,
               sampled.barcode,
               sampled.record_time,
               sampled.alarm_flag,
               sampled.alarm_level,
               sampled.alarm_type,
               sampled.alarm_action
        from (
            <foreach collection="tableNames" item="tbl" separator=" UNION ALL ">
                select t1.id,
                       t1.device_id,
                       t1.read_status,
                       t1.barcode,
                       t1.record_time,
                       t1.alarm_flag,
                       t1.alarm_level,
                       t1.alarm_type,
                       t1.alarm_action
                from ${tbl} t1
                inner join (
                    select
                        t.device_id,
                        FLOOR(UNIX_TIMESTAMP(t.record_time) / (#{samplingInterval} * 60)) as time_slot,
                        MAX(t.record_time) as max_time
                    from ${tbl} t
                    <if test="ew != null">
                        ${ew.customSqlSegment}
                    </if>
                    group by t.device_id, time_slot
                ) t2 on t1.device_id = t2.deviceId and t1.record_time = t2.max_time
            </foreach>
        ) sampled
        left join rfid_device d on sampled.device_id = d.id
        order by sampled.device_id asc, sampled.record_time desc
    </select>

</mapper>

6. 典型分表查询流程串联示例

下面以“分页查询 + 查看详情 + 删除”为例,串起前后端的完整调用链,便于快速理解:

  1. 用户在前端选择时间范围并点击搜索

    • dateRange = ['2025-11-25 00:00:00', '2025-11-26 23:59:59']
    • getList() 中将其转换为:
      • queryParams.beginRecordTime = '2025-11-25 00:00:00'
      • queryParams.endRecordTime = '2025-11-26 23:59:59'
    • 调用 listRfidReadRecord(queryParams)
  2. 后端 Service 收到请求,构建分表列表

    • RfidReadRecordServiceImpl.queryPageList(bo, pageQuery)
      • 调用 RfidReadRecordTableHelper.getExistingTableNames(bo.beginRecordTime, bo.endRecordTime),得到如:
        • [rfid_read_record_20251125, rfid_read_record_20251126]
      • 根据分表数量调用:
        • selectCustomRfidReadRecordVoPageMultiTable(tableNames, pageQuery, lqw)
  3. Mapper 生成最终 SQL

    • 使用 <foreach collection="tableNames"> 依次展开每个分表:
      • select ... from rfid_read_record_20251125 t ...
      • UNION ALL
      • select ... from rfid_read_record_20251126 t ...
    • 最后统一 left join rfid_device,按 record_time desc 排序,实现跨表分页查询。
  4. 用户在前端勾选一条记录并点击“修改”或“删除”

    • handleSelectionChange 将选中行的 recordTime 截断为 yyyy-MM-dd,写入 selectedRecordTimes
    • 修改:
      • handleUpdate(row) 计算 queryDate = row.recordTime.substring(0, 10)
      • 调用 getRfidReadRecord(id, queryDate)
    • 删除:
      • handleDelete(row) 计算相同的 queryDate
      • 调用 delRfidReadRecord(ids, queryDate)
  5. 后端根据 queryDate 精确路由单条操作

    • queryById(id, queryDate):通过 RfidReadRecordTableHelper.getTableName(queryDate) 得到唯一表名,调用单表查询 SQL。
    • deleteWithValidByIds(ids, queryDate):同样通过 queryDate 得到表名,只在该分表中执行删除。

7. 小结与扩展建议

  • 优点
    • 按天分表 + 动态路由,兼顾了写入简单性与查询性能;
    • 通过 getExistingTableNames 屏蔽了不存在分表带来的 SQL 错误;
    • 采样查询在大数据场景下可以显著减少返回记录数,适合看板类页面。
  • 注意事项
    • 前端在做“单条操作(详情/修改/删除)”时,务必传递 queryDate
    • 新建分表后,若需要立刻生效,可调用 RfidReadRecordTableHelper.clearTableExistsCache() 刷新缓存;
    • 大范围跨天查询可能涉及多张分表,需注意分页总量与响应时间,可结合采样查询或限制最大时间跨度。

本说明文档覆盖了 RFID 读取记录分表查询的完整实现链路,后续如需扩展到其他按天分表的业务,可以复用本模式并适当抽象公共能力。

分页