Dieser Commit ist enthalten in:
Claude Project Manager
2025-07-05 17:51:16 +02:00
Commit 0d7d888502
1594 geänderte Dateien mit 122839 neuen und 0 gelöschten Zeilen

Datei anzeigen

@ -0,0 +1,107 @@
-- Lead Management Tables Migration
-- This creates all necessary tables for the lead management system
-- Enable UUID extension if not already enabled
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- 1. Lead Institutions (only name required)
CREATE TABLE IF NOT EXISTS lead_institutions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(255) NOT NULL,
-- Metadata for future extensions without schema changes
metadata JSONB DEFAULT '{}',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
created_by VARCHAR(100),
UNIQUE(name)
);
-- Index for fast lookups
CREATE INDEX IF NOT EXISTS idx_lead_institutions_name ON lead_institutions(name);
-- 2. Lead Contacts
CREATE TABLE IF NOT EXISTS lead_contacts (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
institution_id UUID NOT NULL REFERENCES lead_institutions(id) ON DELETE CASCADE,
first_name VARCHAR(100) NOT NULL,
last_name VARCHAR(100) NOT NULL,
position VARCHAR(255),
-- Extra fields for future extensions
extra_fields JSONB DEFAULT '{}',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Indexes for performance
CREATE INDEX IF NOT EXISTS idx_lead_contacts_institution ON lead_contacts(institution_id);
CREATE INDEX IF NOT EXISTS idx_lead_contacts_name ON lead_contacts(last_name, first_name);
-- 3. Flexible Contact Details (phones, emails, etc.)
CREATE TABLE IF NOT EXISTS lead_contact_details (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
contact_id UUID NOT NULL REFERENCES lead_contacts(id) ON DELETE CASCADE,
detail_type VARCHAR(50) NOT NULL, -- 'phone', 'email', 'social', etc.
detail_value VARCHAR(255) NOT NULL,
detail_label VARCHAR(50), -- 'Mobil', 'Geschäftlich', 'Privat', etc.
is_primary BOOLEAN DEFAULT false,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Indexes for fast queries
CREATE INDEX IF NOT EXISTS idx_lead_details_contact_type ON lead_contact_details(contact_id, detail_type);
CREATE INDEX IF NOT EXISTS idx_lead_details_value ON lead_contact_details(detail_value);
-- 4. Versioned Notes with History
CREATE TABLE IF NOT EXISTS lead_notes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
contact_id UUID NOT NULL REFERENCES lead_contacts(id) ON DELETE CASCADE,
note_text TEXT NOT NULL,
version INTEGER DEFAULT 1,
is_current BOOLEAN DEFAULT true,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
created_by VARCHAR(100),
parent_note_id UUID REFERENCES lead_notes(id),
CHECK (note_text <> '')
);
-- Indexes for note queries
CREATE INDEX IF NOT EXISTS idx_lead_notes_contact_current ON lead_notes(contact_id, is_current);
CREATE INDEX IF NOT EXISTS idx_lead_notes_created ON lead_notes(created_at DESC);
-- Full text search preparation
CREATE INDEX IF NOT EXISTS idx_lead_contacts_search ON lead_contacts
USING gin(to_tsvector('german',
COALESCE(first_name, '') || ' ' ||
COALESCE(last_name, '') || ' ' ||
COALESCE(position, '')
));
-- Update timestamp trigger function
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';
-- Apply update trigger to tables with updated_at
CREATE TRIGGER update_lead_institutions_updated_at
BEFORE UPDATE ON lead_institutions
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_lead_contacts_updated_at
BEFORE UPDATE ON lead_contacts
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
-- Add comments for documentation
COMMENT ON TABLE lead_institutions IS 'Organizations/Companies for lead management';
COMMENT ON TABLE lead_contacts IS 'Contact persons within institutions';
COMMENT ON TABLE lead_contact_details IS 'Flexible contact details (phone, email, etc.)';
COMMENT ON TABLE lead_notes IS 'Versioned notes with full history';
COMMENT ON COLUMN lead_contact_details.detail_type IS 'Type of detail: phone, email, social, etc.';
COMMENT ON COLUMN lead_notes.is_current IS 'Only current version is shown, old versions kept for history';
COMMENT ON COLUMN lead_notes.parent_note_id IS 'References original note for version tracking';