Initial commit
Dieser Commit ist enthalten in:
20
v2_adminpanel/migrations/add_device_type.sql
Normale Datei
20
v2_adminpanel/migrations/add_device_type.sql
Normale Datei
@ -0,0 +1,20 @@
|
||||
-- Migration: Add device_type column to device_registrations table
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT 1 FROM information_schema.columns
|
||||
WHERE table_name = 'device_registrations' AND column_name = 'device_type') THEN
|
||||
ALTER TABLE device_registrations ADD COLUMN device_type VARCHAR(50) DEFAULT 'unknown';
|
||||
|
||||
-- Update existing records to have a device_type based on operating system
|
||||
UPDATE device_registrations
|
||||
SET device_type = CASE
|
||||
WHEN operating_system ILIKE '%windows%' THEN 'desktop'
|
||||
WHEN operating_system ILIKE '%mac%' THEN 'desktop'
|
||||
WHEN operating_system ILIKE '%linux%' THEN 'desktop'
|
||||
WHEN operating_system ILIKE '%android%' THEN 'mobile'
|
||||
WHEN operating_system ILIKE '%ios%' THEN 'mobile'
|
||||
ELSE 'unknown'
|
||||
END
|
||||
WHERE device_type IS NULL OR device_type = 'unknown';
|
||||
END IF;
|
||||
END $$;
|
||||
72
v2_adminpanel/migrations/add_fake_constraint.sql
Normale Datei
72
v2_adminpanel/migrations/add_fake_constraint.sql
Normale Datei
@ -0,0 +1,72 @@
|
||||
-- Add constraint to ensure licenses always inherit is_fake from their customer
|
||||
-- This migration adds a trigger to automatically sync is_fake status
|
||||
|
||||
-- Function to sync is_fake status
|
||||
CREATE OR REPLACE FUNCTION sync_license_fake_status()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
-- When inserting or updating a license, get is_fake from customer
|
||||
IF TG_OP = 'INSERT' OR (TG_OP = 'UPDATE' AND NEW.customer_id != OLD.customer_id) THEN
|
||||
SELECT is_fake INTO NEW.is_fake
|
||||
FROM customers
|
||||
WHERE id = NEW.customer_id;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Trigger for licenses table
|
||||
DROP TRIGGER IF EXISTS sync_license_fake_before_insert_update ON licenses;
|
||||
CREATE TRIGGER sync_license_fake_before_insert_update
|
||||
BEFORE INSERT OR UPDATE ON licenses
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION sync_license_fake_status();
|
||||
|
||||
-- Function to update licenses when customer is_fake changes
|
||||
CREATE OR REPLACE FUNCTION sync_customer_fake_to_licenses()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
-- When customer is_fake changes, update all their licenses
|
||||
IF TG_OP = 'UPDATE' AND NEW.is_fake != OLD.is_fake THEN
|
||||
UPDATE licenses
|
||||
SET is_fake = NEW.is_fake
|
||||
WHERE customer_id = NEW.id;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Trigger for customers table
|
||||
DROP TRIGGER IF EXISTS sync_customer_fake_after_update ON customers;
|
||||
CREATE TRIGGER sync_customer_fake_after_update
|
||||
AFTER UPDATE ON customers
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION sync_customer_fake_to_licenses();
|
||||
|
||||
-- Verify current data is consistent (should return 0)
|
||||
DO $$
|
||||
DECLARE
|
||||
mismatch_count INTEGER;
|
||||
BEGIN
|
||||
SELECT COUNT(*) INTO mismatch_count
|
||||
FROM licenses l
|
||||
JOIN customers c ON l.customer_id = c.id
|
||||
WHERE l.is_fake != c.is_fake;
|
||||
|
||||
IF mismatch_count > 0 THEN
|
||||
RAISE NOTICE 'Found % mismatches. Fixing...', mismatch_count;
|
||||
|
||||
-- Fix any existing mismatches
|
||||
UPDATE licenses l
|
||||
SET is_fake = c.is_fake
|
||||
FROM customers c
|
||||
WHERE l.customer_id = c.id
|
||||
AND l.is_fake != c.is_fake;
|
||||
|
||||
RAISE NOTICE 'Fixed all mismatches.';
|
||||
ELSE
|
||||
RAISE NOTICE 'No mismatches found. Data is consistent.';
|
||||
END IF;
|
||||
END $$;
|
||||
58
v2_adminpanel/migrations/add_june_2025_partition.sql
Normale Datei
58
v2_adminpanel/migrations/add_june_2025_partition.sql
Normale Datei
@ -0,0 +1,58 @@
|
||||
-- Migration: Add June 2025 partition for license_heartbeats table
|
||||
-- This migration adds the missing partition for the current month (June 2025)
|
||||
|
||||
-- Check if the partition already exists before creating it
|
||||
DO $$
|
||||
BEGIN
|
||||
-- Check if the June 2025 partition exists
|
||||
IF NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM pg_tables
|
||||
WHERE tablename = 'license_heartbeats_2025_06'
|
||||
) THEN
|
||||
-- Create the June 2025 partition
|
||||
EXECUTE 'CREATE TABLE license_heartbeats_2025_06 PARTITION OF license_heartbeats
|
||||
FOR VALUES FROM (''2025-06-01'') TO (''2025-07-01'')';
|
||||
|
||||
RAISE NOTICE 'Created partition license_heartbeats_2025_06';
|
||||
ELSE
|
||||
RAISE NOTICE 'Partition license_heartbeats_2025_06 already exists';
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- Also create partitions for the next few months to avoid future issues
|
||||
DO $$
|
||||
DECLARE
|
||||
partition_name text;
|
||||
start_date date;
|
||||
end_date date;
|
||||
i integer;
|
||||
BEGIN
|
||||
-- Create partitions for the next 6 months
|
||||
FOR i IN 0..6 LOOP
|
||||
start_date := date_trunc('month', CURRENT_DATE + (i || ' months')::interval);
|
||||
end_date := start_date + interval '1 month';
|
||||
partition_name := 'license_heartbeats_' || to_char(start_date, 'YYYY_MM');
|
||||
|
||||
-- Check if partition already exists
|
||||
IF NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM pg_tables
|
||||
WHERE tablename = partition_name
|
||||
) THEN
|
||||
EXECUTE format('CREATE TABLE %I PARTITION OF license_heartbeats FOR VALUES FROM (%L) TO (%L)',
|
||||
partition_name, start_date, end_date);
|
||||
|
||||
RAISE NOTICE 'Created partition %', partition_name;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END $$;
|
||||
|
||||
-- Verify the partitions were created
|
||||
SELECT
|
||||
schemaname,
|
||||
tablename,
|
||||
tableowner
|
||||
FROM pg_tables
|
||||
WHERE tablename LIKE 'license_heartbeats_%'
|
||||
ORDER BY tablename;
|
||||
17
v2_adminpanel/migrations/cleanup_orphaned_api_tables.sql
Normale Datei
17
v2_adminpanel/migrations/cleanup_orphaned_api_tables.sql
Normale Datei
@ -0,0 +1,17 @@
|
||||
-- Cleanup orphaned API-related tables
|
||||
-- Since admin panel is exclusively for Account Forger, we only need system_api_key table
|
||||
|
||||
-- Drop tables that depend on api_clients
|
||||
DROP TABLE IF EXISTS rate_limits CASCADE;
|
||||
DROP TABLE IF EXISTS license_events CASCADE;
|
||||
|
||||
-- Drop orphaned API tables
|
||||
DROP TABLE IF EXISTS api_clients CASCADE;
|
||||
DROP TABLE IF EXISTS api_keys CASCADE;
|
||||
|
||||
-- Add comments to document the single API key system
|
||||
COMMENT ON TABLE system_api_key IS 'Single API key table for Account Forger authentication. This is the ONLY API key system in use.';
|
||||
|
||||
-- Log the cleanup
|
||||
INSERT INTO audit_log (username, action, entity_type, details, ip_address)
|
||||
VALUES ('SYSTEM', 'CLEANUP', 'database', 'Removed orphaned API tables: api_keys, api_clients, rate_limits, license_events', '127.0.0.1');
|
||||
107
v2_adminpanel/migrations/create_lead_tables.sql
Normale Datei
107
v2_adminpanel/migrations/create_lead_tables.sql
Normale Datei
@ -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';
|
||||
79
v2_adminpanel/migrations/create_license_heartbeats_table.sql
Normale Datei
79
v2_adminpanel/migrations/create_license_heartbeats_table.sql
Normale Datei
@ -0,0 +1,79 @@
|
||||
-- Migration: Create license_heartbeats partitioned table
|
||||
-- Date: 2025-06-19
|
||||
-- Description: Creates the license_heartbeats table with monthly partitioning
|
||||
|
||||
-- Create the partitioned table
|
||||
CREATE TABLE IF NOT EXISTS license_heartbeats (
|
||||
id BIGSERIAL,
|
||||
license_id INTEGER NOT NULL,
|
||||
hardware_id VARCHAR(255) NOT NULL,
|
||||
ip_address INET NOT NULL,
|
||||
timestamp TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
session_data JSONB,
|
||||
PRIMARY KEY (id, timestamp),
|
||||
FOREIGN KEY (license_id) REFERENCES licenses(id) ON DELETE CASCADE
|
||||
) PARTITION BY RANGE (timestamp);
|
||||
|
||||
-- Create indexes for better query performance
|
||||
CREATE INDEX IF NOT EXISTS idx_license_heartbeats_license_id_timestamp
|
||||
ON license_heartbeats (license_id, timestamp DESC);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_license_heartbeats_timestamp
|
||||
ON license_heartbeats (timestamp DESC);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_license_heartbeats_hardware_id
|
||||
ON license_heartbeats (hardware_id);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_license_heartbeats_ip_address
|
||||
ON license_heartbeats (ip_address);
|
||||
|
||||
-- Create partitions for current and next month
|
||||
DO $$
|
||||
DECLARE
|
||||
current_year INTEGER;
|
||||
current_month INTEGER;
|
||||
next_year INTEGER;
|
||||
next_month INTEGER;
|
||||
partition_name TEXT;
|
||||
start_date DATE;
|
||||
end_date DATE;
|
||||
BEGIN
|
||||
-- Get current date info
|
||||
current_year := EXTRACT(YEAR FROM CURRENT_DATE);
|
||||
current_month := EXTRACT(MONTH FROM CURRENT_DATE);
|
||||
|
||||
-- Calculate next month
|
||||
IF current_month = 12 THEN
|
||||
next_year := current_year + 1;
|
||||
next_month := 1;
|
||||
ELSE
|
||||
next_year := current_year;
|
||||
next_month := current_month + 1;
|
||||
END IF;
|
||||
|
||||
-- Create current month partition
|
||||
partition_name := 'license_heartbeats_' || current_year || '_' || LPAD(current_month::TEXT, 2, '0');
|
||||
start_date := DATE_TRUNC('month', CURRENT_DATE);
|
||||
end_date := DATE_TRUNC('month', CURRENT_DATE) + INTERVAL '1 month';
|
||||
|
||||
EXECUTE format('CREATE TABLE IF NOT EXISTS %I PARTITION OF license_heartbeats FOR VALUES FROM (%L) TO (%L)',
|
||||
partition_name, start_date, end_date);
|
||||
|
||||
-- Create next month partition
|
||||
partition_name := 'license_heartbeats_' || next_year || '_' || LPAD(next_month::TEXT, 2, '0');
|
||||
start_date := end_date;
|
||||
end_date := start_date + INTERVAL '1 month';
|
||||
|
||||
EXECUTE format('CREATE TABLE IF NOT EXISTS %I PARTITION OF license_heartbeats FOR VALUES FROM (%L) TO (%L)',
|
||||
partition_name, start_date, end_date);
|
||||
|
||||
RAISE NOTICE 'Created partitions for current and next month';
|
||||
END $$;
|
||||
|
||||
-- Add comment to the table
|
||||
COMMENT ON TABLE license_heartbeats IS 'Stores heartbeat data from license validations for real-time monitoring';
|
||||
COMMENT ON COLUMN license_heartbeats.license_id IS 'Foreign key to licenses table';
|
||||
COMMENT ON COLUMN license_heartbeats.hardware_id IS 'Hardware identifier of the device';
|
||||
COMMENT ON COLUMN license_heartbeats.ip_address IS 'IP address from which the heartbeat was sent';
|
||||
COMMENT ON COLUMN license_heartbeats.timestamp IS 'Timestamp of the heartbeat';
|
||||
COMMENT ON COLUMN license_heartbeats.session_data IS 'Additional session data in JSON format';
|
||||
9
v2_adminpanel/migrations/remove_duplicate_api_key.sql
Normale Datei
9
v2_adminpanel/migrations/remove_duplicate_api_key.sql
Normale Datei
@ -0,0 +1,9 @@
|
||||
-- Remove duplicate API key from client_configs table
|
||||
-- Since admin panel is exclusively for Account Forger, we only need system_api_key
|
||||
|
||||
-- Remove the api_key column from client_configs
|
||||
ALTER TABLE client_configs DROP COLUMN IF EXISTS api_key;
|
||||
|
||||
-- Update description
|
||||
COMMENT ON TABLE client_configs IS 'Configuration for Account Forger client (versions, timeouts)';
|
||||
COMMENT ON TABLE system_api_key IS 'Single API key for Account Forger authentication';
|
||||
48
v2_adminpanel/migrations/rename_test_to_fake.sql
Normale Datei
48
v2_adminpanel/migrations/rename_test_to_fake.sql
Normale Datei
@ -0,0 +1,48 @@
|
||||
-- Migration script to rename is_test columns to is_fake
|
||||
-- This separates fake/demo data from test licenses
|
||||
|
||||
-- 1. Rename columns in all tables
|
||||
DO $$
|
||||
BEGIN
|
||||
-- Rename is_test to is_fake in customers table
|
||||
IF EXISTS (SELECT 1 FROM information_schema.columns
|
||||
WHERE table_name = 'customers' AND column_name = 'is_test') THEN
|
||||
ALTER TABLE customers RENAME COLUMN is_test TO is_fake;
|
||||
END IF;
|
||||
|
||||
-- Rename is_test to is_fake in licenses table
|
||||
IF EXISTS (SELECT 1 FROM information_schema.columns
|
||||
WHERE table_name = 'licenses' AND column_name = 'is_test') THEN
|
||||
ALTER TABLE licenses RENAME COLUMN is_test TO is_fake;
|
||||
END IF;
|
||||
|
||||
-- Rename is_test to is_fake in resource_pools table
|
||||
IF EXISTS (SELECT 1 FROM information_schema.columns
|
||||
WHERE table_name = 'resource_pools' AND column_name = 'is_test') THEN
|
||||
ALTER TABLE resource_pools RENAME COLUMN is_test TO is_fake;
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- 2. Rename indexes
|
||||
DO $$
|
||||
BEGIN
|
||||
-- Rename index for customers
|
||||
IF EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_customers_is_test') THEN
|
||||
ALTER INDEX idx_customers_is_test RENAME TO idx_customers_is_fake;
|
||||
END IF;
|
||||
|
||||
-- Rename index for licenses
|
||||
IF EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_licenses_is_test') THEN
|
||||
ALTER INDEX idx_licenses_is_test RENAME TO idx_licenses_is_fake;
|
||||
END IF;
|
||||
|
||||
-- Rename index for resource_pools
|
||||
IF EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_resource_pools_is_test') THEN
|
||||
ALTER INDEX idx_resource_pools_is_test RENAME TO idx_resource_pools_is_fake;
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- 3. Add comments to clarify the purpose
|
||||
COMMENT ON COLUMN customers.is_fake IS 'Marks fake/demo data, not to be confused with test licenses';
|
||||
COMMENT ON COLUMN licenses.is_fake IS 'Marks fake/demo data, not to be confused with test license type';
|
||||
COMMENT ON COLUMN resource_pools.is_fake IS 'Marks fake/demo resources';
|
||||
In neuem Issue referenzieren
Einen Benutzer sperren