Skip to content
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
7 changes: 7 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,13 @@

## Unreleased | TBA

- Add `conversation_transcript` view for human-readable conversation logs (#112)
- SQL view extracts clean prompt/response format from `conversation_events`
- Handles both string and array content (Anthropic multimodal format)
- Columns: session_id, created_at, prompt_or_response, model, content, logged_by_luthien, call_id
- No truncation - full content preserved for debugging
- Add `docs/database-schema.md` documentation

- Migration validation and fail-fast checks (#110)
- `run-migrations.sh` validates DB state against local files before applying
- Gateway startup check ensures all migrations are applied
Expand Down
6 changes: 6 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -451,6 +451,12 @@ See `src/luthien_proxy/policies/` for examples. Documentation coming soon.
docker compose logs -f gateway
```

## Documentation

- **Database Schema**: [docs/database-schema.md](docs/database-schema.md) - Tables, views, and querying tips
- **Observability Guide**: [dev/observability.md](dev/observability.md) - Tracing and logging setup
- **OpenTelemetry Conventions**: [dev/context/otel-conventions.md](dev/context/otel-conventions.md)

## Troubleshooting

### Gateway not starting
Expand Down
126 changes: 126 additions & 0 deletions docs/database-schema.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,126 @@
# Database Schema

This document describes the Luthien proxy database schema for conversation tracking and debugging.

## Overview

Luthien stores conversation data in PostgreSQL for debugging, observability, and compliance purposes.

## Tables

### `conversation_calls`
One row per API call through the proxy.

| Column | Type | Description |
|--------|------|-------------|
| `call_id` | TEXT (PK) | Unique identifier for the API call |
| `model_name` | TEXT | Model requested (e.g., claude-sonnet-4-5) |
| `provider` | TEXT | LLM provider |
| `status` | TEXT | Call status (started, success, etc.) |
| `created_at` | TIMESTAMPTZ | When the call started |
| `completed_at` | TIMESTAMPTZ | When the call completed |

### `conversation_events`
Raw events for each call. Contains full JSON payloads.

| Column | Type | Description |
|--------|------|-------------|
| `id` | UUID (PK) | Event unique identifier |
| `call_id` | TEXT (FK) | References conversation_calls |
| `event_type` | TEXT | Event type (see below) |
| `payload` | JSONB | Full event data |
| `created_at` | TIMESTAMPTZ | Event timestamp |
| `session_id` | TEXT | Session identifier (may be NULL) |

**Event Types:**
- `pipeline.client_request` - Incoming request from client
- `pipeline.format_conversion` - Format conversion (Anthropic <-> OpenAI)
- `transaction.request_recorded` - Final request sent to LLM
- `pipeline.backend_request` - Request to backend LLM
- `transaction.streaming_response_recorded` - Streaming response completed
- `transaction.non_streaming_response_recorded` - Non-streaming response

### `policy_events`
Policy decisions and modifications.

| Column | Type | Description |
|--------|------|-------------|
| `id` | UUID (PK) | Event unique identifier |
| `call_id` | TEXT (FK) | References conversation_calls |
| `policy_class` | TEXT | Policy class name |
| `policy_config` | JSONB | Policy configuration |
| `event_type` | TEXT | Policy event type |
| `metadata` | JSONB | Additional metadata |
| `created_at` | TIMESTAMPTZ | Event timestamp |

### `conversation_judge_decisions`
LLM judge policy decisions.

| Column | Type | Description |
|--------|------|-------------|
| `id` | UUID (PK) | Decision unique identifier |
| `call_id` | TEXT (FK) | References conversation_calls |
| `probability` | DOUBLE | Judge probability score |
| `explanation` | TEXT | Judge explanation |
| `tool_call` | JSONB | Tool call being judged |
| `created_at` | TIMESTAMPTZ | Decision timestamp |

## Views

### `conversation_transcript`
Human-readable conversation log. Use this for debugging and session review instead of raw `conversation_events`.

| Column | Type | Description |
|--------|------|-------------|
| `session_id` | TEXT | Session identifier (may be NULL) |
| `created_at` | TIMESTAMPTZ | Event timestamp |
| `prompt_or_response` | TEXT | `PROMPT` or `RESPONSE` |
| `model` | TEXT | Model name |
| `content` | TEXT | Full message content (no truncation) |
| `logged_by_luthien` | TEXT | Always `Y` for Luthien-logged data |
| `call_id` | TEXT | For drill-down to raw events |

**Limitations:**
- Only extracts the **last user message** from multi-message requests
- **Tool calls are not shown** - only text content is extracted
- `session_id` is only populated for certain event types (may be NULL)

**Example usage:**
```sql
-- View recent conversation
SELECT * FROM conversation_transcript
ORDER BY created_at DESC
LIMIT 20;

-- Export session as CSV
\copy (SELECT * FROM conversation_transcript WHERE session_id = 'xxx') TO 'session.csv' WITH CSV HEADER;

-- View specific call's back-and-forth
SELECT created_at, prompt_or_response, LEFT(content, 100) as preview
FROM conversation_transcript
WHERE call_id = 'xxx'
ORDER BY created_at;
```

## Querying Tips

### Export conversation to CSV
```bash
docker exec luthien-proxy-db-1 psql -U luthien -d luthien_control -c "\copy (SELECT * FROM conversation_transcript ORDER BY created_at DESC LIMIT 100) TO STDOUT WITH CSV HEADER" > conversation.csv
```

### Find calls by model
```sql
SELECT * FROM conversation_calls
WHERE model_name LIKE '%claude%'
ORDER BY created_at DESC;
```

### Debug a specific call
```sql
-- Get all events for a call
SELECT event_type, created_at, payload
FROM conversation_events
WHERE call_id = 'your-call-id'
ORDER BY created_at;
```
82 changes: 82 additions & 0 deletions migrations/007_add_conversation_transcript_view.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
-- ABOUTME: Creates conversation_transcript view for human-readable prompt/response logs
-- ABOUTME: Extracts clean text from conversation_events JSON payloads

-- =============================================================================
-- conversation_transcript View
-- =============================================================================
-- PURPOSE: Provides a human-readable view of conversations for debugging.
-- Instead of digging through raw JSON in conversation_events, this view
-- extracts the actual prompt/response text.
--
-- WHY THIS MATTERS: Users debugging issues find the raw conversation_events
-- table too messy (nested JSON payloads). This view gives a clean
-- CSV-exportable format for reviewing what actually happened.
--
-- LIMITATIONS (see docs/database-schema.md for full details):
-- - Only extracts the LAST user message from multi-message requests
-- - Tool calls are not shown (text content only)
-- - session_id may be NULL for some events
-- =============================================================================

CREATE OR REPLACE VIEW conversation_transcript AS
SELECT
ce.session_id,
ce.created_at,

-- Map event types to human-readable PROMPT/RESPONSE labels
CASE
WHEN ce.event_type = 'pipeline.client_request' THEN 'PROMPT'
WHEN ce.event_type LIKE '%response_recorded' THEN 'RESPONSE'
END AS prompt_or_response,

-- Extract model name from the appropriate JSON path per event type
CASE
WHEN ce.event_type = 'pipeline.client_request' THEN
ce.payload->'payload'->>'model'
WHEN ce.event_type LIKE '%response_recorded' THEN
ce.payload->'final_response'->>'model'
END AS model,

-- Extract content, handling format differences:
-- - PROMPTS can be string (OpenAI) or array of content blocks (Anthropic)
-- - RESPONSES use OpenAI format with choices[0].message.content
-- NOTE: We only extract the LAST message (->-1) because that's the user's
-- actual prompt in a multi-turn conversation. Earlier messages are context.
CASE
WHEN ce.event_type = 'pipeline.client_request' THEN
CASE
-- Simple string content (OpenAI format)
WHEN jsonb_typeof(ce.payload->'payload'->'messages'->-1->'content') = 'string' THEN
ce.payload->'payload'->'messages'->-1->>'content'
-- Array of content blocks (Anthropic format) - join all text blocks
WHEN jsonb_typeof(ce.payload->'payload'->'messages'->-1->'content') = 'array' THEN
(SELECT string_agg(elem->>'text', ' ')
FROM jsonb_array_elements(ce.payload->'payload'->'messages'->-1->'content') AS elem
WHERE elem->>'type' = 'text')
ELSE NULL
END
WHEN ce.event_type LIKE '%response_recorded' THEN
-- Response content is in OpenAI format (LiteLLM standardizes to this)
ce.payload->'final_response'->'choices'->0->'message'->>'content'
END AS content,

-- Always 'Y' for Luthien-logged data. This column exists so users can
-- combine Luthien logs with manually-added entries and distinguish them.
'Y' AS logged_by_luthien,

ce.call_id

FROM conversation_events ce
WHERE ce.event_type IN (
'pipeline.client_request', -- User prompts
'transaction.streaming_response_recorded', -- Streaming responses
'transaction.non_streaming_response_recorded' -- Non-streaming responses
);

COMMENT ON VIEW conversation_transcript IS
'Human-readable conversation log. Use for debugging instead of raw conversation_events. '
'No ORDER BY - add your own when querying. See docs/database-schema.md for limitations.';

-- Performance index for filtering by event_type and ordering by time
CREATE INDEX IF NOT EXISTS idx_conversation_events_type_created
ON conversation_events(event_type, created_at);
Loading
Loading