bmc_hub/migrations/004_contacts_relationships.sql

79 lines
3.6 KiB
MySQL
Raw Normal View History

-- Migration 004: Opret contacts og customer relationships tabeller
-- Dato: 6. december 2025
-- Contacts tabel
CREATE TABLE IF NOT EXISTS contacts (
id SERIAL PRIMARY KEY,
first_name VARCHAR(100) NOT NULL,
last_name VARCHAR(100) NOT NULL,
email VARCHAR(255),
phone VARCHAR(50),
mobile VARCHAR(50),
title VARCHAR(100),
department VARCHAR(100),
is_active BOOLEAN DEFAULT TRUE,
vtiger_id VARCHAR(50) UNIQUE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Junction tabel for mange-til-mange relation mellem contacts og customers
CREATE TABLE IF NOT EXISTS contact_companies (
id SERIAL PRIMARY KEY,
contact_id INTEGER NOT NULL REFERENCES contacts(id) ON DELETE CASCADE,
customer_id INTEGER NOT NULL REFERENCES customers(id) ON DELETE CASCADE,
is_primary BOOLEAN DEFAULT FALSE,
role VARCHAR(100),
notes TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
UNIQUE(contact_id, customer_id)
);
-- Customer relationships tabel (for parent/child og billing strukturer)
CREATE TABLE IF NOT EXISTS customer_relationships (
id SERIAL PRIMARY KEY,
parent_customer_id INTEGER NOT NULL REFERENCES customers(id) ON DELETE CASCADE,
child_customer_id INTEGER NOT NULL REFERENCES customers(id) ON DELETE CASCADE,
relationship_type VARCHAR(50) NOT NULL CHECK (relationship_type IN ('parent_child', 'billing', 'partnership', 'subsidiary')),
notes TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
UNIQUE(parent_customer_id, child_customer_id, relationship_type)
);
-- Indexes for contacts
CREATE INDEX IF NOT EXISTS idx_contacts_email ON contacts(email);
CREATE INDEX IF NOT EXISTS idx_contacts_active ON contacts(is_active);
CREATE INDEX IF NOT EXISTS idx_contacts_vtiger ON contacts(vtiger_id);
CREATE INDEX IF NOT EXISTS idx_contacts_name ON contacts(first_name, last_name);
-- Indexes for contact_companies
CREATE INDEX IF NOT EXISTS idx_contact_companies_contact ON contact_companies(contact_id);
CREATE INDEX IF NOT EXISTS idx_contact_companies_customer ON contact_companies(customer_id);
CREATE INDEX IF NOT EXISTS idx_contact_companies_primary ON contact_companies(customer_id, is_primary);
-- Indexes for customer_relationships
CREATE INDEX IF NOT EXISTS idx_customer_relationships_parent ON customer_relationships(parent_customer_id);
CREATE INDEX IF NOT EXISTS idx_customer_relationships_child ON customer_relationships(child_customer_id);
CREATE INDEX IF NOT EXISTS idx_customer_relationships_type ON customer_relationships(relationship_type);
-- Triggers for updated_at
DROP TRIGGER IF EXISTS update_contacts_updated_at ON contacts;
CREATE TRIGGER update_contacts_updated_at
BEFORE UPDATE ON contacts
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_customer_relationships_updated_at ON customer_relationships;
CREATE TRIGGER update_customer_relationships_updated_at
BEFORE UPDATE ON customer_relationships
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
-- Kommentarer
COMMENT ON TABLE contacts IS 'Contact persons associated with one or more customers';
COMMENT ON TABLE contact_companies IS 'Many-to-many junction table linking contacts to customers';
COMMENT ON TABLE customer_relationships IS 'Hierarchical and billing relationships between customers';
COMMENT ON COLUMN contact_companies.is_primary IS 'Whether this is the primary contact for this customer';
COMMENT ON COLUMN customer_relationships.relationship_type IS 'Type of relationship: parent_child, billing, partnership, subsidiary';