diff --git a/memory-store/README.md b/memory-store/README.md new file mode 100644 index 000000000..3441d47a4 --- /dev/null +++ b/memory-store/README.md @@ -0,0 +1,7 @@ +### prototyping flow: + +1. Install `pgmigrate` (until I move to golang-migrate) +2. In a separate window, `docker compose up db vectorizer-worker` to start db instances +3. `cd memory-store` and `pgmigrate migrate --database "postgres://postgres:postgres@0.0.0.0:5432/postgres" --migrations ./migrations` to apply the migrations +4. `pip install --user -U pgcli` +5. `pgcli "postgres://postgres:postgres@localhost:5432/postgres"` diff --git a/memory-store/migrations/000001_initial.down.sql b/memory-store/migrations/000001_initial.down.sql new file mode 100644 index 000000000..ddc44dbc8 --- /dev/null +++ b/memory-store/migrations/000001_initial.down.sql @@ -0,0 +1,17 @@ +-- Drop the update_updated_at_column function +DROP FUNCTION IF EXISTS update_updated_at_column(); + +-- Drop misc extensions +DROP EXTENSION IF EXISTS "uuid-ossp" CASCADE; +DROP EXTENSION IF EXISTS citext CASCADE; +DROP EXTENSION IF EXISTS btree_gist CASCADE; +DROP EXTENSION IF EXISTS btree_gin CASCADE; + +-- Drop timescale's pgai extensions +DROP EXTENSION IF EXISTS ai CASCADE; +DROP EXTENSION IF EXISTS vectorscale CASCADE; +DROP EXTENSION IF EXISTS vector CASCADE; + +-- Drop timescaledb extensions +DROP EXTENSION IF EXISTS timescaledb_toolkit CASCADE; +DROP EXTENSION IF EXISTS timescaledb CASCADE; diff --git a/memory-store/migrations/00001_initial.sql b/memory-store/migrations/000001_initial.up.sql similarity index 98% rename from memory-store/migrations/00001_initial.sql rename to memory-store/migrations/000001_initial.up.sql index 3be41ef68..da04e3c4b 100644 --- a/memory-store/migrations/00001_initial.sql +++ b/memory-store/migrations/000001_initial.up.sql @@ -1,3 +1,5 @@ +BEGIN; + -- init timescaledb CREATE EXTENSION IF NOT EXISTS timescaledb CASCADE; CREATE EXTENSION IF NOT EXISTS timescaledb_toolkit CASCADE; @@ -23,3 +25,5 @@ END; $$ language 'plpgsql'; COMMENT ON FUNCTION update_updated_at_column() IS 'Trigger function to automatically update updated_at timestamp'; + +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000002_developers.down.sql b/memory-store/migrations/000002_developers.down.sql new file mode 100644 index 000000000..ea6c58509 --- /dev/null +++ b/memory-store/migrations/000002_developers.down.sql @@ -0,0 +1,4 @@ +-- Drop the table (this will automatically drop associated indexes and triggers) +DROP TABLE IF EXISTS developers CASCADE; + +-- Note: The update_updated_at_column() function is not dropped as it might be used by other tables diff --git a/memory-store/migrations/00002_developers.sql b/memory-store/migrations/000002_developers.up.sql similarity index 54% rename from memory-store/migrations/00002_developers.sql rename to memory-store/migrations/000002_developers.up.sql index b8d9b7673..0802dcf6f 100644 --- a/memory-store/migrations/00002_developers.sql +++ b/memory-store/migrations/000002_developers.up.sql @@ -1,5 +1,7 @@ +BEGIN; + -- Create developers table -CREATE TABLE developers ( +CREATE TABLE IF NOT EXISTS developers ( developer_id UUID NOT NULL, email TEXT NOT NULL CONSTRAINT ct_developers_email_format CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$'), active BOOLEAN NOT NULL DEFAULT true, @@ -12,22 +14,29 @@ CREATE TABLE developers ( ); -- Create sorted index on developer_id (optimized for UUID v7) -CREATE INDEX idx_developers_id_sorted ON developers (developer_id DESC); +CREATE INDEX IF NOT EXISTS idx_developers_id_sorted ON developers (developer_id DESC); -- Create index on email -CREATE INDEX idx_developers_email ON developers (email); +CREATE INDEX IF NOT EXISTS idx_developers_email ON developers (email); -- Create GIN index for tags array -CREATE INDEX idx_developers_tags ON developers USING GIN (tags); +CREATE INDEX IF NOT EXISTS idx_developers_tags ON developers USING GIN (tags); -- Create partial index for active developers -CREATE INDEX idx_developers_active ON developers (developer_id) WHERE active = true; +CREATE INDEX IF NOT EXISTS idx_developers_active ON developers (developer_id) WHERE active = true; -- Create trigger to automatically update updated_at -CREATE TRIGGER trg_developers_updated_at - BEFORE UPDATE ON developers - FOR EACH ROW - EXECUTE FUNCTION update_updated_at_column(); +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_trigger WHERE tgname = 'trg_developers_updated_at') THEN + CREATE TRIGGER trg_developers_updated_at + BEFORE UPDATE ON developers + FOR EACH ROW + EXECUTE FUNCTION update_updated_at_column(); + END IF; +END +$$; -- Add comment to table -COMMENT ON TABLE developers IS 'Stores developer information including their settings and tags'; \ No newline at end of file +COMMENT ON TABLE developers IS 'Stores developer information including their settings and tags'; +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000003_users.down.sql b/memory-store/migrations/000003_users.down.sql new file mode 100644 index 000000000..3b1b98648 --- /dev/null +++ b/memory-store/migrations/000003_users.down.sql @@ -0,0 +1,18 @@ +BEGIN; + +-- Drop trigger first +DROP TRIGGER IF EXISTS update_users_updated_at ON users; + +-- Drop indexes +DROP INDEX IF EXISTS users_metadata_gin_idx; +DROP INDEX IF EXISTS users_developer_id_idx; +DROP INDEX IF EXISTS users_id_sorted_idx; + +-- Drop foreign key constraint +ALTER TABLE IF EXISTS users + DROP CONSTRAINT IF EXISTS users_developer_id_fkey; + +-- Finally drop the table +DROP TABLE IF EXISTS users; + +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000003_users.up.sql b/memory-store/migrations/000003_users.up.sql new file mode 100644 index 000000000..c32ff48fe --- /dev/null +++ b/memory-store/migrations/000003_users.up.sql @@ -0,0 +1,49 @@ +BEGIN; + +-- Create users table if it doesn't exist +CREATE TABLE IF NOT EXISTS users ( + developer_id UUID NOT NULL, + user_id UUID NOT NULL, + name TEXT NOT NULL, + about TEXT, + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + metadata JSONB NOT NULL DEFAULT '{}'::JSONB, + CONSTRAINT pk_users PRIMARY KEY (developer_id, user_id) +); + +-- Create sorted index on user_id if it doesn't exist +CREATE INDEX IF NOT EXISTS users_id_sorted_idx ON users (user_id DESC); + +-- Create foreign key constraint and index if they don't exist +DO $$ BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_constraint WHERE conname = 'users_developer_id_fkey' + ) THEN + ALTER TABLE users + ADD CONSTRAINT users_developer_id_fkey + FOREIGN KEY (developer_id) + REFERENCES developers(developer_id); + END IF; +END $$; + +CREATE INDEX IF NOT EXISTS users_developer_id_idx ON users (developer_id); + +-- Create a GIN index on the entire metadata column if it doesn't exist +CREATE INDEX IF NOT EXISTS users_metadata_gin_idx ON users USING GIN (metadata); + +-- Create trigger if it doesn't exist +DO $$ BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_trigger WHERE tgname = 'update_users_updated_at' + ) THEN + CREATE TRIGGER update_users_updated_at + BEFORE UPDATE ON users + FOR EACH ROW + EXECUTE FUNCTION update_updated_at_column(); + END IF; +END $$; + +-- Add comment to table (comments are idempotent by default) +COMMENT ON TABLE users IS 'Stores user information linked to developers'; +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000004_agents.down.sql b/memory-store/migrations/000004_agents.down.sql new file mode 100644 index 000000000..0504684fb --- /dev/null +++ b/memory-store/migrations/000004_agents.down.sql @@ -0,0 +1,14 @@ +BEGIN; + +-- Drop trigger first +DROP TRIGGER IF EXISTS trg_agents_updated_at ON agents; + +-- Drop indexes +DROP INDEX IF EXISTS idx_agents_metadata; +DROP INDEX IF EXISTS idx_agents_developer; +DROP INDEX IF EXISTS idx_agents_id_sorted; + +-- Drop table (this will automatically drop associated constraints) +DROP TABLE IF EXISTS agents; + +COMMIT; diff --git a/memory-store/migrations/00004_agents.sql b/memory-store/migrations/000004_agents.up.sql similarity index 70% rename from memory-store/migrations/00004_agents.sql rename to memory-store/migrations/000004_agents.up.sql index 8eb8b2f35..82eb9c84f 100644 --- a/memory-store/migrations/00004_agents.sql +++ b/memory-store/migrations/000004_agents.up.sql @@ -1,5 +1,14 @@ +BEGIN; + +-- Drop existing objects if they exist +DROP TRIGGER IF EXISTS trg_agents_updated_at ON agents; +DROP INDEX IF EXISTS idx_agents_metadata; +DROP INDEX IF EXISTS idx_agents_developer; +DROP INDEX IF EXISTS idx_agents_id_sorted; +DROP TABLE IF EXISTS agents; + -- Create agents table -CREATE TABLE agents ( +CREATE TABLE IF NOT EXISTS agents ( developer_id UUID NOT NULL, agent_id UUID NOT NULL, canonical_name citext NOT NULL CONSTRAINT ct_agents_canonical_name_length CHECK (length(canonical_name) >= 1 AND length(canonical_name) <= 255), @@ -17,24 +26,26 @@ CREATE TABLE agents ( ); -- Create sorted index on agent_id (optimized for UUID v7) -CREATE INDEX idx_agents_id_sorted ON agents (agent_id DESC); +CREATE INDEX IF NOT EXISTS idx_agents_id_sorted ON agents (agent_id DESC); -- Create foreign key constraint and index on developer_id ALTER TABLE agents + DROP CONSTRAINT IF EXISTS fk_agents_developer, ADD CONSTRAINT fk_agents_developer FOREIGN KEY (developer_id) REFERENCES developers(developer_id); -CREATE INDEX idx_agents_developer ON agents (developer_id); +CREATE INDEX IF NOT EXISTS idx_agents_developer ON agents (developer_id); -- Create a GIN index on the entire metadata column -CREATE INDEX idx_agents_metadata ON agents USING GIN (metadata); +CREATE INDEX IF NOT EXISTS idx_agents_metadata ON agents USING GIN (metadata); -- Create trigger to automatically update updated_at -CREATE TRIGGER trg_agents_updated_at +CREATE OR REPLACE TRIGGER trg_agents_updated_at BEFORE UPDATE ON agents FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Add comment to table -COMMENT ON TABLE agents IS 'Stores AI agent configurations and metadata for developers'; \ No newline at end of file +COMMENT ON TABLE agents IS 'Stores AI agent configurations and metadata for developers'; +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000005_files.down.sql b/memory-store/migrations/000005_files.down.sql new file mode 100644 index 000000000..870eac359 --- /dev/null +++ b/memory-store/migrations/000005_files.down.sql @@ -0,0 +1,13 @@ +BEGIN; + +-- Drop agent_files table and its dependencies +DROP TABLE IF EXISTS agent_files; + +-- Drop user_files table and its dependencies +DROP TABLE IF EXISTS user_files; + +-- Drop files table and its dependencies +DROP TRIGGER IF EXISTS trg_files_updated_at ON files; +DROP TABLE IF EXISTS files; + +COMMIT; diff --git a/memory-store/migrations/00005_files.sql b/memory-store/migrations/000005_files.up.sql similarity index 51% rename from memory-store/migrations/00005_files.sql rename to memory-store/migrations/000005_files.up.sql index 3d8c2900b..bf368db9a 100644 --- a/memory-store/migrations/00005_files.sql +++ b/memory-store/migrations/000005_files.up.sql @@ -1,5 +1,7 @@ +BEGIN; + -- Create files table -CREATE TABLE files ( +CREATE TABLE IF NOT EXISTS files ( developer_id UUID NOT NULL, file_id UUID NOT NULL, name TEXT NOT NULL CONSTRAINT ct_files_name_length CHECK (length(name) >= 1 AND length(name) <= 255), @@ -12,32 +14,41 @@ CREATE TABLE files ( CONSTRAINT pk_files PRIMARY KEY (developer_id, file_id) ); --- Create sorted index on file_id (optimized for UUID v7) -CREATE INDEX idx_files_id_sorted ON files (file_id DESC); - --- Create foreign key constraint and index on developer_id -ALTER TABLE files - ADD CONSTRAINT fk_files_developer - FOREIGN KEY (developer_id) - REFERENCES developers(developer_id); +-- Create sorted index on file_id if it doesn't exist +CREATE INDEX IF NOT EXISTS idx_files_id_sorted ON files (file_id DESC); -CREATE INDEX idx_files_developer ON files (developer_id); +-- Create foreign key constraint and index if they don't exist +DO $$ BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'fk_files_developer') THEN + ALTER TABLE files + ADD CONSTRAINT fk_files_developer + FOREIGN KEY (developer_id) + REFERENCES developers(developer_id); + END IF; +END $$; --- Before creating the user_files and agent_files tables, we need to ensure that the file_id is unique for each developer -ALTER TABLE files - ADD CONSTRAINT uq_files_developer_id_file_id UNIQUE (developer_id, file_id); +CREATE INDEX IF NOT EXISTS idx_files_developer ON files (developer_id); --- Create trigger to automatically update updated_at -CREATE TRIGGER trg_files_updated_at - BEFORE UPDATE ON files - FOR EACH ROW - EXECUTE FUNCTION update_updated_at_column(); +-- Add unique constraint if it doesn't exist +DO $$ BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'uq_files_developer_id_file_id') THEN + ALTER TABLE files + ADD CONSTRAINT uq_files_developer_id_file_id UNIQUE (developer_id, file_id); + END IF; +END $$; --- Add comment to table -COMMENT ON TABLE files IS 'Stores file metadata and references for developers'; +-- Create trigger if it doesn't exist +DO $$ BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_trigger WHERE tgname = 'trg_files_updated_at') THEN + CREATE TRIGGER trg_files_updated_at + BEFORE UPDATE ON files + FOR EACH ROW + EXECUTE FUNCTION update_updated_at_column(); + END IF; +END $$; -- Create the user_files table -CREATE TABLE user_files ( +CREATE TABLE IF NOT EXISTS user_files ( developer_id UUID NOT NULL, user_id UUID NOT NULL, file_id UUID NOT NULL, @@ -46,11 +57,11 @@ CREATE TABLE user_files ( CONSTRAINT fk_user_files_file FOREIGN KEY (developer_id, file_id) REFERENCES files(developer_id, file_id) ); --- Indexes for efficient querying -CREATE INDEX idx_user_files_user ON user_files (developer_id, user_id); +-- Create index if it doesn't exist +CREATE INDEX IF NOT EXISTS idx_user_files_user ON user_files (developer_id, user_id); -- Create the agent_files table -CREATE TABLE agent_files ( +CREATE TABLE IF NOT EXISTS agent_files ( developer_id UUID NOT NULL, agent_id UUID NOT NULL, file_id UUID NOT NULL, @@ -59,5 +70,7 @@ CREATE TABLE agent_files ( CONSTRAINT fk_agent_files_file FOREIGN KEY (developer_id, file_id) REFERENCES files(developer_id, file_id) ); --- Indexes for efficient querying -CREATE INDEX idx_agent_files_agent ON agent_files (developer_id, agent_id); +-- Create index if it doesn't exist +CREATE INDEX IF NOT EXISTS idx_agent_files_agent ON agent_files (developer_id, agent_id); + +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000006_docs.down.sql b/memory-store/migrations/000006_docs.down.sql new file mode 100644 index 000000000..50139bb87 --- /dev/null +++ b/memory-store/migrations/000006_docs.down.sql @@ -0,0 +1,29 @@ +BEGIN; + +-- Drop indexes +DROP INDEX IF EXISTS idx_docs_content_trgm; +DROP INDEX IF EXISTS idx_docs_title_trgm; +DROP INDEX IF EXISTS idx_docs_search_tsv; +DROP INDEX IF EXISTS idx_docs_metadata; +DROP INDEX IF EXISTS idx_agent_docs_agent; +DROP INDEX IF EXISTS idx_user_docs_user; +DROP INDEX IF EXISTS idx_docs_developer; +DROP INDEX IF EXISTS idx_docs_id_sorted; + +-- Drop triggers +DROP TRIGGER IF EXISTS trg_docs_search_tsv ON docs; +DROP TRIGGER IF EXISTS trg_docs_updated_at ON docs; + +-- Drop the constraint that depends on is_valid_language function +ALTER TABLE IF EXISTS docs DROP CONSTRAINT IF EXISTS ct_docs_valid_language; + +-- Drop functions +DROP FUNCTION IF EXISTS docs_update_search_tsv(); +DROP FUNCTION IF EXISTS is_valid_language(text); + +-- Drop tables (in correct order due to foreign key constraints) +DROP TABLE IF EXISTS agent_docs; +DROP TABLE IF EXISTS user_docs; +DROP TABLE IF EXISTS docs; + +COMMIT; diff --git a/memory-store/migrations/00006_docs.sql b/memory-store/migrations/000006_docs.up.sql similarity index 61% rename from memory-store/migrations/00006_docs.sql rename to memory-store/migrations/000006_docs.up.sql index 88c7ff2a7..c4a241e65 100644 --- a/memory-store/migrations/00006_docs.sql +++ b/memory-store/migrations/000006_docs.up.sql @@ -1,4 +1,6 @@ --- Create function to validate language +BEGIN; + +-- Create function to validate language (make it OR REPLACE) CREATE OR REPLACE FUNCTION is_valid_language(lang text) RETURNS boolean AS $$ BEGIN @@ -9,7 +11,7 @@ END; $$ LANGUAGE plpgsql; -- Create docs table -CREATE TABLE docs ( +CREATE TABLE IF NOT EXISTS docs ( developer_id UUID NOT NULL, doc_id UUID NOT NULL, title TEXT NOT NULL, @@ -31,28 +33,39 @@ CREATE TABLE docs ( CHECK (is_valid_language(language)) ); --- Create sorted index on doc_id (optimized for UUID v7) -CREATE INDEX idx_docs_id_sorted ON docs (doc_id DESC); - --- Create foreign key constraint and index on developer_id -ALTER TABLE docs - ADD CONSTRAINT fk_docs_developer - FOREIGN KEY (developer_id) - REFERENCES developers(developer_id); - -CREATE INDEX idx_docs_developer ON docs (developer_id); - --- Create trigger to automatically update updated_at -CREATE TRIGGER trg_docs_updated_at - BEFORE UPDATE ON docs - FOR EACH ROW - EXECUTE FUNCTION update_updated_at_column(); - --- Add comment to table -COMMENT ON TABLE docs IS 'Stores document metadata for developers'; +-- Create sorted index on doc_id if not exists +CREATE INDEX IF NOT EXISTS idx_docs_id_sorted ON docs (doc_id DESC); + +-- Create foreign key constraint if not exists (using DO block for safety) +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_constraint WHERE conname = 'fk_docs_developer' + ) THEN + ALTER TABLE docs + ADD CONSTRAINT fk_docs_developer + FOREIGN KEY (developer_id) + REFERENCES developers(developer_id); + END IF; +END $$; + +CREATE INDEX IF NOT EXISTS idx_docs_developer ON docs (developer_id); + +-- Create trigger if not exists +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_trigger WHERE tgname = 'trg_docs_updated_at' + ) THEN + CREATE TRIGGER trg_docs_updated_at + BEFORE UPDATE ON docs + FOR EACH ROW + EXECUTE FUNCTION update_updated_at_column(); + END IF; +END $$; -- Create the user_docs table -CREATE TABLE user_docs ( +CREATE TABLE IF NOT EXISTS user_docs ( developer_id UUID NOT NULL, user_id UUID NOT NULL, doc_id UUID NOT NULL, @@ -62,7 +75,7 @@ CREATE TABLE user_docs ( ); -- Create the agent_docs table -CREATE TABLE agent_docs ( +CREATE TABLE IF NOT EXISTS agent_docs ( developer_id UUID NOT NULL, agent_id UUID NOT NULL, doc_id UUID NOT NULL, @@ -71,12 +84,10 @@ CREATE TABLE agent_docs ( CONSTRAINT fk_agent_docs_doc FOREIGN KEY (developer_id, doc_id) REFERENCES docs(developer_id, doc_id) ); --- Indexes for efficient querying -CREATE INDEX idx_user_docs_user ON user_docs (developer_id, user_id); -CREATE INDEX idx_agent_docs_agent ON agent_docs (developer_id, agent_id); - --- Create a GIN index on the metadata column for efficient searching -CREATE INDEX idx_docs_metadata ON docs USING GIN (metadata); +-- Create indexes if not exists +CREATE INDEX IF NOT EXISTS idx_user_docs_user ON user_docs (developer_id, user_id); +CREATE INDEX IF NOT EXISTS idx_agent_docs_agent ON agent_docs (developer_id, agent_id); +CREATE INDEX IF NOT EXISTS idx_docs_metadata ON docs USING GIN (metadata); -- Enable necessary PostgreSQL extensions CREATE EXTENSION IF NOT EXISTS unaccent; @@ -109,8 +120,16 @@ BEGIN END $$; --- Add the column (not generated) -ALTER TABLE docs ADD COLUMN search_tsv tsvector; +-- Add the search_tsv column if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 FROM information_schema.columns + WHERE table_name = 'docs' AND column_name = 'search_tsv' + ) THEN + ALTER TABLE docs ADD COLUMN search_tsv tsvector; + END IF; +END $$; -- Create function to update tsvector CREATE OR REPLACE FUNCTION docs_update_search_tsv() @@ -123,24 +142,29 @@ BEGIN END; $$ LANGUAGE plpgsql; --- Create trigger -CREATE TRIGGER trg_docs_search_tsv - BEFORE INSERT OR UPDATE OF title, content, language - ON docs - FOR EACH ROW - EXECUTE FUNCTION docs_update_search_tsv(); - --- Create the index -CREATE INDEX idx_docs_search_tsv ON docs USING GIN (search_tsv); +-- Create trigger if not exists +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_trigger WHERE tgname = 'trg_docs_search_tsv' + ) THEN + CREATE TRIGGER trg_docs_search_tsv + BEFORE INSERT OR UPDATE OF title, content, language + ON docs + FOR EACH ROW + EXECUTE FUNCTION docs_update_search_tsv(); + END IF; +END $$; + +-- Create indexes if not exists +CREATE INDEX IF NOT EXISTS idx_docs_search_tsv ON docs USING GIN (search_tsv); +CREATE INDEX IF NOT EXISTS idx_docs_title_trgm ON docs USING GIN (title gin_trgm_ops); +CREATE INDEX IF NOT EXISTS idx_docs_content_trgm ON docs USING GIN (content gin_trgm_ops); -- Update existing rows (if any) UPDATE docs SET search_tsv = setweight(to_tsvector(language::regconfig, unaccent(coalesce(title, ''))), 'A') || - setweight(to_tsvector(language::regconfig, unaccent(coalesce(content, ''))), 'B'); - --- Create GIN trigram indexes for both title and content -CREATE INDEX idx_docs_title_trgm -ON docs USING GIN (title gin_trgm_ops); + setweight(to_tsvector(language::regconfig, unaccent(coalesce(content, ''))), 'B') +WHERE search_tsv IS NULL; -CREATE INDEX idx_docs_content_trgm -ON docs USING GIN (content gin_trgm_ops); \ No newline at end of file +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000007_ann.down.sql b/memory-store/migrations/000007_ann.down.sql new file mode 100644 index 000000000..2458c3dbd --- /dev/null +++ b/memory-store/migrations/000007_ann.down.sql @@ -0,0 +1,17 @@ +BEGIN; + +DO $$ +DECLARE + vectorizer_id INTEGER; +BEGIN + SELECT id INTO vectorizer_id + FROM ai.vectorizer + WHERE source_table = 'docs'; + + -- Drop the vectorizer if it exists + IF vectorizer_id IS NOT NULL THEN + PERFORM ai.drop_vectorizer(vectorizer_id, drop_all => true); + END IF; +END $$; + +COMMIT; diff --git a/memory-store/migrations/00007_ann.sql b/memory-store/migrations/000007_ann.up.sql similarity index 98% rename from memory-store/migrations/00007_ann.sql rename to memory-store/migrations/000007_ann.up.sql index 5f2157f02..0b08e9b07 100644 --- a/memory-store/migrations/00007_ann.sql +++ b/memory-store/migrations/000007_ann.up.sql @@ -1,5 +1,5 @@ -- Create vector similarity search index using diskann and timescale vectorizer -select ai.create_vectorizer( +SELECT ai.create_vectorizer( source => 'docs', destination => 'docs_embeddings', embedding => ai.embedding_voyageai('voyage-3', 1024), -- need to parameterize this diff --git a/memory-store/migrations/000008_tools.down.sql b/memory-store/migrations/000008_tools.down.sql new file mode 100644 index 000000000..2fa3077c0 --- /dev/null +++ b/memory-store/migrations/000008_tools.down.sql @@ -0,0 +1,6 @@ +BEGIN; + +-- Drop table and all its dependent objects (indexes, constraints, triggers) +DROP TABLE IF EXISTS tools CASCADE; + +COMMIT; diff --git a/memory-store/migrations/000008_tools.up.sql b/memory-store/migrations/000008_tools.up.sql new file mode 100644 index 000000000..bcf59def8 --- /dev/null +++ b/memory-store/migrations/000008_tools.up.sql @@ -0,0 +1,49 @@ +BEGIN; + +-- Create tools table if it doesn't exist +CREATE TABLE IF NOT EXISTS tools ( + developer_id UUID NOT NULL, + agent_id UUID NOT NULL, + tool_id UUID NOT NULL, + task_id UUID DEFAULT NULL, + task_version INT DEFAULT NULL, + type TEXT NOT NULL CONSTRAINT ct_tools_type_length CHECK (length(type) >= 1 AND length(type) <= 255), + name TEXT NOT NULL CONSTRAINT ct_tools_name_length CHECK (length(name) >= 1 AND length(name) <= 255), + description TEXT CONSTRAINT ct_tools_description_length CHECK (description IS NULL OR length(description) <= 1000), + spec JSONB NOT NULL, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + + CONSTRAINT pk_tools PRIMARY KEY (developer_id, agent_id, tool_id, type, name) +); + +-- Create sorted index on tool_id if it doesn't exist +CREATE INDEX IF NOT EXISTS idx_tools_id_sorted ON tools (tool_id DESC); + +-- Create sorted index on task_id if it doesn't exist +CREATE INDEX IF NOT EXISTS idx_tools_task_id_sorted ON tools (task_id DESC) WHERE task_id IS NOT NULL; + +-- Create foreign key constraint and index if they don't exist +DO $$ BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_constraint WHERE conname = 'fk_tools_agent' + ) THEN + ALTER TABLE tools + ADD CONSTRAINT fk_tools_agent + FOREIGN KEY (developer_id, agent_id) + REFERENCES agents(developer_id, agent_id); + END IF; +END $$; + +CREATE INDEX IF NOT EXISTS idx_tools_developer_agent ON tools (developer_id, agent_id); + +-- Drop trigger if exists and recreate +DROP TRIGGER IF EXISTS trg_tools_updated_at ON tools; +CREATE TRIGGER trg_tools_updated_at + BEFORE UPDATE ON tools + FOR EACH ROW + EXECUTE FUNCTION update_updated_at_column(); + +-- Add comment to table +COMMENT ON TABLE tools IS 'Stores tool configurations and specifications for AI agents'; +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000009_sessions.down.sql b/memory-store/migrations/000009_sessions.down.sql new file mode 100644 index 000000000..d1c0b2911 --- /dev/null +++ b/memory-store/migrations/000009_sessions.down.sql @@ -0,0 +1,20 @@ +BEGIN; + +-- Drop triggers first +DROP TRIGGER IF EXISTS trg_validate_participant_before_update ON session_lookup; +DROP TRIGGER IF EXISTS trg_validate_participant_before_insert ON session_lookup; + +-- Drop the validation function +DROP FUNCTION IF EXISTS validate_participant(); + +-- Drop session_lookup table and its indexes +DROP TABLE IF EXISTS session_lookup; + +-- Drop sessions table and its indexes +DROP TRIGGER IF EXISTS trg_sessions_updated_at ON sessions; +DROP TABLE IF EXISTS sessions CASCADE; + +-- Drop the enum type +DROP TYPE IF EXISTS participant_type; + +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000009_sessions.up.sql b/memory-store/migrations/000009_sessions.up.sql new file mode 100644 index 000000000..30f135ed7 --- /dev/null +++ b/memory-store/migrations/000009_sessions.up.sql @@ -0,0 +1,115 @@ +BEGIN; + +-- Create sessions table if it doesn't exist +CREATE TABLE IF NOT EXISTS sessions ( + developer_id UUID NOT NULL, + session_id UUID NOT NULL, + situation TEXT, + system_template TEXT NOT NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + -- TODO: Derived from entries + -- updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + metadata JSONB NOT NULL DEFAULT '{}'::JSONB, + render_templates BOOLEAN NOT NULL DEFAULT true, + token_budget INTEGER, + context_overflow TEXT, + forward_tool_calls BOOLEAN, + recall_options JSONB NOT NULL DEFAULT '{}'::JSONB, + CONSTRAINT pk_sessions PRIMARY KEY (developer_id, session_id) +); + +-- Create indexes if they don't exist +CREATE INDEX IF NOT EXISTS idx_sessions_id_sorted ON sessions (session_id DESC); +CREATE INDEX IF NOT EXISTS idx_sessions_metadata ON sessions USING GIN (metadata); + +-- Create foreign key if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_constraint WHERE conname = 'fk_sessions_developer' + ) THEN + ALTER TABLE sessions + ADD CONSTRAINT fk_sessions_developer + FOREIGN KEY (developer_id) + REFERENCES developers(developer_id); + END IF; +END $$; + +-- Create trigger if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_trigger WHERE tgname = 'trg_sessions_updated_at' + ) THEN + CREATE TRIGGER trg_sessions_updated_at + BEFORE UPDATE ON sessions + FOR EACH ROW + EXECUTE FUNCTION update_updated_at_column(); + END IF; +END $$; + +-- Create participant_type enum if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'participant_type') THEN + CREATE TYPE participant_type AS ENUM ('user', 'agent'); + END IF; +END $$; + +-- Create session_lookup table if it doesn't exist +CREATE TABLE IF NOT EXISTS session_lookup ( + developer_id UUID NOT NULL, + session_id UUID NOT NULL, + participant_type participant_type NOT NULL, + participant_id UUID NOT NULL, + PRIMARY KEY (developer_id, session_id, participant_type, participant_id), + FOREIGN KEY (developer_id, session_id) REFERENCES sessions(developer_id, session_id) +); + +-- Create indexes if they don't exist +CREATE INDEX IF NOT EXISTS idx_session_lookup_by_session ON session_lookup (developer_id, session_id); +CREATE INDEX IF NOT EXISTS idx_session_lookup_by_participant ON session_lookup (developer_id, participant_id); + +-- Create or replace the validation function +CREATE OR REPLACE FUNCTION validate_participant() RETURNS trigger AS $$ +BEGIN + IF NEW.participant_type = 'user' THEN + PERFORM 1 FROM users WHERE developer_id = NEW.developer_id AND user_id = NEW.participant_id; + IF NOT FOUND THEN + RAISE EXCEPTION 'Invalid participant_id: % for participant_type user', NEW.participant_id; + END IF; + ELSIF NEW.participant_type = 'agent' THEN + PERFORM 1 FROM agents WHERE developer_id = NEW.developer_id AND agent_id = NEW.participant_id; + IF NOT FOUND THEN + RAISE EXCEPTION 'Invalid participant_id: % for participant_type agent', NEW.participant_id; + END IF; + ELSE + RAISE EXCEPTION 'Unknown participant_type: %', NEW.participant_type; + END IF; + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +-- Create triggers if they don't exist +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 FROM pg_trigger WHERE tgname = 'trg_validate_participant_before_insert' + ) THEN + CREATE TRIGGER trg_validate_participant_before_insert + BEFORE INSERT ON session_lookup + FOR EACH ROW + EXECUTE FUNCTION validate_participant(); + END IF; + + IF NOT EXISTS ( + SELECT 1 FROM pg_trigger WHERE tgname = 'trg_validate_participant_before_update' + ) THEN + CREATE TRIGGER trg_validate_participant_before_update + BEFORE UPDATE ON session_lookup + FOR EACH ROW + EXECUTE FUNCTION validate_participant(); + END IF; +END $$; + +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000010_tasks.down.sql b/memory-store/migrations/000010_tasks.down.sql new file mode 100644 index 000000000..b7f758779 --- /dev/null +++ b/memory-store/migrations/000010_tasks.down.sql @@ -0,0 +1,18 @@ +BEGIN; + +-- Drop the foreign key constraint from tools table if it exists +DO $$ +BEGIN + IF EXISTS ( + SELECT 1 + FROM information_schema.table_constraints + WHERE constraint_name = 'fk_tools_task_id' + ) THEN + ALTER TABLE tools DROP CONSTRAINT fk_tools_task_id; + END IF; +END $$; + +-- Drop the tasks table and all its dependent objects (CASCADE will handle indexes, triggers, and constraints) +DROP TABLE IF EXISTS tasks CASCADE; + +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000010_tasks.up.sql b/memory-store/migrations/000010_tasks.up.sql new file mode 100644 index 000000000..c2bfeb454 --- /dev/null +++ b/memory-store/migrations/000010_tasks.up.sql @@ -0,0 +1,83 @@ +BEGIN; + +-- Create tasks table if it doesn't exist +CREATE TABLE IF NOT EXISTS tasks ( + developer_id UUID NOT NULL, + canonical_name CITEXT NOT NULL CONSTRAINT ct_tasks_canonical_name_length CHECK (length(canonical_name) >= 1 AND length(canonical_name) <= 255), + agent_id UUID NOT NULL, + task_id UUID NOT NULL, + version INTEGER NOT NULL DEFAULT 1, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + name TEXT NOT NULL CONSTRAINT ct_tasks_name_length CHECK (length(name) >= 1 AND length(name) <= 255), + description TEXT DEFAULT NULL CONSTRAINT ct_tasks_description_length CHECK (description IS NULL OR length(description) <= 1000), + input_schema JSON NOT NULL, + inherit_tools BOOLEAN DEFAULT FALSE, + workflows JSON[] DEFAULT ARRAY[]::JSON[], + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + metadata JSONB DEFAULT '{}'::JSONB, + CONSTRAINT pk_tasks PRIMARY KEY (developer_id, task_id), + CONSTRAINT uq_tasks_canonical_name_unique UNIQUE (developer_id, canonical_name), + CONSTRAINT uq_tasks_version_unique UNIQUE (task_id, version), + CONSTRAINT fk_tasks_agent + FOREIGN KEY (developer_id, agent_id) + REFERENCES agents(developer_id, agent_id), + CONSTRAINT ct_tasks_canonical_name_valid_identifier CHECK (canonical_name ~ '^[a-zA-Z][a-zA-Z0-9_]*$') +); + +-- Create sorted index on task_id if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_tasks_id_sorted') THEN + CREATE INDEX idx_tasks_id_sorted ON tasks (task_id DESC); + END IF; +END $$; + +-- Create index on developer_id if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_tasks_developer') THEN + CREATE INDEX idx_tasks_developer ON tasks (developer_id); + END IF; +END $$; + +-- Create a GIN index on metadata if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_tasks_metadata') THEN + CREATE INDEX idx_tasks_metadata ON tasks USING GIN (metadata); + END IF; +END $$; + +-- Add foreign key constraint if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 + FROM information_schema.table_constraints + WHERE constraint_name = 'fk_tools_task_id' + ) THEN + ALTER TABLE tools ADD CONSTRAINT fk_tools_task_id + FOREIGN KEY (task_id, task_version) REFERENCES tasks(task_id, version) + DEFERRABLE INITIALLY DEFERRED; + END IF; +END $$; + +-- Create trigger if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS ( + SELECT 1 + FROM pg_trigger + WHERE tgname = 'trg_tasks_updated_at' + ) THEN + CREATE TRIGGER trg_tasks_updated_at + BEFORE UPDATE ON tasks + FOR EACH ROW + EXECUTE FUNCTION update_updated_at_column(); + END IF; +END $$; + +-- Add comment to table (comments are idempotent by default) +COMMENT ON TABLE tasks IS 'Stores tasks associated with AI agents for developers'; + +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000011_executions.down.sql b/memory-store/migrations/000011_executions.down.sql new file mode 100644 index 000000000..e6c362d0e --- /dev/null +++ b/memory-store/migrations/000011_executions.down.sql @@ -0,0 +1,5 @@ +BEGIN; + +DROP TABLE IF EXISTS executions CASCADE; + +COMMIT; diff --git a/memory-store/migrations/00011_executions.sql b/memory-store/migrations/000011_executions.up.sql similarity index 57% rename from memory-store/migrations/00011_executions.sql rename to memory-store/migrations/000011_executions.up.sql index 031deea0e..74ab5bf97 100644 --- a/memory-store/migrations/00011_executions.sql +++ b/memory-store/migrations/000011_executions.up.sql @@ -1,16 +1,22 @@ --- Migration to create executions table -CREATE TABLE executions ( +BEGIN; + +-- Create executions table if it doesn't exist +CREATE TABLE IF NOT EXISTS executions ( developer_id UUID NOT NULL, task_id UUID NOT NULL, + task_version INTEGER NOT NULL, execution_id UUID NOT NULL, input JSONB NOT NULL, - -- TODO: These will be generated using continuous aggregates from transitions + + -- NOTE: These will be generated using continuous aggregates from transitions -- status TEXT DEFAULT 'pending', -- output JSONB DEFAULT NULL, -- error TEXT DEFAULT NULL, -- updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + metadata JSONB NOT NULL DEFAULT '{}'::JSONB, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + CONSTRAINT pk_executions PRIMARY KEY (execution_id), CONSTRAINT fk_executions_developer FOREIGN KEY (developer_id) REFERENCES developers(developer_id), @@ -19,13 +25,17 @@ CREATE TABLE executions ( ); -- Create sorted index on execution_id (optimized for UUID v7) -CREATE INDEX idx_executions_execution_id_sorted ON executions (execution_id DESC); +CREATE INDEX IF NOT EXISTS idx_executions_execution_id_sorted ON executions (execution_id DESC); -- Create index on developer_id -CREATE INDEX idx_executions_developer_id ON executions (developer_id); +CREATE INDEX IF NOT EXISTS idx_executions_developer_id ON executions (developer_id); + +-- Create index on task_id +CREATE INDEX IF NOT EXISTS idx_executions_task_id ON executions (task_id); -- Create a GIN index on the metadata column -CREATE INDEX idx_executions_metadata ON executions USING GIN (metadata); +CREATE INDEX IF NOT EXISTS idx_executions_metadata ON executions USING GIN (metadata); --- Add comment to table -COMMENT ON TABLE executions IS 'Stores executions associated with AI agents for developers'; \ No newline at end of file +-- Add comment to table (comments are idempotent by default) +COMMENT ON TABLE executions IS 'Stores executions associated with AI agents for developers'; +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/000012_transitions.down.sql b/memory-store/migrations/000012_transitions.down.sql new file mode 100644 index 000000000..590ebc901 --- /dev/null +++ b/memory-store/migrations/000012_transitions.down.sql @@ -0,0 +1,26 @@ +BEGIN; + +-- Drop foreign key constraint if exists +ALTER TABLE IF EXISTS transitions + DROP CONSTRAINT IF EXISTS fk_transitions_execution; + +-- Drop indexes if they exist +DROP INDEX IF EXISTS idx_transitions_metadata; +DROP INDEX IF EXISTS idx_transitions_execution_id_sorted; +DROP INDEX IF EXISTS idx_transitions_transition_id_sorted; +DROP INDEX IF EXISTS idx_transitions_label; +DROP INDEX IF EXISTS idx_transitions_next; +DROP INDEX IF EXISTS idx_transitions_current; + +-- Drop the transitions table (this will also remove it from hypertables) +DROP TABLE IF EXISTS transitions; + +-- Drop custom types if they exist +DROP TYPE IF EXISTS transition_cursor; +DROP TYPE IF EXISTS transition_type; + +-- Drop the trigger and function for transition validation +DROP TRIGGER IF EXISTS validate_transition ON transitions; +DROP FUNCTION IF EXISTS check_valid_transition(); + +COMMIT; diff --git a/memory-store/migrations/000012_transitions.up.sql b/memory-store/migrations/000012_transitions.up.sql new file mode 100644 index 000000000..515af713c --- /dev/null +++ b/memory-store/migrations/000012_transitions.up.sql @@ -0,0 +1,154 @@ +BEGIN; + +-- Create transition type enum if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'transition_type') THEN + CREATE TYPE transition_type AS ENUM ( + 'init', + 'finish', + 'init_branch', + 'finish_branch', + 'wait', + 'resume', + 'error', + 'step', + 'cancelled' + ); + END IF; +END $$; + +-- Create transition cursor type if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'transition_cursor') THEN + CREATE TYPE transition_cursor AS ( + workflow_name TEXT, + step_index INT + ); + END IF; +END $$; + +-- Create transitions table if it doesn't exist +CREATE TABLE IF NOT EXISTS transitions ( + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + execution_id UUID NOT NULL, + transition_id UUID NOT NULL, + type transition_type NOT NULL, + step_definition JSONB NOT NULL, + step_label TEXT DEFAULT NULL, + current_step transition_cursor NOT NULL, + next_step transition_cursor DEFAULT NULL, + output JSONB, + task_token TEXT DEFAULT NULL, + metadata JSONB DEFAULT '{}'::JSONB, + CONSTRAINT pk_transitions PRIMARY KEY (created_at, execution_id, transition_id) +); + +-- Convert to hypertable if not already +SELECT create_hypertable('transitions', by_range('created_at', INTERVAL '1 day'), if_not_exists => TRUE); +SELECT add_dimension('transitions', by_hash('execution_id', 2), if_not_exists => TRUE); + +-- Create indexes if they don't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_transitions_current') THEN + CREATE UNIQUE INDEX idx_transitions_current ON transitions (execution_id, current_step, created_at DESC); + END IF; + + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_transitions_next') THEN + CREATE UNIQUE INDEX idx_transitions_next ON transitions (execution_id, next_step, created_at DESC) + WHERE next_step IS NOT NULL; + END IF; + + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_transitions_label') THEN + CREATE UNIQUE INDEX idx_transitions_label ON transitions (execution_id, step_label, created_at DESC) + WHERE step_label IS NOT NULL; + END IF; + + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_transitions_transition_id_sorted') THEN + CREATE INDEX idx_transitions_transition_id_sorted ON transitions (transition_id DESC, created_at DESC); + END IF; + + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_transitions_execution_id_sorted') THEN + CREATE INDEX idx_transitions_execution_id_sorted ON transitions (execution_id DESC, created_at DESC); + END IF; + + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_transitions_metadata') THEN + CREATE INDEX idx_transitions_metadata ON transitions USING GIN (metadata); + END IF; +END $$; + +-- Add foreign key constraint if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'fk_transitions_execution') THEN + ALTER TABLE transitions + ADD CONSTRAINT fk_transitions_execution + FOREIGN KEY (execution_id) + REFERENCES executions(execution_id); + END IF; +END $$; + +-- Add comment to table +COMMENT ON TABLE transitions IS 'Stores transitions associated with AI agents for developers'; + +-- Create a trigger function that checks for valid transitions +CREATE OR REPLACE FUNCTION check_valid_transition() RETURNS trigger AS $$ +DECLARE + previous_type transition_type; + valid_next_types transition_type[]; +BEGIN + -- Get the latest transition_type for this execution_id + SELECT t.type INTO previous_type + FROM transitions t + WHERE t.execution_id = NEW.execution_id + ORDER BY t.created_at DESC + LIMIT 1; + + IF previous_type IS NULL THEN + -- If there is no previous transition, allow only 'init' or 'init_branch' + IF NEW.type NOT IN ('init', 'init_branch') THEN + RAISE EXCEPTION 'First transition must be init or init_branch, got %', NEW.type; + END IF; + ELSE + -- Define the valid_next_types array based on previous_type + CASE previous_type + WHEN 'init' THEN + valid_next_types := ARRAY['wait', 'error', 'step', 'cancelled', 'init_branch', 'finish']; + WHEN 'init_branch' THEN + valid_next_types := ARRAY['wait', 'error', 'step', 'cancelled', 'init_branch', 'finish_branch', 'finish']; + WHEN 'wait' THEN + valid_next_types := ARRAY['resume', 'step', 'cancelled', 'finish', 'finish_branch']; + WHEN 'resume' THEN + valid_next_types := ARRAY['wait', 'error', 'cancelled', 'step', 'finish', 'finish_branch', 'init_branch']; + WHEN 'step' THEN + valid_next_types := ARRAY['wait', 'error', 'cancelled', 'step', 'finish', 'finish_branch', 'init_branch']; + WHEN 'finish_branch' THEN + valid_next_types := ARRAY['wait', 'error', 'cancelled', 'step', 'finish', 'init_branch', 'finish_branch']; + WHEN 'finish' THEN + valid_next_types := ARRAY[]::transition_type[]; -- No valid next transitions + WHEN 'error' THEN + valid_next_types := ARRAY[]::transition_type[]; -- No valid next transitions + WHEN 'cancelled' THEN + valid_next_types := ARRAY[]::transition_type[]; -- No valid next transitions + ELSE + RAISE EXCEPTION 'Unknown previous transition type: %', previous_type; + END CASE; + + IF NOT NEW.type = ANY(valid_next_types) THEN + RAISE EXCEPTION 'Invalid transition from % to %', previous_type, NEW.type; + END IF; + END IF; + + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +-- Create a trigger on the transitions table +CREATE TRIGGER validate_transition +BEFORE INSERT ON transitions +FOR EACH ROW +EXECUTE FUNCTION check_valid_transition(); + +COMMIT; \ No newline at end of file diff --git a/memory-store/migrations/00003_users.sql b/memory-store/migrations/00003_users.sql deleted file mode 100644 index 0d9f76ff7..000000000 --- a/memory-store/migrations/00003_users.sql +++ /dev/null @@ -1,34 +0,0 @@ --- Create users table -CREATE TABLE users ( - developer_id UUID NOT NULL, - user_id UUID NOT NULL, - name TEXT NOT NULL, - about TEXT, - created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - metadata JSONB NOT NULL DEFAULT '{}'::JSONB, - CONSTRAINT pk_users PRIMARY KEY (developer_id, user_id) -); - --- Create sorted index on user_id (optimized for UUID v7) -CREATE INDEX users_id_sorted_idx ON users (user_id DESC); - --- Create foreign key constraint and index on developer_id -ALTER TABLE users - ADD CONSTRAINT users_developer_id_fkey - FOREIGN KEY (developer_id) - REFERENCES developers(developer_id); - -CREATE INDEX users_developer_id_idx ON users (developer_id); - --- Create a GIN index on the entire metadata column -CREATE INDEX users_metadata_gin_idx ON users USING GIN (metadata); - --- Create trigger to automatically update updated_at -CREATE TRIGGER update_users_updated_at - BEFORE UPDATE ON users - FOR EACH ROW - EXECUTE FUNCTION update_updated_at_column(); - --- Add comment to table -COMMENT ON TABLE users IS 'Stores user information linked to developers'; \ No newline at end of file diff --git a/memory-store/migrations/00008_tools.sql b/memory-store/migrations/00008_tools.sql deleted file mode 100644 index ec5d8590d..000000000 --- a/memory-store/migrations/00008_tools.sql +++ /dev/null @@ -1,33 +0,0 @@ --- Create tools table -CREATE TABLE tools ( - developer_id UUID NOT NULL, - agent_id UUID NOT NULL, - tool_id UUID NOT NULL, - type TEXT NOT NULL CONSTRAINT ct_tools_type_length CHECK (length(type) >= 1 AND length(type) <= 255), - name TEXT NOT NULL CONSTRAINT ct_tools_name_length CHECK (length(name) >= 1 AND length(name) <= 255), - description TEXT CONSTRAINT ct_tools_description_length CHECK (description IS NULL OR length(description) <= 1000), - spec JSONB NOT NULL, - updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - CONSTRAINT pk_tools PRIMARY KEY (developer_id, agent_id, tool_id) -); - --- Create sorted index on tool_id (optimized for UUID v7) -CREATE INDEX idx_tools_id_sorted ON tools (tool_id DESC); - --- Create foreign key constraint and index on developer_id and agent_id -ALTER TABLE tools - ADD CONSTRAINT fk_tools_agent - FOREIGN KEY (developer_id, agent_id) - REFERENCES agents(developer_id, agent_id); - -CREATE INDEX idx_tools_developer_agent ON tools (developer_id, agent_id); - --- Create trigger to automatically update updated_at -CREATE TRIGGER trg_tools_updated_at - BEFORE UPDATE ON tools - FOR EACH ROW - EXECUTE FUNCTION update_updated_at_column(); - --- Add comment to table -COMMENT ON TABLE tools IS 'Stores tool configurations and specifications for AI agents'; \ No newline at end of file diff --git a/memory-store/migrations/00009_sessions.sql b/memory-store/migrations/00009_sessions.sql deleted file mode 100644 index d79517f86..000000000 --- a/memory-store/migrations/00009_sessions.sql +++ /dev/null @@ -1,99 +0,0 @@ --- Create sessions table -CREATE TABLE sessions ( - developer_id UUID NOT NULL, - session_id UUID NOT NULL, - situation TEXT, - system_template TEXT NOT NULL, - created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - metadata JSONB NOT NULL DEFAULT '{}'::JSONB, - render_templates BOOLEAN NOT NULL DEFAULT true, - token_budget INTEGER, - context_overflow TEXT, - forward_tool_calls BOOLEAN, - recall_options JSONB NOT NULL DEFAULT '{}'::JSONB, - CONSTRAINT pk_sessions PRIMARY KEY (developer_id, session_id) -); - --- Create sorted index on session_id (optimized for UUID v7) -CREATE INDEX idx_sessions_id_sorted ON sessions (session_id DESC); - --- Create index for updated_at since we'll sort by it -CREATE INDEX idx_sessions_updated_at ON sessions (updated_at DESC); - --- Create foreign key constraint and index on developer_id -ALTER TABLE sessions - ADD CONSTRAINT fk_sessions_developer - FOREIGN KEY (developer_id) - REFERENCES developers(developer_id); - -CREATE INDEX idx_sessions_developer ON sessions (developer_id); - --- Create a GIN index on the metadata column -CREATE INDEX idx_sessions_metadata ON sessions USING GIN (metadata); - --- Create trigger to automatically update updated_at -CREATE TRIGGER trg_sessions_updated_at - BEFORE UPDATE ON sessions - FOR EACH ROW - EXECUTE FUNCTION update_updated_at_column(); - --- Add comment to table -COMMENT ON TABLE sessions IS 'Stores chat sessions and their configurations'; - --- Create session_lookup table with participant type enum -DO $$ -BEGIN - IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'participant_type') THEN - CREATE TYPE participant_type AS ENUM ('user', 'agent'); - END IF; -END -$$; - --- Create session_lookup table without the CHECK constraint -CREATE TABLE session_lookup ( - developer_id UUID NOT NULL, - session_id UUID NOT NULL, - participant_type participant_type NOT NULL, - participant_id UUID NOT NULL, - PRIMARY KEY (developer_id, session_id, participant_type, participant_id), - FOREIGN KEY (developer_id, session_id) REFERENCES sessions(developer_id, session_id) -); - --- Create indexes for common query patterns -CREATE INDEX idx_session_lookup_by_session ON session_lookup (developer_id, session_id); -CREATE INDEX idx_session_lookup_by_participant ON session_lookup (developer_id, participant_id); - --- Add comments to the table -COMMENT ON TABLE session_lookup IS 'Maps sessions to their participants (users and agents)'; - --- Create trigger function to enforce conditional foreign keys -CREATE OR REPLACE FUNCTION validate_participant() RETURNS trigger AS $$ -BEGIN - IF NEW.participant_type = 'user' THEN - PERFORM 1 FROM users WHERE developer_id = NEW.developer_id AND user_id = NEW.participant_id; - IF NOT FOUND THEN - RAISE EXCEPTION 'Invalid participant_id: % for participant_type user', NEW.participant_id; - END IF; - ELSIF NEW.participant_type = 'agent' THEN - PERFORM 1 FROM agents WHERE developer_id = NEW.developer_id AND agent_id = NEW.participant_id; - IF NOT FOUND THEN - RAISE EXCEPTION 'Invalid participant_id: % for participant_type agent', NEW.participant_id; - END IF; - ELSE - RAISE EXCEPTION 'Unknown participant_type: %', NEW.participant_type; - END IF; - RETURN NEW; -END; -$$ LANGUAGE plpgsql; - --- Create triggers for INSERT and UPDATE operations -CREATE TRIGGER trg_validate_participant_before_insert - BEFORE INSERT ON session_lookup - FOR EACH ROW - EXECUTE FUNCTION validate_participant(); - -CREATE TRIGGER trg_validate_participant_before_update - BEFORE UPDATE ON session_lookup - FOR EACH ROW - EXECUTE FUNCTION validate_participant(); \ No newline at end of file diff --git a/memory-store/migrations/00010_tasks.sql b/memory-store/migrations/00010_tasks.sql deleted file mode 100644 index 66bd8ffc4..000000000 --- a/memory-store/migrations/00010_tasks.sql +++ /dev/null @@ -1,40 +0,0 @@ --- Create tasks table -CREATE TABLE tasks ( - developer_id UUID NOT NULL, - canonical_name CITEXT NOT NULL CONSTRAINT ct_tasks_canonical_name_length CHECK (length(canonical_name) >= 1 AND length(canonical_name) <= 255), - agent_id UUID NOT NULL, - task_id UUID NOT NULL, - updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - name TEXT NOT NULL CONSTRAINT ct_tasks_name_length CHECK (length(name) >= 1 AND length(name) <= 255), - description TEXT DEFAULT NULL CONSTRAINT ct_tasks_description_length CHECK (description IS NULL OR length(description) <= 1000), - input_schema JSON NOT NULL, - tools JSON[] DEFAULT ARRAY[]::JSON[], - inherit_tools BOOLEAN DEFAULT FALSE, - workflows JSON[] DEFAULT ARRAY[]::JSON[], - created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - metadata JSONB DEFAULT '{}'::JSONB, - CONSTRAINT pk_tasks PRIMARY KEY (developer_id, task_id), - CONSTRAINT uq_tasks_canonical_name_unique UNIQUE (developer_id, canonical_name), - CONSTRAINT fk_tasks_agent - FOREIGN KEY (developer_id, agent_id) - REFERENCES agents(developer_id, agent_id), - CONSTRAINT ct_tasks_canonical_name_valid_identifier CHECK (canonical_name ~ '^[a-zA-Z][a-zA-Z0-9_]*$') -); - --- Create sorted index on task_id (optimized for UUID v7) -CREATE INDEX idx_tasks_id_sorted ON tasks (task_id DESC); - --- Create foreign key constraint and index on developer_id -CREATE INDEX idx_tasks_developer ON tasks (developer_id); - --- Create a GIN index on the entire metadata column -CREATE INDEX idx_tasks_metadata ON tasks USING GIN (metadata); - --- Create trigger to automatically update updated_at -CREATE TRIGGER trg_tasks_updated_at - BEFORE UPDATE ON tasks - FOR EACH ROW - EXECUTE FUNCTION update_updated_at_column(); - --- Add comment to table -COMMENT ON TABLE tasks IS 'Stores tasks associated with AI agents for developers'; \ No newline at end of file diff --git a/memory-store/migrations/00012_transitions.sql b/memory-store/migrations/00012_transitions.sql deleted file mode 100644 index 3bc3ea290..000000000 --- a/memory-store/migrations/00012_transitions.sql +++ /dev/null @@ -1,66 +0,0 @@ --- Create transition type enum -CREATE TYPE transition_type AS ENUM ( - 'init', - 'finish', - 'init_branch', - 'finish_branch', - 'wait', - 'resume', - 'error', - 'step', - 'cancelled' -); - --- Create transition cursor type -CREATE TYPE transition_cursor AS ( - workflow_name TEXT, - step_index INT -); - --- Create transitions table -CREATE TABLE transitions ( - created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, - execution_id UUID NOT NULL, - transition_id UUID NOT NULL, - type transition_type NOT NULL, - step_definition JSONB NOT NULL, - step_label TEXT DEFAULT NULL, - current_step transition_cursor NOT NULL, - next_step transition_cursor DEFAULT NULL, - output JSONB, - task_token TEXT DEFAULT NULL, - metadata JSONB DEFAULT '{}'::JSONB, - CONSTRAINT pk_transitions PRIMARY KEY (created_at, execution_id, transition_id) -); - --- Convert to hypertable -SELECT create_hypertable('transitions', 'created_at'); - --- Create unique constraint for current step -CREATE UNIQUE INDEX idx_transitions_current ON transitions (execution_id, current_step, created_at DESC); - --- Create unique constraint for next step (excluding nulls) -CREATE UNIQUE INDEX idx_transitions_next ON transitions (execution_id, next_step, created_at DESC) -WHERE next_step IS NOT NULL; - --- Create unique constraint for step label (excluding nulls) -CREATE UNIQUE INDEX idx_transitions_label ON transitions (execution_id, step_label, created_at DESC) -WHERE step_label IS NOT NULL; - --- Create sorted index on transition_id (optimized for UUID v7) -CREATE INDEX idx_transitions_transition_id_sorted ON transitions (transition_id DESC, created_at DESC); - --- Create sorted index on execution_id (optimized for UUID v7) -CREATE INDEX idx_transitions_execution_id_sorted ON transitions (execution_id DESC, created_at DESC); - --- Create a GIN index on the metadata column -CREATE INDEX idx_transitions_metadata ON transitions USING GIN (metadata); - --- Add foreign key constraint -ALTER TABLE transitions - ADD CONSTRAINT fk_transitions_execution - FOREIGN KEY (execution_id) - REFERENCES executions(execution_id); - --- Add comment to table -COMMENT ON TABLE transitions IS 'Stores transitions associated with AI agents for developers'; \ No newline at end of file