Most of the way through nip01
This commit is contained in:
24
README.md
24
README.md
@@ -2,3 +2,27 @@ A nostr relay in C with sqlite on the back end.
|
||||
|
||||
|
||||
|
||||
|
||||
### [NIPs](https://github.com/nostr-protocol/nips)
|
||||
|
||||
- [x] NIP-01: Basic protocol flow description
|
||||
- [ ] NIP-02: Contact list and petnames
|
||||
- [ ] NIP-04: Encrypted Direct Message
|
||||
- [ ] NIP-09: Event deletion
|
||||
- [ ] NIP-11: Relay information document
|
||||
- [ ] NIP-12: Generic tag queries
|
||||
- [ ] NIP-13: Proof of Work
|
||||
- [x] NIP-15: End of Stored Events Notice
|
||||
- [ ] NIP-16: Event Treatment
|
||||
- [x] NIP-20: Command Results
|
||||
- [ ] NIP-22: Event `created_at` Limits
|
||||
- [ ] NIP-25: Reactions
|
||||
- [ ] NIP-26: Delegated Event Signing
|
||||
- [ ] NIP-28: Public Chat
|
||||
- [ ] NIP-33: Parameterized Replaceable Events
|
||||
- [ ] NIP-40: Expiration Timestamp
|
||||
- [ ] NIP-42: Authentication of clients to relays
|
||||
- [ ] NIP-45: Counting results. [experimental](#count)
|
||||
- [ ] NIP-50: Keywords filter. [experimental](#search)
|
||||
- [ ] NIP-70: Protected Events
|
||||
|
||||
|
||||
Binary file not shown.
Binary file not shown.
Binary file not shown.
@@ -88,3 +88,94 @@ BEGIN
|
||||
AND event_type = 'replaceable'
|
||||
AND id != NEW.id;
|
||||
END;
|
||||
|
||||
-- Persistent Subscriptions Logging Tables (Phase 2)
|
||||
-- Optional database logging for subscription analytics and debugging
|
||||
|
||||
-- Subscription events log
|
||||
CREATE TABLE subscription_events (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
subscription_id TEXT NOT NULL, -- Subscription ID from client
|
||||
client_ip TEXT NOT NULL, -- Client IP address
|
||||
event_type TEXT NOT NULL CHECK (event_type IN ('created', 'closed', 'expired', 'disconnected')),
|
||||
filter_json TEXT, -- JSON representation of filters (for created events)
|
||||
events_sent INTEGER DEFAULT 0, -- Number of events sent to this subscription
|
||||
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
|
||||
ended_at INTEGER, -- When subscription ended (for closed/expired/disconnected)
|
||||
duration INTEGER -- Computed: ended_at - created_at
|
||||
);
|
||||
|
||||
-- Subscription metrics summary
|
||||
CREATE TABLE subscription_metrics (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
date TEXT NOT NULL, -- Date (YYYY-MM-DD)
|
||||
total_created INTEGER DEFAULT 0, -- Total subscriptions created
|
||||
total_closed INTEGER DEFAULT 0, -- Total subscriptions closed
|
||||
total_events_broadcast INTEGER DEFAULT 0, -- Total events broadcast
|
||||
avg_duration REAL DEFAULT 0, -- Average subscription duration
|
||||
peak_concurrent INTEGER DEFAULT 0, -- Peak concurrent subscriptions
|
||||
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
|
||||
UNIQUE(date)
|
||||
);
|
||||
|
||||
-- Event broadcasting log (optional, for detailed analytics)
|
||||
CREATE TABLE event_broadcasts (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
event_id TEXT NOT NULL, -- Event ID that was broadcast
|
||||
subscription_id TEXT NOT NULL, -- Subscription that received it
|
||||
client_ip TEXT NOT NULL, -- Client IP
|
||||
broadcast_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
|
||||
FOREIGN KEY (event_id) REFERENCES events(id)
|
||||
);
|
||||
|
||||
-- Indexes for subscription logging performance
|
||||
CREATE INDEX idx_subscription_events_id ON subscription_events(subscription_id);
|
||||
CREATE INDEX idx_subscription_events_type ON subscription_events(event_type);
|
||||
CREATE INDEX idx_subscription_events_created ON subscription_events(created_at DESC);
|
||||
CREATE INDEX idx_subscription_events_client ON subscription_events(client_ip);
|
||||
|
||||
CREATE INDEX idx_subscription_metrics_date ON subscription_metrics(date DESC);
|
||||
|
||||
CREATE INDEX idx_event_broadcasts_event ON event_broadcasts(event_id);
|
||||
CREATE INDEX idx_event_broadcasts_sub ON event_broadcasts(subscription_id);
|
||||
CREATE INDEX idx_event_broadcasts_time ON event_broadcasts(broadcast_at DESC);
|
||||
|
||||
-- Trigger to update subscription duration when ended
|
||||
CREATE TRIGGER update_subscription_duration
|
||||
AFTER UPDATE OF ended_at ON subscription_events
|
||||
WHEN NEW.ended_at IS NOT NULL AND OLD.ended_at IS NULL
|
||||
BEGIN
|
||||
UPDATE subscription_events
|
||||
SET duration = NEW.ended_at - NEW.created_at
|
||||
WHERE id = NEW.id;
|
||||
END;
|
||||
|
||||
-- View for subscription analytics
|
||||
CREATE VIEW subscription_analytics AS
|
||||
SELECT
|
||||
date(created_at, 'unixepoch') as date,
|
||||
COUNT(*) as subscriptions_created,
|
||||
COUNT(CASE WHEN ended_at IS NOT NULL THEN 1 END) as subscriptions_ended,
|
||||
AVG(CASE WHEN duration IS NOT NULL THEN duration END) as avg_duration_seconds,
|
||||
MAX(events_sent) as max_events_sent,
|
||||
AVG(events_sent) as avg_events_sent,
|
||||
COUNT(DISTINCT client_ip) as unique_clients
|
||||
FROM subscription_events
|
||||
GROUP BY date(created_at, 'unixepoch')
|
||||
ORDER BY date DESC;
|
||||
|
||||
-- View for current active subscriptions (from log perspective)
|
||||
CREATE VIEW active_subscriptions_log AS
|
||||
SELECT
|
||||
subscription_id,
|
||||
client_ip,
|
||||
filter_json,
|
||||
events_sent,
|
||||
created_at,
|
||||
(strftime('%s', 'now') - created_at) as duration_seconds
|
||||
FROM subscription_events
|
||||
WHERE event_type = 'created'
|
||||
AND subscription_id NOT IN (
|
||||
SELECT subscription_id FROM subscription_events
|
||||
WHERE event_type IN ('closed', 'expired', 'disconnected')
|
||||
);
|
||||
@@ -1,337 +0,0 @@
|
||||
# Advanced Nostr Relay Schema Design
|
||||
|
||||
## Overview
|
||||
|
||||
This document outlines the design for an advanced multi-table schema that enforces Nostr protocol compliance at the database level, with separate tables for different event types based on their storage and replacement characteristics.
|
||||
|
||||
## Event Type Classification
|
||||
|
||||
Based on the Nostr specification, events are classified into four categories:
|
||||
|
||||
### 1. Regular Events
|
||||
- **Kinds**: `1000 <= n < 10000` || `4 <= n < 45` || `n == 1` || `n == 2`
|
||||
- **Storage Policy**: All events stored permanently
|
||||
- **Examples**: Text notes (1), Reposts (6), Reactions (7), Direct Messages (4)
|
||||
|
||||
### 2. Replaceable Events
|
||||
- **Kinds**: `10000 <= n < 20000` || `n == 0` || `n == 3`
|
||||
- **Storage Policy**: Only latest per `(pubkey, kind)` combination
|
||||
- **Replacement Logic**: Latest `created_at`, then lowest `id` lexically
|
||||
- **Examples**: Metadata (0), Contacts (3), Mute List (10000)
|
||||
|
||||
### 3. Ephemeral Events
|
||||
- **Kinds**: `20000 <= n < 30000`
|
||||
- **Storage Policy**: Not expected to be stored (optional temporary storage)
|
||||
- **Examples**: Typing indicators, presence updates, ephemeral messages
|
||||
|
||||
### 4. Addressable Events
|
||||
- **Kinds**: `30000 <= n < 40000`
|
||||
- **Storage Policy**: Only latest per `(pubkey, kind, d_tag)` combination
|
||||
- **Replacement Logic**: Same as replaceable events
|
||||
- **Examples**: Long-form content (30023), Application-specific data
|
||||
|
||||
## SQLite JSON Capabilities Research
|
||||
|
||||
SQLite provides powerful JSON functions that could be leveraged for tag storage:
|
||||
|
||||
### Core JSON Functions
|
||||
```sql
|
||||
-- Extract specific values
|
||||
json_extract(column, '$.path')
|
||||
|
||||
-- Iterate through arrays
|
||||
json_each(json_array_column)
|
||||
|
||||
-- Flatten nested structures
|
||||
json_tree(json_column)
|
||||
|
||||
-- Validate JSON structure
|
||||
json_valid(column)
|
||||
|
||||
-- Array operations
|
||||
json_array_length(column)
|
||||
json_extract(column, '$[0]') -- First element
|
||||
```
|
||||
|
||||
### Tag Query Examples
|
||||
|
||||
#### Find all 'e' tag references:
|
||||
```sql
|
||||
SELECT
|
||||
id,
|
||||
json_extract(value, '$[1]') as referenced_event_id,
|
||||
json_extract(value, '$[2]') as relay_hint,
|
||||
json_extract(value, '$[3]') as marker
|
||||
FROM events, json_each(tags)
|
||||
WHERE json_extract(value, '$[0]') = 'e';
|
||||
```
|
||||
|
||||
#### Find events with specific hashtags:
|
||||
```sql
|
||||
SELECT id, content
|
||||
FROM events, json_each(tags)
|
||||
WHERE json_extract(value, '$[0]') = 't'
|
||||
AND json_extract(value, '$[1]') = 'bitcoin';
|
||||
```
|
||||
|
||||
#### Extract 'd' tag for addressable events:
|
||||
```sql
|
||||
SELECT
|
||||
id,
|
||||
json_extract(value, '$[1]') as d_tag_value
|
||||
FROM events, json_each(tags)
|
||||
WHERE json_extract(value, '$[0]') = 'd'
|
||||
LIMIT 1;
|
||||
```
|
||||
|
||||
### JSON Functional Indexes
|
||||
```sql
|
||||
-- Index on hashtags
|
||||
CREATE INDEX idx_hashtags ON events(
|
||||
json_extract(tags, '$[*][1]')
|
||||
) WHERE json_extract(tags, '$[*][0]') = 't';
|
||||
|
||||
-- Index on 'd' tags for addressable events
|
||||
CREATE INDEX idx_d_tags ON events_addressable(
|
||||
json_extract(tags, '$[*][1]')
|
||||
) WHERE json_extract(tags, '$[*][0]') = 'd';
|
||||
```
|
||||
|
||||
## Proposed Schema Design
|
||||
|
||||
### Option 1: Separate Tables with JSON Tags
|
||||
|
||||
```sql
|
||||
-- Regular Events (permanent storage)
|
||||
CREATE TABLE events_regular (
|
||||
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,
|
||||
tags JSON,
|
||||
first_seen INTEGER DEFAULT (strftime('%s', 'now')),
|
||||
CONSTRAINT kind_regular CHECK (
|
||||
(kind >= 1000 AND kind < 10000) OR
|
||||
(kind >= 4 AND kind < 45) OR
|
||||
kind = 1 OR kind = 2
|
||||
)
|
||||
);
|
||||
|
||||
-- Replaceable Events (latest per pubkey+kind)
|
||||
CREATE TABLE events_replaceable (
|
||||
pubkey TEXT NOT NULL,
|
||||
kind INTEGER NOT NULL,
|
||||
id TEXT NOT NULL,
|
||||
created_at INTEGER NOT NULL,
|
||||
content TEXT NOT NULL,
|
||||
sig TEXT NOT NULL,
|
||||
tags JSON,
|
||||
replaced_at INTEGER DEFAULT (strftime('%s', 'now')),
|
||||
PRIMARY KEY (pubkey, kind),
|
||||
CONSTRAINT kind_replaceable CHECK (
|
||||
(kind >= 10000 AND kind < 20000) OR
|
||||
kind = 0 OR kind = 3
|
||||
)
|
||||
);
|
||||
|
||||
-- Ephemeral Events (temporary/optional storage)
|
||||
CREATE TABLE events_ephemeral (
|
||||
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,
|
||||
tags JSON,
|
||||
expires_at INTEGER DEFAULT (strftime('%s', 'now', '+1 hour')),
|
||||
CONSTRAINT kind_ephemeral CHECK (
|
||||
kind >= 20000 AND kind < 30000
|
||||
)
|
||||
);
|
||||
|
||||
-- Addressable Events (latest per pubkey+kind+d_tag)
|
||||
CREATE TABLE events_addressable (
|
||||
pubkey TEXT NOT NULL,
|
||||
kind INTEGER NOT NULL,
|
||||
d_tag TEXT NOT NULL,
|
||||
id TEXT NOT NULL,
|
||||
created_at INTEGER NOT NULL,
|
||||
content TEXT NOT NULL,
|
||||
sig TEXT NOT NULL,
|
||||
tags JSON,
|
||||
replaced_at INTEGER DEFAULT (strftime('%s', 'now')),
|
||||
PRIMARY KEY (pubkey, kind, d_tag),
|
||||
CONSTRAINT kind_addressable CHECK (
|
||||
kind >= 30000 AND kind < 40000
|
||||
)
|
||||
);
|
||||
```
|
||||
|
||||
### Indexes for Performance
|
||||
|
||||
```sql
|
||||
-- Regular events indexes
|
||||
CREATE INDEX idx_regular_pubkey ON events_regular(pubkey);
|
||||
CREATE INDEX idx_regular_kind ON events_regular(kind);
|
||||
CREATE INDEX idx_regular_created_at ON events_regular(created_at);
|
||||
CREATE INDEX idx_regular_kind_created_at ON events_regular(kind, created_at);
|
||||
|
||||
-- Replaceable events indexes
|
||||
CREATE INDEX idx_replaceable_created_at ON events_replaceable(created_at);
|
||||
CREATE INDEX idx_replaceable_id ON events_replaceable(id);
|
||||
|
||||
-- Ephemeral events indexes
|
||||
CREATE INDEX idx_ephemeral_expires_at ON events_ephemeral(expires_at);
|
||||
CREATE INDEX idx_ephemeral_pubkey ON events_ephemeral(pubkey);
|
||||
|
||||
-- Addressable events indexes
|
||||
CREATE INDEX idx_addressable_created_at ON events_addressable(created_at);
|
||||
CREATE INDEX idx_addressable_id ON events_addressable(id);
|
||||
|
||||
-- JSON tag indexes (examples)
|
||||
CREATE INDEX idx_regular_e_tags ON events_regular(
|
||||
json_extract(tags, '$[*][1]')
|
||||
) WHERE json_extract(tags, '$[*][0]') = 'e';
|
||||
|
||||
CREATE INDEX idx_regular_p_tags ON events_regular(
|
||||
json_extract(tags, '$[*][1]')
|
||||
) WHERE json_extract(tags, '$[*][0]') = 'p';
|
||||
```
|
||||
|
||||
### Option 2: Unified Tag Table Approach
|
||||
|
||||
```sql
|
||||
-- Unified tag storage (alternative to JSON)
|
||||
CREATE TABLE tags_unified (
|
||||
event_id TEXT NOT NULL,
|
||||
event_type TEXT NOT NULL, -- 'regular', 'replaceable', 'ephemeral', 'addressable'
|
||||
tag_index INTEGER NOT NULL, -- Position in tag array
|
||||
name TEXT NOT NULL,
|
||||
value TEXT NOT NULL,
|
||||
param_2 TEXT, -- Third element if present
|
||||
param_3 TEXT, -- Fourth element if present
|
||||
param_json TEXT, -- JSON for additional parameters
|
||||
PRIMARY KEY (event_id, tag_index)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_tags_name_value ON tags_unified(name, value);
|
||||
CREATE INDEX idx_tags_event_type ON tags_unified(event_type);
|
||||
```
|
||||
|
||||
## Implementation Strategy
|
||||
|
||||
### 1. Kind Classification Function (C Code)
|
||||
```c
|
||||
typedef enum {
|
||||
EVENT_TYPE_REGULAR,
|
||||
EVENT_TYPE_REPLACEABLE,
|
||||
EVENT_TYPE_EPHEMERAL,
|
||||
EVENT_TYPE_ADDRESSABLE,
|
||||
EVENT_TYPE_INVALID
|
||||
} 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_INVALID;
|
||||
}
|
||||
```
|
||||
|
||||
### 2. Replacement Logic for Replaceable Events
|
||||
```sql
|
||||
-- Trigger for replaceable events
|
||||
CREATE TRIGGER replace_event_on_insert
|
||||
BEFORE INSERT ON events_replaceable
|
||||
FOR EACH ROW
|
||||
WHEN EXISTS (
|
||||
SELECT 1 FROM events_replaceable
|
||||
WHERE pubkey = NEW.pubkey AND kind = NEW.kind
|
||||
)
|
||||
BEGIN
|
||||
DELETE FROM events_replaceable
|
||||
WHERE pubkey = NEW.pubkey
|
||||
AND kind = NEW.kind
|
||||
AND (
|
||||
created_at < NEW.created_at OR
|
||||
(created_at = NEW.created_at AND id > NEW.id)
|
||||
);
|
||||
END;
|
||||
```
|
||||
|
||||
### 3. D-Tag Extraction for Addressable Events
|
||||
```c
|
||||
char* extract_d_tag(cJSON* tags) {
|
||||
if (!tags || !cJSON_IsArray(tags)) {
|
||||
return NULL;
|
||||
}
|
||||
|
||||
cJSON* tag;
|
||||
cJSON_ArrayForEach(tag, tags) {
|
||||
if (cJSON_IsArray(tag) && cJSON_GetArraySize(tag) >= 2) {
|
||||
cJSON* tag_name = cJSON_GetArrayItem(tag, 0);
|
||||
cJSON* tag_value = cJSON_GetArrayItem(tag, 1);
|
||||
|
||||
if (cJSON_IsString(tag_name) && cJSON_IsString(tag_value)) {
|
||||
if (strcmp(cJSON_GetStringValue(tag_name), "d") == 0) {
|
||||
return strdup(cJSON_GetStringValue(tag_value));
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
return strdup(""); // Default empty d-tag
|
||||
}
|
||||
```
|
||||
|
||||
## Advantages of This Design
|
||||
|
||||
### 1. Protocol Compliance
|
||||
- **Enforced at DB level**: Schema constraints prevent invalid event storage
|
||||
- **Automatic replacement**: Triggers handle replaceable/addressable event logic
|
||||
- **Type safety**: Separate tables ensure correct handling per event type
|
||||
|
||||
### 2. Performance Benefits
|
||||
- **Targeted indexes**: Each table optimized for its access patterns
|
||||
- **Reduced storage**: Ephemeral events can be auto-expired
|
||||
- **Query optimization**: SQLite can optimize queries per table structure
|
||||
|
||||
### 3. JSON Tag Benefits
|
||||
- **Atomic storage**: Tags stored with their event
|
||||
- **Rich querying**: SQLite JSON functions enable complex tag queries
|
||||
- **Schema flexibility**: Can handle arbitrary tag structures
|
||||
- **Functional indexes**: Index specific tag patterns efficiently
|
||||
|
||||
## Migration Strategy
|
||||
|
||||
1. **Phase 1**: Create new schema alongside existing
|
||||
2. **Phase 2**: Implement kind classification and routing logic
|
||||
3. **Phase 3**: Migrate existing data to appropriate tables
|
||||
4. **Phase 4**: Update application logic to use new tables
|
||||
5. **Phase 5**: Drop old schema after verification
|
||||
|
||||
## Next Steps for Implementation
|
||||
|
||||
1. **Prototype JSON performance**: Create test database with sample data
|
||||
2. **Benchmark query patterns**: Compare JSON vs normalized approaches
|
||||
3. **Implement kind classification**: Add routing logic to C code
|
||||
4. **Create migration scripts**: Handle existing data transformation
|
||||
5. **Update test suite**: Verify compliance with new schema
|
||||
@@ -1,416 +0,0 @@
|
||||
# Final Schema Recommendation: Hybrid Single Table Approach
|
||||
|
||||
## Executive Summary
|
||||
|
||||
After analyzing the subscription query complexity, **the multi-table approach creates more problems than it solves**. REQ filters don't align with storage semantics - clients filter by kind, author, and tags regardless of event type classification.
|
||||
|
||||
**Recommendation: Modified Single Table with Event Type Classification**
|
||||
|
||||
## The Multi-Table Problem
|
||||
|
||||
### REQ Filter Reality Check
|
||||
- Clients send: `{"kinds": [1, 0, 30023], "authors": ["pubkey"], "#p": ["target"]}`
|
||||
- Multi-table requires: 3 separate queries + UNION + complex ordering
|
||||
- Single table requires: 1 query with simple WHERE conditions
|
||||
|
||||
### Query Complexity Explosion
|
||||
```sql
|
||||
-- Multi-table nightmare for simple filter
|
||||
WITH results AS (
|
||||
SELECT * FROM events_regular WHERE kind = 1 AND pubkey = ?
|
||||
UNION ALL
|
||||
SELECT * FROM events_replaceable WHERE kind = 0 AND pubkey = ?
|
||||
UNION ALL
|
||||
SELECT * FROM events_addressable WHERE kind = 30023 AND pubkey = ?
|
||||
)
|
||||
SELECT r.* FROM results r
|
||||
JOIN multiple_tag_tables t ON complex_conditions
|
||||
ORDER BY created_at DESC, id ASC LIMIT ?;
|
||||
|
||||
-- vs Single table simplicity
|
||||
SELECT e.* FROM events e, json_each(e.tags) t
|
||||
WHERE e.kind IN (1, 0, 30023)
|
||||
AND e.pubkey = ?
|
||||
AND json_extract(t.value, '$[0]') = 'p'
|
||||
AND json_extract(t.value, '$[1]') = ?
|
||||
ORDER BY e.created_at DESC, e.id ASC LIMIT ?;
|
||||
```
|
||||
|
||||
## Recommended Schema: Hybrid Approach
|
||||
|
||||
### Core Design Philosophy
|
||||
- **Single table for REQ query simplicity**
|
||||
- **Event type classification for protocol compliance**
|
||||
- **JSON tags for atomic storage and rich querying**
|
||||
- **Partial unique constraints for replacement logic**
|
||||
|
||||
### Schema Definition
|
||||
|
||||
```sql
|
||||
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')),
|
||||
|
||||
-- Additional fields for addressable events
|
||||
d_tag TEXT GENERATED ALWAYS AS (
|
||||
CASE
|
||||
WHEN event_type = 'addressable' THEN
|
||||
json_extract(tags, '$[*][1]')
|
||||
FROM json_each(tags)
|
||||
WHERE json_extract(value, '$[0]') = 'd'
|
||||
LIMIT 1
|
||||
ELSE NULL
|
||||
END
|
||||
) STORED,
|
||||
|
||||
-- Replacement tracking
|
||||
replaced_at INTEGER,
|
||||
|
||||
-- Protocol compliance constraints
|
||||
CONSTRAINT unique_replaceable
|
||||
UNIQUE (pubkey, kind)
|
||||
WHERE event_type = 'replaceable',
|
||||
|
||||
CONSTRAINT unique_addressable
|
||||
UNIQUE (pubkey, kind, d_tag)
|
||||
WHERE event_type = 'addressable' AND d_tag IS NOT NULL
|
||||
);
|
||||
```
|
||||
|
||||
### Event Type Classification Function
|
||||
|
||||
```sql
|
||||
-- Function to determine event type from kind
|
||||
CREATE VIEW event_type_lookup AS
|
||||
SELECT
|
||||
CASE
|
||||
WHEN (kind >= 1000 AND kind < 10000) OR
|
||||
(kind >= 4 AND kind < 45) OR
|
||||
kind = 1 OR kind = 2 THEN 'regular'
|
||||
WHEN (kind >= 10000 AND kind < 20000) OR
|
||||
kind = 0 OR kind = 3 THEN 'replaceable'
|
||||
WHEN kind >= 20000 AND kind < 30000 THEN 'ephemeral'
|
||||
WHEN kind >= 30000 AND kind < 40000 THEN 'addressable'
|
||||
ELSE 'unknown'
|
||||
END as event_type,
|
||||
kind
|
||||
FROM (
|
||||
-- Generate all possible kind values for lookup
|
||||
WITH RECURSIVE kinds(kind) AS (
|
||||
SELECT 0
|
||||
UNION ALL
|
||||
SELECT kind + 1 FROM kinds WHERE kind < 65535
|
||||
)
|
||||
SELECT kind FROM kinds
|
||||
);
|
||||
```
|
||||
|
||||
### Performance Indexes
|
||||
|
||||
```sql
|
||||
-- Core query patterns
|
||||
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 filters
|
||||
CREATE INDEX idx_events_pubkey_created_at ON events(pubkey, created_at DESC);
|
||||
CREATE INDEX idx_events_kind_created_at ON events(kind, created_at DESC);
|
||||
CREATE INDEX idx_events_type_created_at ON events(event_type, created_at DESC);
|
||||
|
||||
-- JSON tag indexes for common 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';
|
||||
|
||||
CREATE INDEX idx_events_hashtags ON events(
|
||||
json_extract(tags, '$[*][1]')
|
||||
) WHERE json_extract(tags, '$[*][0]') = 't';
|
||||
|
||||
-- Addressable events d_tag index
|
||||
CREATE INDEX idx_events_d_tag ON events(d_tag)
|
||||
WHERE event_type = 'addressable' AND d_tag IS NOT NULL;
|
||||
```
|
||||
|
||||
### Replacement Logic Implementation
|
||||
|
||||
#### Replaceable Events Trigger
|
||||
```sql
|
||||
CREATE TRIGGER handle_replaceable_events
|
||||
BEFORE INSERT ON events
|
||||
FOR EACH ROW
|
||||
WHEN NEW.event_type = 'replaceable'
|
||||
BEGIN
|
||||
-- Delete older replaceable events with same pubkey+kind
|
||||
DELETE FROM events
|
||||
WHERE event_type = 'replaceable'
|
||||
AND pubkey = NEW.pubkey
|
||||
AND kind = NEW.kind
|
||||
AND (
|
||||
created_at < NEW.created_at OR
|
||||
(created_at = NEW.created_at AND id > NEW.id)
|
||||
);
|
||||
END;
|
||||
```
|
||||
|
||||
#### Addressable Events Trigger
|
||||
```sql
|
||||
CREATE TRIGGER handle_addressable_events
|
||||
BEFORE INSERT ON events
|
||||
FOR EACH ROW
|
||||
WHEN NEW.event_type = 'addressable'
|
||||
BEGIN
|
||||
-- Delete older addressable events with same pubkey+kind+d_tag
|
||||
DELETE FROM events
|
||||
WHERE event_type = 'addressable'
|
||||
AND pubkey = NEW.pubkey
|
||||
AND kind = NEW.kind
|
||||
AND d_tag = NEW.d_tag
|
||||
AND (
|
||||
created_at < NEW.created_at OR
|
||||
(created_at = NEW.created_at AND id > NEW.id)
|
||||
);
|
||||
END;
|
||||
```
|
||||
|
||||
## Implementation Strategy
|
||||
|
||||
### C Code Integration
|
||||
|
||||
#### Event Type Classification
|
||||
```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";
|
||||
}
|
||||
}
|
||||
```
|
||||
|
||||
#### Simplified Event Storage
|
||||
```c
|
||||
int store_event(cJSON* event) {
|
||||
// Extract 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");
|
||||
|
||||
// Classify event type
|
||||
event_type_t type = classify_event_kind(cJSON_GetNumberValue(kind));
|
||||
|
||||
// Serialize tags to JSON
|
||||
cJSON* tags = cJSON_GetObjectItem(event, "tags");
|
||||
char* tags_json = cJSON_Print(tags ? tags : cJSON_CreateArray());
|
||||
|
||||
// Single INSERT statement - database handles replacement via triggers
|
||||
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) {
|
||||
free(tags_json);
|
||||
return -1;
|
||||
}
|
||||
|
||||
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);
|
||||
|
||||
rc = sqlite3_step(stmt);
|
||||
sqlite3_finalize(stmt);
|
||||
free(tags_json);
|
||||
|
||||
return (rc == SQLITE_DONE) ? 0 : -1;
|
||||
}
|
||||
```
|
||||
|
||||
#### Simple REQ Query Building
|
||||
```c
|
||||
char* build_filter_query(cJSON* filter) {
|
||||
// Build single query against events table
|
||||
// Much simpler than multi-table approach
|
||||
|
||||
GString* query = g_string_new("SELECT * FROM events WHERE 1=1");
|
||||
|
||||
// Handle ids filter
|
||||
cJSON* ids = cJSON_GetObjectItem(filter, "ids");
|
||||
if (ids && cJSON_IsArray(ids)) {
|
||||
g_string_append(query, " AND id IN (");
|
||||
// Add parameter placeholders
|
||||
g_string_append(query, ")");
|
||||
}
|
||||
|
||||
// Handle authors filter
|
||||
cJSON* authors = cJSON_GetObjectItem(filter, "authors");
|
||||
if (authors && cJSON_IsArray(authors)) {
|
||||
g_string_append(query, " AND pubkey IN (");
|
||||
// Add parameter placeholders
|
||||
g_string_append(query, ")");
|
||||
}
|
||||
|
||||
// Handle kinds filter
|
||||
cJSON* kinds = cJSON_GetObjectItem(filter, "kinds");
|
||||
if (kinds && cJSON_IsArray(kinds)) {
|
||||
g_string_append(query, " AND kind IN (");
|
||||
// Add parameter placeholders
|
||||
g_string_append(query, ")");
|
||||
}
|
||||
|
||||
// Handle tag filters (#e, #p, etc.)
|
||||
cJSON* item;
|
||||
cJSON_ArrayForEach(item, filter) {
|
||||
char* key = item->string;
|
||||
if (key && key[0] == '#' && strlen(key) == 2) {
|
||||
char tag_name = key[1];
|
||||
g_string_append_printf(query,
|
||||
" AND EXISTS (SELECT 1 FROM json_each(tags) "
|
||||
"WHERE json_extract(value, '$[0]') = '%c' "
|
||||
"AND json_extract(value, '$[1]') IN (", tag_name);
|
||||
// Add parameter placeholders
|
||||
g_string_append(query, "))");
|
||||
}
|
||||
}
|
||||
|
||||
// Handle time range
|
||||
cJSON* since = cJSON_GetObjectItem(filter, "since");
|
||||
if (since) {
|
||||
g_string_append(query, " AND created_at >= ?");
|
||||
}
|
||||
|
||||
cJSON* until = cJSON_GetObjectItem(filter, "until");
|
||||
if (until) {
|
||||
g_string_append(query, " AND created_at <= ?");
|
||||
}
|
||||
|
||||
// Standard ordering and limit
|
||||
g_string_append(query, " ORDER BY created_at DESC, id ASC");
|
||||
|
||||
cJSON* limit = cJSON_GetObjectItem(filter, "limit");
|
||||
if (limit) {
|
||||
g_string_append(query, " LIMIT ?");
|
||||
}
|
||||
|
||||
return g_string_free(query, FALSE);
|
||||
}
|
||||
```
|
||||
|
||||
## Benefits of This Approach
|
||||
|
||||
### 1. Query Simplicity
|
||||
- ✅ Single table = simple REQ queries
|
||||
- ✅ No UNION complexity
|
||||
- ✅ Familiar SQL patterns
|
||||
- ✅ Easy LIMIT and ORDER BY handling
|
||||
|
||||
### 2. Protocol Compliance
|
||||
- ✅ Event type classification enforced
|
||||
- ✅ Replacement logic via triggers
|
||||
- ✅ Unique constraints prevent duplicates
|
||||
- ✅ Proper handling of all event types
|
||||
|
||||
### 3. Performance
|
||||
- ✅ Unified indexes across all events
|
||||
- ✅ No join overhead for basic queries
|
||||
- ✅ JSON tag indexes for complex filters
|
||||
- ✅ Single table scan for cross-kind queries
|
||||
|
||||
### 4. Implementation Simplicity
|
||||
- ✅ Minimal changes from current code
|
||||
- ✅ Database handles replacement logic
|
||||
- ✅ Simple event storage function
|
||||
- ✅ No complex routing logic needed
|
||||
|
||||
### 5. Future Flexibility
|
||||
- ✅ Can add columns for new event types
|
||||
- ✅ Can split tables later if needed
|
||||
- ✅ Easy to add new indexes
|
||||
- ✅ Extensible constraint system
|
||||
|
||||
## Migration Path
|
||||
|
||||
### Phase 1: Schema Update
|
||||
1. Add `event_type` column to existing events table
|
||||
2. Add JSON `tags` column
|
||||
3. Create classification triggers
|
||||
4. Add partial unique constraints
|
||||
|
||||
### Phase 2: Data Migration
|
||||
1. Classify existing events by kind
|
||||
2. Convert existing tag table data to JSON
|
||||
3. Verify constraint compliance
|
||||
4. Update indexes
|
||||
|
||||
### Phase 3: Code Updates
|
||||
1. Update event storage to use new schema
|
||||
2. Simplify REQ query building
|
||||
3. Remove tag table JOIN logic
|
||||
4. Test subscription filtering
|
||||
|
||||
### Phase 4: Optimization
|
||||
1. Monitor query performance
|
||||
2. Add specialized indexes as needed
|
||||
3. Tune replacement triggers
|
||||
4. Consider ephemeral event cleanup
|
||||
|
||||
## Conclusion
|
||||
|
||||
This hybrid approach achieves the best of both worlds:
|
||||
|
||||
- **Protocol compliance** through event type classification and constraints
|
||||
- **Query simplicity** through unified storage
|
||||
- **Performance** through targeted indexes
|
||||
- **Implementation ease** through minimal complexity
|
||||
|
||||
The multi-table approach, while theoretically cleaner, creates a subscription query nightmare that would significantly burden the implementation. The hybrid single-table approach provides all the benefits with manageable complexity.
|
||||
@@ -1,326 +0,0 @@
|
||||
# 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)
|
||||
```sql
|
||||
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)
|
||||
```sql
|
||||
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`
|
||||
|
||||
1. Replace current event table definition
|
||||
2. Remove tag table completely
|
||||
3. Add new indexes for performance
|
||||
4. Add event type classification logic
|
||||
|
||||
### Phase 2: Update C Code
|
||||
|
||||
**File**: `src/main.c`
|
||||
|
||||
1. Add event type classification function
|
||||
2. Update `store_event()` function to use JSON tags
|
||||
3. Update `retrieve_event()` function to return JSON tags
|
||||
4. Remove all tag table related code
|
||||
5. Update REQ query handling to use JSON tag queries
|
||||
|
||||
### Phase 3: Update Database Initialization
|
||||
|
||||
**File**: `db/init.sh`
|
||||
|
||||
1. Update table count validation (expect 1 table instead of 2)
|
||||
2. Update schema verification logic
|
||||
|
||||
### Phase 4: Update Tests
|
||||
|
||||
**File**: `tests/1_nip_test.sh`
|
||||
|
||||
1. Verify events are stored with JSON tags
|
||||
2. Test query functionality with new schema
|
||||
3. Validate event type classification
|
||||
|
||||
### Phase 5: Migration Strategy
|
||||
|
||||
Create migration script to handle existing data (if any).
|
||||
|
||||
## Detailed Implementation
|
||||
|
||||
### 1. Event Type Classification
|
||||
|
||||
```c
|
||||
// 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
|
||||
|
||||
```c
|
||||
// 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
|
||||
|
||||
```c
|
||||
// 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:
|
||||
|
||||
1. **Export existing events and tags**
|
||||
2. **Transform tag data to JSON format**
|
||||
3. **Classify events by kind**
|
||||
4. **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
|
||||
|
||||
```sql
|
||||
-- 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
|
||||
|
||||
1. **Switch to code mode** to implement the schema changes
|
||||
2. **Update db/schema.sql** with new table definition
|
||||
3. **Modify src/main.c** with new functions
|
||||
4. **Update db/init.sh** for single table validation
|
||||
5. **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?
|
||||
@@ -1,331 +0,0 @@
|
||||
# Subscription Query Complexity Analysis
|
||||
|
||||
## Overview
|
||||
|
||||
This document analyzes how Nostr REQ subscription filters would be implemented across different schema designs, focusing on query complexity, performance implications, and implementation burden.
|
||||
|
||||
## Nostr REQ Filter Specification Recap
|
||||
|
||||
Clients send REQ messages with filters containing:
|
||||
- **`ids`**: List of specific event IDs
|
||||
- **`authors`**: List of pubkeys
|
||||
- **`kinds`**: List of event kinds
|
||||
- **`#<letter>`**: Tag filters (e.g., `#e` for event refs, `#p` for pubkey mentions)
|
||||
- **`since`/`until`**: Time range filters
|
||||
- **`limit`**: Maximum events to return
|
||||
|
||||
### Key Filter Behaviors:
|
||||
- **Multiple filters = OR logic**: Match any filter
|
||||
- **Within filter = AND logic**: Match all specified conditions
|
||||
- **Lists = IN logic**: Match any value in the list
|
||||
- **Tag filters**: Must have at least one matching tag
|
||||
|
||||
## Schema Comparison for REQ Handling
|
||||
|
||||
### Current Simple Schema (Single Table)
|
||||
```sql
|
||||
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, -- event ID
|
||||
name TEXT NOT NULL,
|
||||
value TEXT NOT NULL,
|
||||
parameters TEXT
|
||||
);
|
||||
```
|
||||
|
||||
#### Sample REQ Query Implementation:
|
||||
```sql
|
||||
-- Filter: {"authors": ["pubkey1", "pubkey2"], "kinds": [1, 6], "#p": ["target_pubkey"]}
|
||||
SELECT DISTINCT e.*
|
||||
FROM event e
|
||||
WHERE e.pubkey IN ('pubkey1', 'pubkey2')
|
||||
AND e.kind IN (1, 6)
|
||||
AND EXISTS (
|
||||
SELECT 1 FROM tag t
|
||||
WHERE t.id = e.id AND t.name = 'p' AND t.value = 'target_pubkey'
|
||||
)
|
||||
ORDER BY e.created_at DESC, e.id ASC
|
||||
LIMIT ?;
|
||||
```
|
||||
|
||||
### Multi-Table Schema Challenge
|
||||
|
||||
With separate tables (`events_regular`, `events_replaceable`, `events_ephemeral`, `events_addressable`), a REQ filter could potentially match events across ALL tables.
|
||||
|
||||
#### Problem Example:
|
||||
Filter: `{"kinds": [1, 0, 20001, 30023]}`
|
||||
- Kind 1 → `events_regular`
|
||||
- Kind 0 → `events_replaceable`
|
||||
- Kind 20001 → `events_ephemeral`
|
||||
- Kind 30023 → `events_addressable`
|
||||
|
||||
This requires **4 separate queries + UNION**, significantly complicating the implementation.
|
||||
|
||||
## Multi-Table Query Complexity
|
||||
|
||||
### Scenario 1: Cross-Table Kind Filter
|
||||
```sql
|
||||
-- Filter: {"kinds": [1, 0, 30023]}
|
||||
-- Requires querying 3 different tables
|
||||
|
||||
SELECT id, pubkey, created_at, kind, content, sig FROM events_regular
|
||||
WHERE kind = 1
|
||||
UNION ALL
|
||||
SELECT id, pubkey, created_at, kind, content, sig FROM events_replaceable
|
||||
WHERE kind = 0
|
||||
UNION ALL
|
||||
SELECT id, pubkey, created_at, kind, content, sig FROM events_addressable
|
||||
WHERE kind = 30023
|
||||
ORDER BY created_at DESC, id ASC
|
||||
LIMIT ?;
|
||||
```
|
||||
|
||||
### Scenario 2: Cross-Table Author Filter
|
||||
```sql
|
||||
-- Filter: {"authors": ["pubkey1"]}
|
||||
-- Must check ALL tables for this author
|
||||
|
||||
SELECT id, pubkey, created_at, kind, content, sig FROM events_regular
|
||||
WHERE pubkey = 'pubkey1'
|
||||
UNION ALL
|
||||
SELECT id, pubkey, created_at, kind, content, sig FROM events_replaceable
|
||||
WHERE pubkey = 'pubkey1'
|
||||
UNION ALL
|
||||
SELECT id, pubkey, created_at, kind, content, sig FROM events_ephemeral
|
||||
WHERE pubkey = 'pubkey1'
|
||||
UNION ALL
|
||||
SELECT id, pubkey, created_at, kind, content, sig FROM events_addressable
|
||||
WHERE pubkey = 'pubkey1'
|
||||
ORDER BY created_at DESC, id ASC
|
||||
LIMIT ?;
|
||||
```
|
||||
|
||||
### Scenario 3: Complex Multi-Condition Filter
|
||||
```sql
|
||||
-- Filter: {"authors": ["pubkey1"], "kinds": [1, 0], "#p": ["target"], "since": 1234567890}
|
||||
-- Extremely complex with multiple UNIONs and tag JOINs
|
||||
|
||||
WITH regular_results AS (
|
||||
SELECT DISTINCT r.*
|
||||
FROM events_regular r
|
||||
JOIN tags_regular tr ON r.id = tr.event_id
|
||||
WHERE r.pubkey = 'pubkey1'
|
||||
AND r.kind = 1
|
||||
AND r.created_at >= 1234567890
|
||||
AND tr.name = 'p' AND tr.value = 'target'
|
||||
),
|
||||
replaceable_results AS (
|
||||
SELECT DISTINCT rp.*
|
||||
FROM events_replaceable rp
|
||||
JOIN tags_replaceable trp ON (rp.pubkey, rp.kind) = (trp.event_pubkey, trp.event_kind)
|
||||
WHERE rp.pubkey = 'pubkey1'
|
||||
AND rp.kind = 0
|
||||
AND rp.created_at >= 1234567890
|
||||
AND trp.name = 'p' AND trp.value = 'target'
|
||||
)
|
||||
SELECT * FROM regular_results
|
||||
UNION ALL
|
||||
SELECT * FROM replaceable_results
|
||||
ORDER BY created_at DESC, id ASC
|
||||
LIMIT ?;
|
||||
```
|
||||
|
||||
## Implementation Burden Analysis
|
||||
|
||||
### Single Table Approach
|
||||
```c
|
||||
// Simple - one query builder function
|
||||
char* build_filter_query(cJSON* filters) {
|
||||
// Build single SELECT with WHERE conditions
|
||||
// Single ORDER BY and LIMIT
|
||||
// One execution path
|
||||
}
|
||||
```
|
||||
|
||||
### Multi-Table Approach
|
||||
```c
|
||||
// Complex - requires routing and union logic
|
||||
char* build_multi_table_query(cJSON* filters) {
|
||||
// 1. Analyze kinds to determine which tables to query
|
||||
// 2. Split filters per table type
|
||||
// 3. Build separate queries for each table
|
||||
// 4. Union results with complex ORDER BY
|
||||
// 5. Handle LIMIT across UNION (tricky!)
|
||||
}
|
||||
|
||||
typedef struct {
|
||||
bool needs_regular;
|
||||
bool needs_replaceable;
|
||||
bool needs_ephemeral;
|
||||
bool needs_addressable;
|
||||
cJSON* regular_filter;
|
||||
cJSON* replaceable_filter;
|
||||
cJSON* ephemeral_filter;
|
||||
cJSON* addressable_filter;
|
||||
} filter_routing_t;
|
||||
```
|
||||
|
||||
### Query Routing Complexity
|
||||
|
||||
For each REQ filter, we must:
|
||||
|
||||
1. **Analyze kinds** → Determine which tables to query
|
||||
2. **Split filters** → Create per-table filter conditions
|
||||
3. **Handle tag filters** → Different tag table references per event type
|
||||
4. **Union results** → Merge with proper ordering
|
||||
5. **Apply LIMIT** → Complex with UNION queries
|
||||
|
||||
## Performance Implications
|
||||
|
||||
### Single Table Advantages:
|
||||
- ✅ **Single query execution**
|
||||
- ✅ **One index strategy**
|
||||
- ✅ **Simple LIMIT handling**
|
||||
- ✅ **Unified ORDER BY**
|
||||
- ✅ **No UNION overhead**
|
||||
|
||||
### Multi-Table Disadvantages:
|
||||
- ❌ **Multiple query executions**
|
||||
- ❌ **UNION sorting overhead**
|
||||
- ❌ **Complex LIMIT application**
|
||||
- ❌ **Index fragmentation across tables**
|
||||
- ❌ **Result set merging complexity**
|
||||
|
||||
## Specific REQ Filter Challenges
|
||||
|
||||
### 1. LIMIT Handling with UNION
|
||||
```sql
|
||||
-- WRONG: Limit applies to each subquery
|
||||
(SELECT * FROM events_regular WHERE ... LIMIT 100)
|
||||
UNION ALL
|
||||
(SELECT * FROM events_replaceable WHERE ... LIMIT 100)
|
||||
-- Could return 200 events!
|
||||
|
||||
-- CORRECT: Limit applies to final result
|
||||
SELECT * FROM (
|
||||
SELECT * FROM events_regular WHERE ...
|
||||
UNION ALL
|
||||
SELECT * FROM events_replaceable WHERE ...
|
||||
ORDER BY created_at DESC, id ASC
|
||||
) LIMIT 100;
|
||||
-- But this sorts ALL results before limiting!
|
||||
```
|
||||
|
||||
### 2. Tag Filter Complexity
|
||||
Each event type needs different tag table joins:
|
||||
- `events_regular` → `tags_regular`
|
||||
- `events_replaceable` → `tags_replaceable` (with composite key)
|
||||
- `events_addressable` → `tags_addressable` (with composite key)
|
||||
- `events_ephemeral` → `tags_ephemeral`
|
||||
|
||||
### 3. Subscription State Management
|
||||
With multiple tables, subscription state becomes complex:
|
||||
- Which tables does this subscription monitor?
|
||||
- How to efficiently check new events across tables?
|
||||
- Different trigger/notification patterns per table
|
||||
|
||||
## Alternative: Unified Event View
|
||||
|
||||
### Hybrid Approach: Views Over Multi-Tables
|
||||
```sql
|
||||
-- Create unified view for queries
|
||||
CREATE VIEW all_events AS
|
||||
SELECT
|
||||
'regular' as event_type,
|
||||
id, pubkey, created_at, kind, content, sig
|
||||
FROM events_regular
|
||||
UNION ALL
|
||||
SELECT
|
||||
'replaceable' as event_type,
|
||||
id, pubkey, created_at, kind, content, sig
|
||||
FROM events_replaceable
|
||||
UNION ALL
|
||||
SELECT
|
||||
'ephemeral' as event_type,
|
||||
id, pubkey, created_at, kind, content, sig
|
||||
FROM events_ephemeral
|
||||
UNION ALL
|
||||
SELECT
|
||||
'addressable' as event_type,
|
||||
id, pubkey, created_at, kind, content, sig
|
||||
FROM events_addressable;
|
||||
|
||||
-- Unified tag view
|
||||
CREATE VIEW all_tags AS
|
||||
SELECT event_id, name, value, parameters FROM tags_regular
|
||||
UNION ALL
|
||||
SELECT CONCAT(event_pubkey, ':', event_kind), name, value, parameters FROM tags_replaceable
|
||||
UNION ALL
|
||||
SELECT event_id, name, value, parameters FROM tags_ephemeral
|
||||
UNION ALL
|
||||
SELECT CONCAT(event_pubkey, ':', event_kind, ':', d_tag), name, value, parameters FROM tags_addressable;
|
||||
```
|
||||
|
||||
### REQ Query Against Views:
|
||||
```sql
|
||||
-- Much simpler - back to single-table complexity
|
||||
SELECT DISTINCT e.*
|
||||
FROM all_events e
|
||||
JOIN all_tags t ON e.id = t.event_id
|
||||
WHERE e.pubkey IN (?)
|
||||
AND e.kind IN (?)
|
||||
AND t.name = 'p' AND t.value = ?
|
||||
ORDER BY e.created_at DESC, e.id ASC
|
||||
LIMIT ?;
|
||||
```
|
||||
|
||||
## Recommendation
|
||||
|
||||
**The multi-table approach creates significant subscription query complexity that may outweigh its benefits.**
|
||||
|
||||
### Key Issues:
|
||||
1. **REQ filters don't map to event types** - clients filter by kind, author, tags, not storage semantics
|
||||
2. **UNION query complexity** - much harder to optimize and implement
|
||||
3. **Subscription management burden** - must monitor multiple tables
|
||||
4. **Performance uncertainty** - UNION queries may be slower than single table
|
||||
|
||||
### Alternative Recommendation:
|
||||
|
||||
**Modified Single Table with Event Type Column:**
|
||||
|
||||
```sql
|
||||
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, -- 'regular', 'replaceable', 'ephemeral', 'addressable'
|
||||
content TEXT NOT NULL,
|
||||
sig TEXT NOT NULL,
|
||||
tags JSON,
|
||||
|
||||
-- Replaceable event fields
|
||||
replaced_at INTEGER,
|
||||
|
||||
-- Addressable event fields
|
||||
d_tag TEXT,
|
||||
|
||||
-- Unique constraints per event type
|
||||
CONSTRAINT unique_replaceable
|
||||
UNIQUE (pubkey, kind) WHERE event_type = 'replaceable',
|
||||
CONSTRAINT unique_addressable
|
||||
UNIQUE (pubkey, kind, d_tag) WHERE event_type = 'addressable'
|
||||
);
|
||||
```
|
||||
|
||||
### Benefits:
|
||||
- ✅ **Simple REQ queries** - single table, familiar patterns
|
||||
- ✅ **Type enforcement** - partial unique constraints handle replacement logic
|
||||
- ✅ **Performance** - unified indexes, no UNIONs
|
||||
- ✅ **Implementation simplicity** - minimal changes from current code
|
||||
- ✅ **Future flexibility** - can split tables later if needed
|
||||
|
||||
This approach gets the best of both worlds: protocol compliance through constraints, but query simplicity through unified storage.
|
||||
235
relay.log
235
relay.log
@@ -3,238 +3,3 @@
|
||||
[34m[INFO][0m Starting relay server...
|
||||
[34m[INFO][0m Starting libwebsockets-based Nostr relay server...
|
||||
[32m[SUCCESS][0m WebSocket relay started on ws://127.0.0.1:8888
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (1) ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 5 rows
|
||||
[34m[INFO][0m Total events sent: 5
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 17 rows
|
||||
[34m[INFO][0m Total events sent: 17
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (1) ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 7 rows
|
||||
[34m[INFO][0m Total events sent: 7
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (0) ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 1 rows
|
||||
[34m[INFO][0m Total events sent: 1
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND pubkey IN ('aa4fc8665f5696e33db7e1a572e3b0f5b3d615837b0f362dcb1c8068b098c7b4') ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 17 rows
|
||||
[34m[INFO][0m Total events sent: 17
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND created_at >= 1756983802 ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 6 rows
|
||||
[34m[INFO][0m Total events sent: 6
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 17 rows
|
||||
[34m[INFO][0m Total events sent: 17
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (0,1) ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 8 rows
|
||||
[34m[INFO][0m Total events sent: 8
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (1) ORDER BY created_at DESC LIMIT 1
|
||||
[34m[INFO][0m Query returned 1 rows
|
||||
[34m[INFO][0m Total events sent: 1
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling EVENT message
|
||||
[32m[SUCCESS][0m Event stored in database
|
||||
[32m[SUCCESS][0m Event stored successfully
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 22 rows
|
||||
[34m[INFO][0m Total events sent: 22
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (1) ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 9 rows
|
||||
[34m[INFO][0m Total events sent: 9
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (0) ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 1 rows
|
||||
[34m[INFO][0m Total events sent: 1
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND pubkey IN ('aa4fc8665f5696e33db7e1a572e3b0f5b3d615837b0f362dcb1c8068b098c7b4') ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 22 rows
|
||||
[34m[INFO][0m Total events sent: 22
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND created_at >= 1756983945 ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 9 rows
|
||||
[34m[INFO][0m Total events sent: 9
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 22 rows
|
||||
[34m[INFO][0m Total events sent: 22
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (0,1) ORDER BY created_at DESC LIMIT 500
|
||||
[34m[INFO][0m Query returned 10 rows
|
||||
[34m[INFO][0m Total events sent: 10
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
[34m[INFO][0m WebSocket connection established
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Handling REQ message
|
||||
[34m[INFO][0m Executing SQL: SELECT id, pubkey, created_at, kind, content, sig, tags FROM events WHERE 1=1 AND kind IN (1) ORDER BY created_at DESC LIMIT 1
|
||||
[34m[INFO][0m Query returned 1 rows
|
||||
[34m[INFO][0m Total events sent: 1
|
||||
[34m[INFO][0m Received WebSocket message
|
||||
[34m[INFO][0m Subscription closed
|
||||
[34m[INFO][0m WebSocket connection closed
|
||||
|
||||
966
src/main.c
966
src/main.c
File diff suppressed because it is too large
Load Diff
199
tests/subscribe_all.sh
Executable file
199
tests/subscribe_all.sh
Executable file
@@ -0,0 +1,199 @@
|
||||
#!/bin/bash
|
||||
|
||||
# Persistent Subscription Test Script
|
||||
# Subscribes to all events in the relay and prints them as they arrive in real-time
|
||||
# This tests the persistent subscription functionality of the C-Relay
|
||||
|
||||
set -e # Exit on any error
|
||||
|
||||
# Color constants
|
||||
RED='\033[31m'
|
||||
GREEN='\033[32m'
|
||||
YELLOW='\033[33m'
|
||||
BLUE='\033[34m'
|
||||
BOLD='\033[1m'
|
||||
RESET='\033[0m'
|
||||
|
||||
# Test configuration
|
||||
RELAY_URL="ws://127.0.0.1:8888"
|
||||
SUBSCRIPTION_ID="persistent_test_$(date +%s)"
|
||||
|
||||
# Print functions
|
||||
print_header() {
|
||||
echo -e "${BLUE}${BOLD}=== $1 ===${RESET}"
|
||||
}
|
||||
|
||||
print_info() {
|
||||
echo -e "${BLUE}[INFO]${RESET} $1"
|
||||
}
|
||||
|
||||
print_success() {
|
||||
echo -e "${GREEN}✓${RESET} $1"
|
||||
}
|
||||
|
||||
print_error() {
|
||||
echo -e "${RED}✗${RESET} $1"
|
||||
}
|
||||
|
||||
print_warning() {
|
||||
echo -e "${YELLOW}[WARNING]${RESET} $1"
|
||||
}
|
||||
|
||||
print_event() {
|
||||
echo -e "${GREEN}[EVENT]${RESET} $1"
|
||||
}
|
||||
|
||||
# Cleanup function
|
||||
cleanup() {
|
||||
print_info "Cleaning up..."
|
||||
if [[ -n "$WEBSOCAT_PID" ]]; then
|
||||
kill "$WEBSOCAT_PID" 2>/dev/null || true
|
||||
wait "$WEBSOCAT_PID" 2>/dev/null || true
|
||||
fi
|
||||
|
||||
# Send CLOSE message to clean up subscription on relay
|
||||
if command -v websocat &> /dev/null; then
|
||||
echo "[\"CLOSE\",\"$SUBSCRIPTION_ID\"]" | timeout 2s websocat "$RELAY_URL" 2>/dev/null || true
|
||||
fi
|
||||
|
||||
print_info "Cleanup complete"
|
||||
exit 0
|
||||
}
|
||||
|
||||
# Set up signal handlers
|
||||
trap cleanup SIGINT SIGTERM
|
||||
|
||||
# Parse events from relay responses
|
||||
parse_events() {
|
||||
while IFS= read -r line; do
|
||||
# Check if this is an EVENT message
|
||||
if echo "$line" | jq -e '. | type == "array" and length >= 3 and .[0] == "EVENT"' >/dev/null 2>&1; then
|
||||
# Extract event details
|
||||
local event_id=$(echo "$line" | jq -r '.[2].id' 2>/dev/null || echo "unknown")
|
||||
local event_kind=$(echo "$line" | jq -r '.[2].kind' 2>/dev/null || echo "unknown")
|
||||
local event_content=$(echo "$line" | jq -r '.[2].content' 2>/dev/null || echo "")
|
||||
local event_pubkey=$(echo "$line" | jq -r '.[2].pubkey' 2>/dev/null || echo "unknown")
|
||||
local event_created_at=$(echo "$line" | jq -r '.[2].created_at' 2>/dev/null || echo "unknown")
|
||||
local event_tags=$(echo "$line" | jq -r '.[2].tags | length' 2>/dev/null || echo "0")
|
||||
|
||||
# Convert timestamp to readable format
|
||||
local readable_time="unknown"
|
||||
if [[ "$event_created_at" != "unknown" && "$event_created_at" =~ ^[0-9]+$ ]]; then
|
||||
readable_time=$(date -d "@$event_created_at" "+%Y-%m-%d %H:%M:%S" 2>/dev/null || echo "$event_created_at")
|
||||
fi
|
||||
|
||||
# Print formatted event
|
||||
print_event "Kind: $event_kind | ID: ${event_id:0:16}... | Author: ${event_pubkey:0:16}..."
|
||||
echo -e " ${YELLOW}Time:${RESET} $readable_time | ${YELLOW}Tags:${RESET} $event_tags"
|
||||
|
||||
# Show content (truncated if too long)
|
||||
if [[ -n "$event_content" ]]; then
|
||||
local truncated_content="${event_content:0:100}"
|
||||
if [[ ${#event_content} -gt 100 ]]; then
|
||||
truncated_content="${truncated_content}..."
|
||||
fi
|
||||
echo -e " ${YELLOW}Content:${RESET} $truncated_content"
|
||||
fi
|
||||
echo # Blank line for readability
|
||||
|
||||
elif echo "$line" | jq -e '. | type == "array" and length >= 2 and .[0] == "EOSE"' >/dev/null 2>&1; then
|
||||
# End of stored events
|
||||
local sub_id=$(echo "$line" | jq -r '.[1]' 2>/dev/null)
|
||||
print_info "End of stored events for subscription: $sub_id"
|
||||
print_success "Persistent subscription is now active - waiting for new events..."
|
||||
echo
|
||||
|
||||
elif echo "$line" | jq -e '. | type == "array" and length >= 3 and .[0] == "CLOSED"' >/dev/null 2>&1; then
|
||||
# Subscription closed
|
||||
local sub_id=$(echo "$line" | jq -r '.[1]' 2>/dev/null)
|
||||
local reason=$(echo "$line" | jq -r '.[2]' 2>/dev/null)
|
||||
print_warning "Subscription $sub_id was closed: $reason"
|
||||
|
||||
elif echo "$line" | jq -e '. | type == "array" and length >= 4 and .[0] == "OK"' >/dev/null 2>&1; then
|
||||
# OK response to event publishing
|
||||
local event_id=$(echo "$line" | jq -r '.[1]' 2>/dev/null)
|
||||
local success=$(echo "$line" | jq -r '.[2]' 2>/dev/null)
|
||||
local message=$(echo "$line" | jq -r '.[3]' 2>/dev/null)
|
||||
if [[ "$success" == "true" ]]; then
|
||||
print_success "Event published: ${event_id:0:16}..."
|
||||
else
|
||||
print_error "Event publish failed: ${event_id:0:16}... - $message"
|
||||
fi
|
||||
|
||||
else
|
||||
# Unknown message type - just show it
|
||||
print_info "Relay message: $line"
|
||||
fi
|
||||
done
|
||||
}
|
||||
|
||||
# Main function
|
||||
main() {
|
||||
print_header "Persistent Subscription Test - Subscribe to All Events"
|
||||
|
||||
# Check dependencies
|
||||
if ! command -v websocat &> /dev/null; then
|
||||
print_error "websocat command not found"
|
||||
print_info "Please install websocat for testing"
|
||||
return 1
|
||||
fi
|
||||
if ! command -v jq &> /dev/null; then
|
||||
print_error "jq command not found"
|
||||
print_info "Please install jq for JSON processing"
|
||||
return 1
|
||||
fi
|
||||
|
||||
print_info "Subscription ID: $SUBSCRIPTION_ID"
|
||||
print_info "Relay URL: $RELAY_URL"
|
||||
print_info "Filter: {} (all events)"
|
||||
echo
|
||||
|
||||
# Create REQ message to subscribe to all events
|
||||
local req_message="[\"REQ\",\"$SUBSCRIPTION_ID\",{}]"
|
||||
|
||||
print_info "Establishing persistent subscription..."
|
||||
print_info "Press Ctrl+C to stop and cleanup"
|
||||
echo
|
||||
|
||||
# Start websocat connection and keep it open
|
||||
{
|
||||
echo "$req_message"
|
||||
# Keep the connection alive by sleeping indefinitely
|
||||
# The connection will receive events as they come in
|
||||
while true; do
|
||||
sleep 1
|
||||
done
|
||||
} | websocat "$RELAY_URL" | parse_events &
|
||||
|
||||
# Store the background process ID
|
||||
WEBSOCAT_PID=$!
|
||||
|
||||
# Wait for the background process (which runs indefinitely)
|
||||
# This will exit when we get a signal (Ctrl+C)
|
||||
wait "$WEBSOCAT_PID" 2>/dev/null || true
|
||||
}
|
||||
|
||||
# Usage information
|
||||
usage() {
|
||||
echo "Usage: $0"
|
||||
echo
|
||||
echo "This script creates a persistent subscription to all events on the relay"
|
||||
echo "and displays them in real-time as they arrive. Perfect for testing"
|
||||
echo "the persistent subscription functionality."
|
||||
echo
|
||||
echo "To test:"
|
||||
echo "1. Run this script in one terminal"
|
||||
echo "2. Run 'tests/1_nip_test.sh' in another terminal"
|
||||
echo "3. Watch events appear in real-time in this terminal"
|
||||
echo
|
||||
echo "Press Ctrl+C to stop and cleanup the subscription."
|
||||
}
|
||||
|
||||
# Handle help flag
|
||||
if [[ "$1" == "-h" || "$1" == "--help" ]]; then
|
||||
usage
|
||||
exit 0
|
||||
fi
|
||||
|
||||
# Run main function
|
||||
main "$@"
|
||||
Reference in New Issue
Block a user