67 lines
2.5 KiB
SQL
67 lines
2.5 KiB
SQL
SET sql_mode = 'STRICT_ALL_TABLES,ERROR_FOR_DIVISION_BY_ZERO,NO_ENGINE_SUBSTITUTION';
|
|
|
|
-- USERS
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id BIGINT PRIMARY KEY AUTO_INCREMENT,
|
|
email VARCHAR(255) NOT NULL UNIQUE,
|
|
pass_bcrypt VARBINARY(60) NOT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
|
|
) ENGINE=InnoDB;
|
|
|
|
-- CONVERSATIONS (one tree-ish DAG per conversation)
|
|
CREATE TABLE IF NOT EXISTS conversations (
|
|
id BIGINT PRIMARY KEY AUTO_INCREMENT,
|
|
owner_id BIGINT NOT NULL,
|
|
title VARCHAR(255),
|
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
CONSTRAINT fk_conversations_owner
|
|
FOREIGN KEY (owner_id) REFERENCES users(id)
|
|
ON DELETE CASCADE
|
|
) ENGINE=InnoDB;
|
|
|
|
-- NODES = commits (plain numeric IDs). author_kind for display only.
|
|
CREATE TABLE IF NOT EXISTS nodes (
|
|
id BIGINT PRIMARY KEY AUTO_INCREMENT,
|
|
conversation_id BIGINT NOT NULL,
|
|
author_kind ENUM('user','assistant') NOT NULL,
|
|
content MEDIUMTEXT NOT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
CONSTRAINT fk_nodes_conversation
|
|
FOREIGN KEY (conversation_id) REFERENCES conversations(id)
|
|
ON DELETE CASCADE
|
|
) ENGINE=InnoDB;
|
|
|
|
-- EDGES (parent -> child). Acyclic enforced in application.
|
|
CREATE TABLE IF NOT EXISTS edges (
|
|
parent_id BIGINT NOT NULL,
|
|
child_id BIGINT NOT NULL,
|
|
PRIMARY KEY (parent_id, child_id),
|
|
CONSTRAINT fk_edges_parent
|
|
FOREIGN KEY (parent_id) REFERENCES nodes(id)
|
|
ON DELETE CASCADE,
|
|
CONSTRAINT fk_edges_child
|
|
FOREIGN KEY (child_id) REFERENCES nodes(id)
|
|
ON DELETE CASCADE
|
|
) ENGINE=InnoDB;
|
|
|
|
-- BRANCHES (named pointers to any node within a conversation)
|
|
CREATE TABLE IF NOT EXISTS branches (
|
|
id BIGINT PRIMARY KEY AUTO_INCREMENT,
|
|
conversation_id BIGINT NOT NULL,
|
|
name VARCHAR(128) NOT NULL,
|
|
head_node_id BIGINT NOT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE KEY uq_branch_name (conversation_id, name),
|
|
CONSTRAINT fk_branches_conversation
|
|
FOREIGN KEY (conversation_id) REFERENCES conversations(id)
|
|
ON DELETE CASCADE,
|
|
CONSTRAINT fk_branches_head
|
|
FOREIGN KEY (head_node_id) REFERENCES nodes(id)
|
|
ON DELETE CASCADE
|
|
) ENGINE=InnoDB;
|
|
|
|
CREATE INDEX idx_nodes_conv_created ON nodes (conversation_id, created_at, id);
|
|
CREATE INDEX idx_edges_child ON edges (child_id);
|
|
CREATE INDEX idx_edges_parent ON edges (parent_id);
|
|
CREATE INDEX idx_branches_conv_head ON branches (conversation_id, head_node_id);
|