Files
c-relay/db/README.md
2025-09-03 20:39:06 -04:00

228 lines
6.2 KiB
Markdown

# C Nostr Relay Database
This directory contains the SQLite database schema and initialization scripts for the C Nostr Relay implementation.
## Files
- **`schema.sql`** - Complete database schema based on nostr-rs-relay v18
- **`init.sh`** - Database initialization script
- **`c_nostr_relay.db`** - SQLite database file (created after running init.sh)
## Quick Start
1. **Initialize the database:**
```bash
cd db
./init.sh
```
2. **Force reinitialize (removes existing database):**
```bash
./init.sh --force
```
3. **Initialize with optimization and info:**
```bash
./init.sh --info --optimize
```
## Database Schema
The schema is fully compatible with the Nostr protocol and includes:
### Core Tables
- **`event`** - Main event storage with all Nostr event data
- **`tag`** - Denormalized tag index for efficient queries
- **`user_verification`** - NIP-05 verification tracking
- **`account`** - User account management (optional)
- **`invoice`** - Lightning payment tracking (optional)
### Key Features
- ✅ **NIP-01 compliant** - Full basic protocol support
- ✅ **Replaceable events** - Supports kinds 0, 3, 10000-19999
- ✅ **Parameterized replaceable** - Supports kinds 30000-39999 with `d` tags
- ✅ **Event deletion** - NIP-09 soft deletion with `hidden` column
- ✅ **Event expiration** - NIP-40 automatic cleanup
- ✅ **Authentication** - NIP-42 client authentication
- ✅ **NIP-05 verification** - Domain-based identity verification
- ✅ **Performance optimized** - Comprehensive indexing strategy
### Schema Version
Current version: **v18** (compatible with nostr-rs-relay v18)
## Database Structure
### Event Storage
```sql
CREATE TABLE event (
id INTEGER PRIMARY KEY,
event_hash BLOB NOT NULL, -- 32-byte SHA256 hash
first_seen INTEGER NOT NULL, -- relay receive timestamp
created_at INTEGER NOT NULL, -- event creation timestamp
expires_at INTEGER, -- NIP-40 expiration
author BLOB NOT NULL, -- 32-byte pubkey
delegated_by BLOB, -- NIP-26 delegator
kind INTEGER NOT NULL, -- event kind
hidden INTEGER DEFAULT FALSE, -- soft deletion flag
content TEXT NOT NULL -- complete JSON event
);
```
### Tag Indexing
```sql
CREATE TABLE tag (
id INTEGER PRIMARY KEY,
event_id INTEGER NOT NULL,
name TEXT, -- tag name ("e", "p", etc.)
value TEXT, -- tag value
created_at INTEGER NOT NULL, -- denormalized for performance
kind INTEGER NOT NULL -- denormalized for performance
);
```
## Performance Features
### Optimized Indexes
- **Hash-based lookups** - `event_hash_index` for O(1) event retrieval
- **Author queries** - `author_index`, `author_created_at_index`
- **Kind filtering** - `kind_index`, `kind_created_at_index`
- **Tag searching** - `tag_covering_index` for efficient tag queries
- **Composite queries** - Multi-column indexes for complex filters
### Query Optimization
- **Denormalized tags** - Includes `kind` and `created_at` in tag table
- **Binary storage** - BLOBs for hex data (pubkeys, hashes)
- **WAL mode** - Write-Ahead Logging for concurrent access
- **Automatic cleanup** - Triggers for data integrity
## Usage Examples
### Basic Operations
1. **Insert an event:**
```sql
INSERT INTO event (event_hash, first_seen, created_at, author, kind, content)
VALUES (?, ?, ?, ?, ?, ?);
```
2. **Query by author:**
```sql
SELECT content FROM event
WHERE author = ? AND hidden != TRUE
ORDER BY created_at DESC;
```
3. **Filter by tags:**
```sql
SELECT e.content FROM event e
JOIN tag t ON e.id = t.event_id
WHERE t.name = 'p' AND t.value = ? AND e.hidden != TRUE;
```
### Advanced Queries
1. **Get replaceable event (latest only):**
```sql
SELECT content FROM event
WHERE author = ? AND kind = ? AND hidden != TRUE
ORDER BY created_at DESC LIMIT 1;
```
2. **Tag-based filtering (NIP-01 filters):**
```sql
SELECT e.content FROM event e
WHERE e.id IN (
SELECT t.event_id FROM tag t
WHERE t.name = ? AND t.value IN (?, ?, ?)
) AND e.hidden != TRUE;
```
## Maintenance
### Regular Operations
1. **Check database integrity:**
```bash
sqlite3 c_nostr_relay.db "PRAGMA integrity_check;"
```
2. **Optimize database:**
```bash
sqlite3 c_nostr_relay.db "PRAGMA optimize; VACUUM; ANALYZE;"
```
3. **Clean expired events:**
```sql
DELETE FROM event WHERE expires_at <= strftime('%s', 'now');
```
### Monitoring
1. **Database size:**
```bash
ls -lh c_nostr_relay.db
```
2. **Table statistics:**
```sql
SELECT name, COUNT(*) as count FROM (
SELECT 'events' as name FROM event UNION ALL
SELECT 'tags' as name FROM tag UNION ALL
SELECT 'verifications' as name FROM user_verification
) GROUP BY name;
```
## Migration Support
The schema includes a migration system for future updates:
```sql
CREATE TABLE schema_info (
version INTEGER PRIMARY KEY,
applied_at INTEGER NOT NULL,
description TEXT
);
```
## Security Considerations
1. **Input validation** - Always validate event JSON and signatures
2. **Rate limiting** - Implement at application level
3. **Access control** - Use `account` table for permissions
4. **Backup strategy** - Regular database backups recommended
## Compatibility
- **SQLite version** - Requires SQLite 3.8.0+
- **nostr-rs-relay** - Schema compatible with v18
- **NIPs supported** - 01, 02, 05, 09, 10, 11, 26, 40, 42
- **C libraries** - Compatible with sqlite3 C API
## Troubleshooting
### Common Issues
1. **Database locked error:**
- Ensure proper connection closing in your C code
- Check for long-running transactions
2. **Performance issues:**
- Run `PRAGMA optimize;` regularly
- Consider `VACUUM` if database grew significantly
3. **Schema errors:**
- Verify SQLite version compatibility
- Check foreign key constraints
### Getting Help
- Check the main project README for C implementation details
- Review nostr-rs-relay documentation for reference implementation
- Consult Nostr NIPs for protocol specifications
## License
This database schema is part of the C Nostr Relay project and follows the same license terms.