1+ -- +goose Up
2+ -- Create UUID extension if not exists
3+ CREATE EXTENSION IF NOT EXISTS " uuid-ossp" ;
4+
5+ -- Core User and Account Management
6+ CREATE TABLE users (
7+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
8+ email VARCHAR (255 ) UNIQUE NOT NULL ,
9+ password_hash VARCHAR (255 ),
10+ auth_provider VARCHAR (50 ),
11+ provider_id VARCHAR (255 ),
12+ email_verified BOOLEAN DEFAULT FALSE,
13+ email_verified_at TIMESTAMPTZ ,
14+ account_type VARCHAR (50 ) NOT NULL ,
15+ account_status VARCHAR (50 ) DEFAULT ' pending' ,
16+ two_factor_enabled BOOLEAN DEFAULT FALSE,
17+ two_factor_method VARCHAR (50 ),
18+ user_login_type VARCHAR (50 ),
19+ created_at TIMESTAMPTZ DEFAULT NOW(),
20+ updated_at TIMESTAMPTZ DEFAULT NOW(),
21+ last_login_at TIMESTAMPTZ ,
22+ deleted_at TIMESTAMPTZ
23+ );
24+
25+ CREATE TABLE personal_users (
26+ id UUID PRIMARY KEY REFERENCES users(id) ON DELETE CASCADE ,
27+ first_name VARCHAR (255 ),
28+ last_name VARCHAR (255 ),
29+ profile_picture VARCHAR (255 ),
30+ phone_number VARCHAR (50 ),
31+ phone_number_verified BOOLEAN DEFAULT FALSE,
32+ phone_number_verified_at TIMESTAMPTZ ,
33+ nationality VARCHAR (255 ),
34+ residential_country VARCHAR (255 ),
35+ user_address VARCHAR (255 ),
36+ user_city VARCHAR (255 ),
37+ user_postal_code VARCHAR (255 ),
38+ gender VARCHAR (50 ),
39+ date_of_birth DATE ,
40+ job_role VARCHAR (255 ),
41+ personal_account_type VARCHAR (50 ),
42+ employment_type VARCHAR (50 ),
43+ tax_id VARCHAR (255 ),
44+ default_payment_currency VARCHAR (50 ),
45+ default_payment_method VARCHAR (50 ),
46+ hourly_rate DECIMAL (18 , 2 ),
47+ specialization VARCHAR (255 ),
48+ kyc_status VARCHAR (50 ) DEFAULT ' pending' ,
49+ kyc_verified_at TIMESTAMPTZ ,
50+ created_at TIMESTAMPTZ DEFAULT NOW(),
51+ updated_at TIMESTAMPTZ DEFAULT NOW()
52+ );
53+
54+ CREATE TABLE companies (
55+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
56+ owner_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE ,
57+ company_name VARCHAR (255 ) NOT NULL ,
58+ company_email VARCHAR (255 ),
59+ company_phone VARCHAR (50 ),
60+ company_size VARCHAR (50 ),
61+ company_industry VARCHAR (255 ),
62+ company_description TEXT ,
63+ company_headquarters VARCHAR (255 ),
64+ company_logo VARCHAR (255 ),
65+ company_website VARCHAR (255 ),
66+ primary_contact_name VARCHAR (255 ),
67+ primary_contact_email VARCHAR (255 ),
68+ primary_contact_phone VARCHAR (50 ),
69+ company_address VARCHAR (255 ),
70+ company_city VARCHAR (255 ),
71+ company_postal_code VARCHAR (255 ),
72+ company_country VARCHAR (255 ),
73+ company_registration_number VARCHAR (255 ),
74+ registration_country VARCHAR (255 ),
75+ tax_id VARCHAR (255 ),
76+ incorporation_date DATE ,
77+ account_status VARCHAR (50 ) DEFAULT ' pending' ,
78+ kyb_status VARCHAR (50 ) DEFAULT ' pending' ,
79+ kyb_verified_at TIMESTAMPTZ ,
80+ kyb_verification_method VARCHAR (50 ),
81+ kyb_verification_provider VARCHAR (255 ),
82+ kyb_rejection_reason TEXT ,
83+ legal_entity_type VARCHAR (50 ),
84+ created_at TIMESTAMPTZ DEFAULT NOW(),
85+ updated_at TIMESTAMPTZ DEFAULT NOW()
86+ );
87+
88+ CREATE TABLE company_users (
89+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
90+ company_id UUID NOT NULL REFERENCES companies(id) ON DELETE CASCADE ,
91+ user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE ,
92+ role VARCHAR (50 ) NOT NULL ,
93+ department VARCHAR (100 ),
94+ job_title VARCHAR (255 ),
95+ is_administrator BOOLEAN DEFAULT FALSE,
96+ can_manage_payroll BOOLEAN DEFAULT FALSE,
97+ can_manage_invoices BOOLEAN DEFAULT FALSE,
98+ can_manage_employees BOOLEAN DEFAULT FALSE,
99+ can_manage_company_settings BOOLEAN DEFAULT FALSE,
100+ can_manage_bank_accounts BOOLEAN DEFAULT FALSE,
101+ can_manage_wallets BOOLEAN DEFAULT FALSE,
102+ permissions JSONB,
103+ is_active BOOLEAN DEFAULT TRUE,
104+ added_by UUID REFERENCES users(id),
105+ created_at TIMESTAMPTZ DEFAULT NOW(),
106+ updated_at TIMESTAMPTZ DEFAULT NOW(),
107+ UNIQUE(company_id, user_id)
108+ );
109+
110+ CREATE TABLE company_staff_profiles (
111+ id UUID PRIMARY KEY REFERENCES company_users(id) ON DELETE CASCADE ,
112+ first_name VARCHAR (255 ),
113+ last_name VARCHAR (255 ),
114+ profile_picture VARCHAR (255 ),
115+ phone_number VARCHAR (50 ),
116+ email VARCHAR (255 ),
117+ department VARCHAR (100 ),
118+ job_title VARCHAR (255 ),
119+ reports_to UUID REFERENCES company_users(id),
120+ hire_date DATE ,
121+ created_at TIMESTAMPTZ DEFAULT NOW(),
122+ updated_at TIMESTAMPTZ DEFAULT NOW()
123+ );
124+
125+ CREATE TABLE company_employees (
126+ id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
127+ company_id UUID NOT NULL REFERENCES companies(id) ON DELETE CASCADE ,
128+ user_id UUID REFERENCES users(id) ON DELETE SET NULL ,
129+ employee_id VARCHAR (100 ),
130+ department VARCHAR (100 ),
131+ position VARCHAR (100 ),
132+ employment_status VARCHAR (50 ) DEFAULT ' active' ,
133+ employment_type VARCHAR (50 ),
134+ start_date DATE ,
135+ end_date DATE ,
136+ manager_id UUID REFERENCES company_users(id),
137+ salary_amount DECIMAL (18 , 6 ),
138+ salary_currency VARCHAR (10 ),
139+ salary_frequency VARCHAR (50 ),
140+ hourly_rate DECIMAL (18 , 6 ),
141+ payment_method VARCHAR (50 ),
142+ payment_split JSONB,
143+ tax_information JSONB,
144+ created_at TIMESTAMPTZ DEFAULT NOW(),
145+ updated_at TIMESTAMPTZ DEFAULT NOW(),
146+ UNIQUE(company_id, employee_id)
147+ );
148+
149+ -- Create indexes for better performance
150+ CREATE INDEX idx_users_email ON users(email);
151+ CREATE INDEX idx_users_account_type ON users(account_type);
152+ CREATE INDEX idx_users_account_status ON users(account_status);
153+ CREATE INDEX idx_companies_owner_id ON companies(owner_id);
154+ CREATE INDEX idx_company_users_company_id ON company_users(company_id);
155+ CREATE INDEX idx_company_users_user_id ON company_users(user_id);
156+ CREATE INDEX idx_company_employees_company_id ON company_employees(company_id);
157+ CREATE INDEX idx_company_employees_user_id ON company_employees(user_id);
158+
159+ -- +goose Down
160+ DROP TABLE IF EXISTS company_employees CASCADE;
161+ DROP TABLE IF EXISTS company_staff_profiles CASCADE;
162+ DROP TABLE IF EXISTS company_users CASCADE;
163+ DROP TABLE IF EXISTS companies CASCADE;
164+ DROP TABLE IF EXISTS personal_users CASCADE;
165+ DROP TABLE IF EXISTS users CASCADE;
166+ DROP EXTENSION IF EXISTS " uuid-ossp" ;
0 commit comments