9.6 KiB
9.6 KiB
Implementation Plan: Hybrid Schema Migration
Overview
Migrating from the current two-table design (event + tag tables) to a single event table with JSON tags column and event type classification.
Current Schema → Target Schema
Current Schema (to be replaced)
CREATE TABLE event (
id TEXT PRIMARY KEY,
pubkey TEXT NOT NULL,
created_at INTEGER NOT NULL,
kind INTEGER NOT NULL,
content TEXT NOT NULL,
sig TEXT NOT NULL
);
CREATE TABLE tag (
id TEXT NOT NULL, -- references event.id
name TEXT NOT NULL,
value TEXT NOT NULL,
parameters TEXT
);
Target Schema (simplified from final recommendation)
CREATE TABLE events (
id TEXT PRIMARY KEY,
pubkey TEXT NOT NULL,
created_at INTEGER NOT NULL,
kind INTEGER NOT NULL,
event_type TEXT NOT NULL CHECK (event_type IN ('regular', 'replaceable', 'ephemeral', 'addressable')),
content TEXT NOT NULL,
sig TEXT NOT NULL,
tags JSON NOT NULL DEFAULT '[]',
first_seen INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
-- Optional: Protocol compliance constraints (can be added later)
CONSTRAINT unique_replaceable
UNIQUE (pubkey, kind) WHERE event_type = 'replaceable',
CONSTRAINT unique_addressable
UNIQUE (pubkey, kind, json_extract(tags, '$[?(@[0]=="d")][1]'))
WHERE event_type = 'addressable'
);
Implementation Steps
Phase 1: Update Schema File
File: db/schema.sql
- Replace current event table definition
- Remove tag table completely
- Add new indexes for performance
- Add event type classification logic
Phase 2: Update C Code
File: src/main.c
- Add event type classification function
- Update
store_event()function to use JSON tags - Update
retrieve_event()function to return JSON tags - Remove all tag table related code
- Update REQ query handling to use JSON tag queries
Phase 3: Update Database Initialization
File: db/init.sh
- Update table count validation (expect 1 table instead of 2)
- Update schema verification logic
Phase 4: Update Tests
File: tests/1_nip_test.sh
- Verify events are stored with JSON tags
- Test query functionality with new schema
- Validate event type classification
Phase 5: Migration Strategy
Create migration script to handle existing data (if any).
Detailed Implementation
1. Event Type Classification
// Add to src/main.c
typedef enum {
EVENT_TYPE_REGULAR,
EVENT_TYPE_REPLACEABLE,
EVENT_TYPE_EPHEMERAL,
EVENT_TYPE_ADDRESSABLE,
EVENT_TYPE_UNKNOWN
} event_type_t;
event_type_t classify_event_kind(int kind) {
if ((kind >= 1000 && kind < 10000) ||
(kind >= 4 && kind < 45) ||
kind == 1 || kind == 2) {
return EVENT_TYPE_REGULAR;
}
if ((kind >= 10000 && kind < 20000) ||
kind == 0 || kind == 3) {
return EVENT_TYPE_REPLACEABLE;
}
if (kind >= 20000 && kind < 30000) {
return EVENT_TYPE_EPHEMERAL;
}
if (kind >= 30000 && kind < 40000) {
return EVENT_TYPE_ADDRESSABLE;
}
return EVENT_TYPE_UNKNOWN;
}
const char* event_type_to_string(event_type_t type) {
switch (type) {
case EVENT_TYPE_REGULAR: return "regular";
case EVENT_TYPE_REPLACEABLE: return "replaceable";
case EVENT_TYPE_EPHEMERAL: return "ephemeral";
case EVENT_TYPE_ADDRESSABLE: return "addressable";
default: return "unknown";
}
}
2. Updated store_event Function
// Replace existing store_event function
int store_event(cJSON* event) {
if (!g_db || !event) {
return -1;
}
// Extract event fields
cJSON* id = cJSON_GetObjectItem(event, "id");
cJSON* pubkey = cJSON_GetObjectItem(event, "pubkey");
cJSON* created_at = cJSON_GetObjectItem(event, "created_at");
cJSON* kind = cJSON_GetObjectItem(event, "kind");
cJSON* content = cJSON_GetObjectItem(event, "content");
cJSON* sig = cJSON_GetObjectItem(event, "sig");
cJSON* tags = cJSON_GetObjectItem(event, "tags");
if (!id || !pubkey || !created_at || !kind || !content || !sig) {
log_error("Invalid event - missing required fields");
return -1;
}
// Classify event type
event_type_t type = classify_event_kind((int)cJSON_GetNumberValue(kind));
// Serialize tags to JSON (use empty array if no tags)
char* tags_json = NULL;
if (tags && cJSON_IsArray(tags)) {
tags_json = cJSON_Print(tags);
} else {
tags_json = strdup("[]");
}
if (!tags_json) {
log_error("Failed to serialize tags to JSON");
return -1;
}
// Single INSERT statement
const char* sql =
"INSERT INTO events (id, pubkey, created_at, kind, event_type, content, sig, tags) "
"VALUES (?, ?, ?, ?, ?, ?, ?, ?)";
sqlite3_stmt* stmt;
int rc = sqlite3_prepare_v2(g_db, sql, -1, &stmt, NULL);
if (rc != SQLITE_OK) {
log_error("Failed to prepare event insert statement");
free(tags_json);
return -1;
}
// Bind parameters
sqlite3_bind_text(stmt, 1, cJSON_GetStringValue(id), -1, SQLITE_STATIC);
sqlite3_bind_text(stmt, 2, cJSON_GetStringValue(pubkey), -1, SQLITE_STATIC);
sqlite3_bind_int64(stmt, 3, (sqlite3_int64)cJSON_GetNumberValue(created_at));
sqlite3_bind_int(stmt, 4, (int)cJSON_GetNumberValue(kind));
sqlite3_bind_text(stmt, 5, event_type_to_string(type), -1, SQLITE_STATIC);
sqlite3_bind_text(stmt, 6, cJSON_GetStringValue(content), -1, SQLITE_STATIC);
sqlite3_bind_text(stmt, 7, cJSON_GetStringValue(sig), -1, SQLITE_STATIC);
sqlite3_bind_text(stmt, 8, tags_json, -1, SQLITE_TRANSIENT);
// Execute statement
rc = sqlite3_step(stmt);
sqlite3_finalize(stmt);
if (rc != SQLITE_DONE) {
if (rc == SQLITE_CONSTRAINT) {
log_warning("Event already exists in database");
free(tags_json);
return 0; // Not an error, just duplicate
}
char error_msg[256];
snprintf(error_msg, sizeof(error_msg), "Failed to insert event: %s", sqlite3_errmsg(g_db));
log_error(error_msg);
free(tags_json);
return -1;
}
free(tags_json);
log_success("Event stored in database");
return 0;
}
3. Updated retrieve_event Function
// Replace existing retrieve_event function
cJSON* retrieve_event(const char* event_id) {
if (!g_db || !event_id) {
return NULL;
}
const char* sql =
"SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE id = ?";
sqlite3_stmt* stmt;
int rc = sqlite3_prepare_v2(g_db, sql, -1, &stmt, NULL);
if (rc != SQLITE_OK) {
return NULL;
}
sqlite3_bind_text(stmt, 1, event_id, -1, SQLITE_STATIC);
cJSON* event = NULL;
if (sqlite3_step(stmt) == SQLITE_ROW) {
event = cJSON_CreateObject();
cJSON_AddStringToObject(event, "id", (char*)sqlite3_column_text(stmt, 0));
cJSON_AddStringToObject(event, "pubkey", (char*)sqlite3_column_text(stmt, 1));
cJSON_AddNumberToObject(event, "created_at", sqlite3_column_int64(stmt, 2));
cJSON_AddNumberToObject(event, "kind", sqlite3_column_int(stmt, 3));
cJSON_AddStringToObject(event, "content", (char*)sqlite3_column_text(stmt, 4));
cJSON_AddStringToObject(event, "sig", (char*)sqlite3_column_text(stmt, 5));
// Parse tags JSON
const char* tags_json = (char*)sqlite3_column_text(stmt, 6);
if (tags_json) {
cJSON* tags = cJSON_Parse(tags_json);
if (tags) {
cJSON_AddItemToObject(event, "tags", tags);
} else {
cJSON_AddItemToObject(event, "tags", cJSON_CreateArray());
}
} else {
cJSON_AddItemToObject(event, "tags", cJSON_CreateArray());
}
}
sqlite3_finalize(stmt);
return event;
}
Migration Considerations
Handling Existing Data
If there's existing data in the current schema:
- Export existing events and tags
- Transform tag data to JSON format
- Classify events by kind
- Import into new schema
Backward Compatibility
- API remains the same - events still have the same JSON structure
- Internal storage changes but external interface is unchanged
- Tests should pass with minimal modifications
Performance Optimizations
Essential Indexes
-- Core performance indexes
CREATE INDEX idx_events_pubkey ON events(pubkey);
CREATE INDEX idx_events_kind ON events(kind);
CREATE INDEX idx_events_created_at ON events(created_at DESC);
CREATE INDEX idx_events_event_type ON events(event_type);
-- Composite indexes for common query patterns
CREATE INDEX idx_events_kind_created_at ON events(kind, created_at DESC);
CREATE INDEX idx_events_pubkey_created_at ON events(pubkey, created_at DESC);
-- JSON tag indexes for common tag patterns
CREATE INDEX idx_events_e_tags ON events(
json_extract(tags, '$[*][1]')
) WHERE json_extract(tags, '$[*][0]') = 'e';
CREATE INDEX idx_events_p_tags ON events(
json_extract(tags, '$[*][1]')
) WHERE json_extract(tags, '$[*][0]') = 'p';
Next Steps
- Switch to code mode to implement the schema changes
- Update db/schema.sql with new table definition
- Modify src/main.c with new functions
- Update db/init.sh for single table validation
- Test with existing test suite
This approach will provide:
- ✅ Simplified schema management
- ✅ Protocol compliance preparation
- ✅ JSON tag query capabilities
- ✅ Performance optimization opportunities
- ✅ Easy REQ subscription handling
Ready to proceed with implementation?