Initial commit: Lightning Lottery - Bitcoin Lightning Network powered lottery

Features:
- Lightning Network payments via LNbits integration
- Provably fair draws using CSPRNG
- Random ticket number generation
- Automatic payouts with retry/redraw logic
- Nostr authentication (NIP-07)
- Multiple draw cycles (hourly, daily, weekly, monthly)
- PostgreSQL and SQLite database support
- Real-time countdown and payment animations
- Swagger API documentation
- Docker support

Stack:
- Backend: Node.js, TypeScript, Express
- Frontend: Next.js, React, TailwindCSS, Redux
- Payments: LNbits
This commit is contained in:
Michilis
2025-11-27 22:13:37 +00:00
commit d3bf8080b6
75 changed files with 18184 additions and 0 deletions

View File

@@ -0,0 +1,131 @@
-- Lightning Lottery Database Schema
-- PostgreSQL 14+
-- Create UUID extension if not exists
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Lotteries table
CREATE TABLE IF NOT EXISTS lotteries (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL,
status TEXT NOT NULL CHECK (status IN ('active', 'paused', 'finished')),
ticket_price_sats BIGINT NOT NULL,
fee_percent INTEGER NOT NULL CHECK (fee_percent >= 0 AND fee_percent <= 100),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Jackpot Cycles table
CREATE TABLE IF NOT EXISTS jackpot_cycles (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
lottery_id UUID NOT NULL REFERENCES lotteries(id),
cycle_type TEXT NOT NULL CHECK (cycle_type IN ('hourly', 'daily', 'weekly', 'monthly')),
sequence_number INTEGER NOT NULL,
scheduled_at TIMESTAMPTZ NOT NULL,
sales_open_at TIMESTAMPTZ NOT NULL,
sales_close_at TIMESTAMPTZ NOT NULL,
status TEXT NOT NULL CHECK (status IN ('scheduled', 'sales_open', 'drawing', 'completed', 'cancelled')),
pot_total_sats BIGINT NOT NULL DEFAULT 0,
pot_after_fee_sats BIGINT,
winning_ticket_id UUID,
winning_lightning_address TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Users table (optional for Nostr)
CREATE TABLE IF NOT EXISTS users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
nostr_pubkey TEXT UNIQUE NOT NULL,
display_name TEXT,
lightning_address TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Ticket Purchases table
CREATE TABLE IF NOT EXISTS ticket_purchases (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
lottery_id UUID NOT NULL REFERENCES lotteries(id),
cycle_id UUID NOT NULL REFERENCES jackpot_cycles(id),
user_id UUID REFERENCES users(id),
nostr_pubkey TEXT,
lightning_address TEXT NOT NULL,
buyer_name TEXT NOT NULL DEFAULT 'Anon',
number_of_tickets INTEGER NOT NULL,
ticket_price_sats BIGINT NOT NULL,
amount_sats BIGINT NOT NULL,
lnbits_invoice_id TEXT NOT NULL,
lnbits_payment_hash TEXT NOT NULL,
invoice_status TEXT NOT NULL CHECK (invoice_status IN ('pending', 'paid', 'expired', 'cancelled')),
ticket_issue_status TEXT NOT NULL CHECK (ticket_issue_status IN ('not_issued', 'issued')),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Tickets table
CREATE TABLE IF NOT EXISTS tickets (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
lottery_id UUID NOT NULL REFERENCES lotteries(id),
cycle_id UUID NOT NULL REFERENCES jackpot_cycles(id),
ticket_purchase_id UUID NOT NULL REFERENCES ticket_purchases(id),
user_id UUID REFERENCES users(id),
lightning_address TEXT NOT NULL,
serial_number BIGINT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Payouts table
CREATE TABLE IF NOT EXISTS payouts (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
lottery_id UUID NOT NULL REFERENCES lotteries(id),
cycle_id UUID NOT NULL REFERENCES jackpot_cycles(id),
ticket_id UUID NOT NULL REFERENCES tickets(id),
user_id UUID REFERENCES users(id),
lightning_address TEXT NOT NULL,
amount_sats BIGINT NOT NULL,
status TEXT NOT NULL CHECK (status IN ('pending', 'paid', 'failed')),
lnbits_payment_id TEXT,
error_message TEXT,
retry_count INTEGER NOT NULL DEFAULT 0,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Draw logs table (for audit and transparency)
CREATE TABLE IF NOT EXISTS draw_logs (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
cycle_id UUID NOT NULL REFERENCES jackpot_cycles(id),
number_of_tickets INTEGER NOT NULL,
pot_total_sats BIGINT NOT NULL,
fee_percent INTEGER NOT NULL,
pot_after_fee_sats BIGINT NOT NULL,
winner_ticket_id UUID,
winner_lightning_address TEXT,
rng_source TEXT NOT NULL,
selected_index INTEGER,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Indexes for performance
CREATE INDEX IF NOT EXISTS idx_cycles_status_time ON jackpot_cycles(status, scheduled_at);
CREATE INDEX IF NOT EXISTS idx_ticketpurchase_paymenthash ON ticket_purchases(lnbits_payment_hash);
CREATE INDEX IF NOT EXISTS idx_ticketpurchase_cycle ON ticket_purchases(cycle_id);
CREATE INDEX IF NOT EXISTS idx_tickets_cycle ON tickets(cycle_id);
CREATE INDEX IF NOT EXISTS idx_tickets_purchase ON tickets(ticket_purchase_id);
CREATE INDEX IF NOT EXISTS idx_payouts_ticket ON payouts(ticket_id);
CREATE INDEX IF NOT EXISTS idx_payouts_status ON payouts(status);
CREATE INDEX IF NOT EXISTS idx_users_pubkey ON users(nostr_pubkey);
-- Add foreign key constraint for winning ticket (after tickets table exists)
ALTER TABLE jackpot_cycles ADD CONSTRAINT fk_winning_ticket
FOREIGN KEY (winning_ticket_id) REFERENCES tickets(id) ON DELETE SET NULL;
ALTER TABLE ticket_purchases
ADD COLUMN IF NOT EXISTS buyer_name TEXT NOT NULL DEFAULT 'Anon';
-- Insert default lottery
INSERT INTO lotteries (name, status, ticket_price_sats, fee_percent)
VALUES ('Main Lightning Jackpot', 'active', 1000, 5)
ON CONFLICT DO NOTHING;