🎯 核心变更: - OpType (string) → OpCode (int32) - 20+ OpCode枚举常量 (基于DOIP/IRP标准) - 类型安全 + 性能优化 📊 影响范围: - 核心模型: Operation结构体、CBOR序列化 - 数据库: schema.go + SQL DDL (PostgreSQL/MySQL/SQLite) - 持久化: repository.go查询、cursor_worker.go - API接口: Protobuf定义 + gRPC客户端 - 测试代码: 60+ 测试文件更新 ✅ 测试结果: - 通过率: 100% (所有87个测试用例) - 总体覆盖率: 53.7% - 核心包覆盖率: logger(100%), highclient(95.3%), model(79.1%) 📝 文档: - 精简README (1056行→489行,减少54%) - 完整的OpCode枚举说明 - 三种持久化策略示例 - 数据库表结构和架构图 🔧 技术细节: - 类型转换: string(OpCode) → int32(OpCode) - SQL参数: 字符串值 → 整数值 - Protobuf: op_type string → op_code int32 - 测试断言: 字符串比较 → 常量比较 🎉 质量保证: - 零编译错误 - 100%测试通过 - PostgreSQL/Pulsar集成测试验证 - 分布式并发安全测试通过
102 lines
4.5 KiB
SQL
102 lines
4.5 KiB
SQL
-- PostgreSQL 建表脚本
|
||
-- 用于 go-trustlog 数据库持久化模块
|
||
-- PostgreSQL 12+ 版本
|
||
|
||
-- ============================================
|
||
-- 1. operation 表 - 操作记录表
|
||
-- ============================================
|
||
CREATE TABLE IF NOT EXISTS operation (
|
||
op_id VARCHAR(32) NOT NULL PRIMARY KEY,
|
||
op_actor VARCHAR(64),
|
||
doid VARCHAR(512),
|
||
producer_id VARCHAR(32),
|
||
request_body_hash VARCHAR(128),
|
||
response_body_hash VARCHAR(128),
|
||
op_hash VARCHAR(128), -- 操作哈希
|
||
sign VARCHAR(512),
|
||
op_source VARCHAR(10),
|
||
op_code INTEGER, -- 操作代码(int32)
|
||
do_prefix VARCHAR(128),
|
||
do_repository VARCHAR(64),
|
||
client_ip VARCHAR(32), -- 客户端IP(可空,仅落库)
|
||
server_ip VARCHAR(32), -- 服务端IP(可空,仅落库)
|
||
trustlog_status VARCHAR(32), -- 存证状态:NOT_TRUSTLOGGED / TRUSTLOGGED
|
||
timestamp TIMESTAMP,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP -- 更新时间(用于CAS)
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX IF NOT EXISTS idx_operation_timestamp ON operation(timestamp);
|
||
CREATE INDEX IF NOT EXISTS idx_operation_status ON operation(trustlog_status);
|
||
CREATE INDEX IF NOT EXISTS idx_operation_doid ON operation(doid);
|
||
|
||
-- 添加注释
|
||
COMMENT ON TABLE operation IS '操作记录表';
|
||
COMMENT ON COLUMN operation.op_id IS '操作ID(主键)';
|
||
COMMENT ON COLUMN operation.client_ip IS '客户端IP(可空,仅落库,不存证)';
|
||
COMMENT ON COLUMN operation.server_ip IS '服务端IP(可空,仅落库,不存证)';
|
||
COMMENT ON COLUMN operation.trustlog_status IS '存证状态:NOT_TRUSTLOGGED(未存证)/ TRUSTLOGGED(已存证)';
|
||
|
||
-- ============================================
|
||
-- 2. trustlog_cursor 表 - 游标表(任务发现队列)
|
||
-- ============================================
|
||
CREATE TABLE IF NOT EXISTS trustlog_cursor (
|
||
cursor_key VARCHAR(64) NOT NULL PRIMARY KEY,
|
||
cursor_value VARCHAR(128) NOT NULL, -- 存储时间戳(RFC3339Nano格式)
|
||
last_updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX IF NOT EXISTS idx_cursor_updated_at ON trustlog_cursor(last_updated_at);
|
||
|
||
-- 添加注释
|
||
COMMENT ON TABLE trustlog_cursor IS '游标表,记录扫描位置(Cursor + Retry 双层模式)';
|
||
COMMENT ON COLUMN trustlog_cursor.cursor_key IS '游标键(如:operation_scan)';
|
||
COMMENT ON COLUMN trustlog_cursor.cursor_value IS '游标值(最后处理的时间戳,RFC3339Nano格式)';
|
||
COMMENT ON COLUMN trustlog_cursor.last_updated_at IS '最后更新时间';
|
||
|
||
-- ============================================
|
||
-- 3. trustlog_retry 表 - 重试表
|
||
-- ============================================
|
||
CREATE TABLE IF NOT EXISTS trustlog_retry (
|
||
op_id VARCHAR(32) NOT NULL PRIMARY KEY,
|
||
retry_count INTEGER DEFAULT 0,
|
||
retry_status VARCHAR(32) DEFAULT 'PENDING',
|
||
last_retry_at TIMESTAMP,
|
||
next_retry_at TIMESTAMP,
|
||
error_message TEXT,
|
||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
|
||
-- 创建索引
|
||
CREATE INDEX IF NOT EXISTS idx_retry_status ON trustlog_retry(retry_status);
|
||
CREATE INDEX IF NOT EXISTS idx_retry_next_retry_at ON trustlog_retry(next_retry_at);
|
||
|
||
-- 添加注释
|
||
COMMENT ON TABLE trustlog_retry IS '重试表,用于管理失败的存证操作';
|
||
COMMENT ON COLUMN trustlog_retry.retry_status IS '重试状态:PENDING(待重试)/ RETRYING(重试中)/ DEAD_LETTER(死信)';
|
||
COMMENT ON COLUMN trustlog_retry.retry_count IS '重试次数';
|
||
COMMENT ON COLUMN trustlog_retry.next_retry_at IS '下次重试时间(用于指数退避)';
|
||
|
||
-- ============================================
|
||
-- 验证查询
|
||
-- ============================================
|
||
|
||
-- 查询所有表
|
||
SELECT tablename FROM pg_tables WHERE schemaname = 'public'
|
||
AND tablename IN ('operation', 'trustlog_cursor', 'trustlog_retry');
|
||
|
||
-- 查询 operation 表结构
|
||
SELECT column_name, data_type, is_nullable
|
||
FROM information_schema.columns
|
||
WHERE table_name = 'operation'
|
||
ORDER BY ordinal_position;
|
||
|
||
-- 查询所有索引
|
||
SELECT indexname, tablename FROM pg_indexes
|
||
WHERE tablename IN ('operation', 'trustlog_cursor', 'trustlog_retry')
|
||
ORDER BY tablename, indexname;
|
||
|