supplement_tables.sql 8.5 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183
  1. -- 灵越智报 v2.0 补充表结构
  2. -- PostgreSQL 15+
  3. -- 根据产品设计方案补充的表结构
  4. -- ============================================
  5. -- 1. 图节点表(graph_nodes)
  6. -- ============================================
  7. CREATE TABLE IF NOT EXISTS graph_nodes (
  8. id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  9. document_id UUID NOT NULL REFERENCES documents(id) ON DELETE CASCADE,
  10. user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  11. name VARCHAR(255) NOT NULL,
  12. type VARCHAR(50) NOT NULL, -- text/table/image/number/date/company/person等
  13. value TEXT,
  14. position JSONB, -- {file_id, page, line, char_start, char_end}
  15. parent_id UUID REFERENCES graph_nodes(id) ON DELETE SET NULL,
  16. level INTEGER DEFAULT 0, -- 层级
  17. metadata JSONB DEFAULT '{}',
  18. created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
  19. updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
  20. );
  21. CREATE INDEX IF NOT EXISTS idx_graph_nodes_document_id ON graph_nodes(document_id);
  22. CREATE INDEX IF NOT EXISTS idx_graph_nodes_user_id ON graph_nodes(user_id);
  23. CREATE INDEX IF NOT EXISTS idx_graph_nodes_type ON graph_nodes(type);
  24. CREATE INDEX IF NOT EXISTS idx_graph_nodes_parent_id ON graph_nodes(parent_id);
  25. CREATE INDEX IF NOT EXISTS idx_graph_nodes_position ON graph_nodes USING GIN(position);
  26. -- ============================================
  27. -- 2. 图关系表(graph_relations)
  28. -- ============================================
  29. CREATE TABLE IF NOT EXISTS graph_relations (
  30. id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  31. from_node_id UUID NOT NULL REFERENCES graph_nodes(id) ON DELETE CASCADE,
  32. to_node_id UUID NOT NULL REFERENCES graph_nodes(id) ON DELETE CASCADE,
  33. relation_type VARCHAR(50) NOT NULL, -- DEP/ADD/SUB/MUL/DIV/UNION/INTERSECT/AI等
  34. action_type VARCHAR(50), -- 动作类型
  35. action_config JSONB, -- 动作配置(如AI模型ID)
  36. order_index INTEGER DEFAULT 0, -- 顺序
  37. condition_expr TEXT, -- 条件表达式
  38. metadata JSONB DEFAULT '{}',
  39. created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
  40. updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
  41. );
  42. CREATE INDEX IF NOT EXISTS idx_graph_relations_from_node ON graph_relations(from_node_id);
  43. CREATE INDEX IF NOT EXISTS idx_graph_relations_to_node ON graph_relations(to_node_id);
  44. CREATE INDEX IF NOT EXISTS idx_graph_relations_type ON graph_relations(relation_type);
  45. -- ============================================
  46. -- 3. 规则表(rules)
  47. -- ============================================
  48. CREATE TABLE IF NOT EXISTS rules (
  49. id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  50. user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  51. name VARCHAR(255) NOT NULL,
  52. description TEXT,
  53. entry_node_id UUID NOT NULL REFERENCES graph_nodes(id) ON DELETE CASCADE,
  54. exit_node_id UUID NOT NULL REFERENCES graph_nodes(id) ON DELETE CASCADE,
  55. rule_chain JSONB NOT NULL DEFAULT '[]', -- 规则链(节点ID序列)
  56. status VARCHAR(20) DEFAULT 'active', -- active/inactive
  57. metadata JSONB DEFAULT '{}',
  58. created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
  59. updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
  60. );
  61. CREATE INDEX IF NOT EXISTS idx_rules_user_id ON rules(user_id);
  62. CREATE INDEX IF NOT EXISTS idx_rules_entry_node ON rules(entry_node_id);
  63. CREATE INDEX IF NOT EXISTS idx_rules_exit_node ON rules(exit_node_id);
  64. CREATE INDEX IF NOT EXISTS idx_rules_status ON rules(status);
  65. -- ============================================
  66. -- 4. 数据源表(data_sources)
  67. -- ============================================
  68. CREATE TABLE IF NOT EXISTS data_sources (
  69. id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  70. user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  71. document_id UUID REFERENCES documents(id) ON DELETE SET NULL,
  72. name VARCHAR(255) NOT NULL,
  73. type VARCHAR(50) NOT NULL, -- table/text/image
  74. source_type VARCHAR(50) NOT NULL, -- file/manual/rule_result
  75. node_ids UUID[] DEFAULT '{}', -- 关联的节点ID数组
  76. config JSONB DEFAULT '{}', -- 数据源配置
  77. metadata JSONB DEFAULT '{}',
  78. created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
  79. updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
  80. );
  81. CREATE INDEX IF NOT EXISTS idx_data_sources_user_id ON data_sources(user_id);
  82. CREATE INDEX IF NOT EXISTS idx_data_sources_document_id ON data_sources(document_id);
  83. CREATE INDEX IF NOT EXISTS idx_data_sources_type ON data_sources(type);
  84. -- ============================================
  85. -- 5. 模板表(templates)
  86. -- ============================================
  87. CREATE TABLE IF NOT EXISTS templates (
  88. id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  89. user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
  90. name VARCHAR(255) NOT NULL,
  91. content TEXT NOT NULL, -- 模板内容(带占位符)
  92. placeholder_mapping JSONB DEFAULT '{}', -- 占位符到数据源的映射
  93. source_template_id UUID REFERENCES templates(id) ON DELETE SET NULL, -- 复制来源
  94. status VARCHAR(20) DEFAULT 'active', -- active/inactive
  95. metadata JSONB DEFAULT '{}',
  96. created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
  97. updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
  98. );
  99. CREATE INDEX IF NOT EXISTS idx_templates_user_id ON templates(user_id);
  100. CREATE INDEX IF NOT EXISTS idx_templates_source_template ON templates(source_template_id);
  101. CREATE INDEX IF NOT EXISTS idx_templates_status ON templates(status);
  102. -- ============================================
  103. -- 6. 文本存储路径表(text_storage)
  104. -- ============================================
  105. CREATE TABLE IF NOT EXISTS text_storage (
  106. id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  107. document_id UUID NOT NULL REFERENCES documents(id) ON DELETE CASCADE,
  108. file_path VARCHAR(500) NOT NULL, -- TXT文件路径
  109. file_size BIGINT,
  110. checksum VARCHAR(64), -- 文件校验和
  111. created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
  112. updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
  113. );
  114. CREATE INDEX IF NOT EXISTS idx_text_storage_document_id ON text_storage(document_id);
  115. CREATE UNIQUE INDEX IF NOT EXISTS idx_text_storage_document_unique ON text_storage(document_id);
  116. -- ============================================
  117. -- 7. 向量存储表(vector_embeddings)
  118. -- ============================================
  119. -- 注意:需要先安装pgvector扩展
  120. -- CREATE EXTENSION IF NOT EXISTS vector;
  121. CREATE TABLE IF NOT EXISTS vector_embeddings (
  122. id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
  123. document_id UUID NOT NULL REFERENCES documents(id) ON DELETE CASCADE,
  124. chunk_text TEXT NOT NULL,
  125. chunk_index INTEGER NOT NULL, -- 分块索引
  126. embedding vector(768), -- 向量(需要pgvector扩展,如果未安装可先注释)
  127. file_name VARCHAR(255),
  128. file_hash VARCHAR(64), -- MD5哈希
  129. metadata JSONB DEFAULT '{}',
  130. created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
  131. );
  132. CREATE INDEX IF NOT EXISTS idx_vector_embeddings_document_id ON vector_embeddings(document_id);
  133. CREATE INDEX IF NOT EXISTS idx_vector_embeddings_file_hash ON vector_embeddings(file_hash);
  134. -- 向量相似度搜索索引(需要pgvector扩展)
  135. -- CREATE INDEX IF NOT EXISTS idx_vector_embeddings_embedding ON vector_embeddings USING ivfflat (embedding vector_cosine_ops);
  136. -- ============================================
  137. -- 创建更新时间触发器
  138. -- ============================================
  139. CREATE TRIGGER update_graph_nodes_updated_at BEFORE UPDATE ON graph_nodes
  140. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  141. CREATE TRIGGER update_graph_relations_updated_at BEFORE UPDATE ON graph_relations
  142. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  143. CREATE TRIGGER update_rules_updated_at BEFORE UPDATE ON rules
  144. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  145. CREATE TRIGGER update_data_sources_updated_at BEFORE UPDATE ON data_sources
  146. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  147. CREATE TRIGGER update_templates_updated_at BEFORE UPDATE ON templates
  148. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  149. CREATE TRIGGER update_text_storage_updated_at BEFORE UPDATE ON text_storage
  150. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  151. -- ============================================
  152. -- 安装pgvector扩展(可选,用于向量检索)
  153. -- ============================================
  154. -- 如果需要使用pgvector,请执行:
  155. -- CREATE EXTENSION IF NOT EXISTS vector;
  156. --
  157. -- 安装方法:
  158. -- 1. 下载pgvector: https://github.com/pgvector/pgvector
  159. -- 2. 编译安装
  160. -- 3. 在数据库中执行: CREATE EXTENSION vector;