89 lines
4.0 KiB
PL/PgSQL
89 lines
4.0 KiB
PL/PgSQL
CREATE TABLE users (
|
|
id SERIAL PRIMARY KEY,
|
|
username VARCHAR(255) NOT NULL UNIQUE,
|
|
password VARCHAR(255) NOT NULL,
|
|
email VARCHAR UNIQUE,
|
|
is_admin BOOLEAN DEFAULT FALSE,
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
last_login TIMESTAMP WITH TIME ZONE,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Function to update the updated_at timestamp
|
|
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
-- Sequence and defined type for users table if not exists
|
|
CREATE SEQUENCE IF NOT EXISTS users_id_seq;
|
|
|
|
-- Create permissions table
|
|
CREATE TABLE IF NOT EXISTS "public"."permissions" (
|
|
"id" SERIAL PRIMARY KEY,
|
|
"name" varchar NOT NULL UNIQUE,
|
|
"code" varchar NOT NULL UNIQUE,
|
|
"description" text,
|
|
"category" varchar NOT NULL,
|
|
"created_at" timestamp with time zone DEFAULT CURRENT_TIMESTAMP,
|
|
"updated_at" timestamp with time zone DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create user_permissions junction table
|
|
CREATE TABLE IF NOT EXISTS "public"."user_permissions" (
|
|
"user_id" int4 NOT NULL REFERENCES "public"."users"("id") ON DELETE CASCADE,
|
|
"permission_id" int4 NOT NULL REFERENCES "public"."permissions"("id") ON DELETE CASCADE,
|
|
"created_at" timestamp with time zone DEFAULT CURRENT_TIMESTAMP,
|
|
PRIMARY KEY ("user_id", "permission_id")
|
|
);
|
|
|
|
-- Add triggers for updated_at on users and permissions
|
|
DROP TRIGGER IF EXISTS update_users_updated_at ON users;
|
|
CREATE TRIGGER update_users_updated_at
|
|
BEFORE UPDATE ON users
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
DROP TRIGGER IF EXISTS update_permissions_updated_at ON permissions;
|
|
CREATE TRIGGER update_permissions_updated_at
|
|
BEFORE UPDATE ON permissions
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- Insert default permissions by page - only the ones used in application
|
|
INSERT INTO permissions (name, code, description, category) VALUES
|
|
('Dashboard Access', 'access:dashboard', 'Can access the Dashboard page', 'Pages'),
|
|
('Products Access', 'access:products', 'Can access the Products page', 'Pages'),
|
|
('Categories Access', 'access:categories', 'Can access the Categories page', 'Pages'),
|
|
('Vendors Access', 'access:vendors', 'Can access the Vendors page', 'Pages'),
|
|
('Analytics Access', 'access:analytics', 'Can access the Analytics page', 'Pages'),
|
|
('Forecasting Access', 'access:forecasting', 'Can access the Forecasting page', 'Pages'),
|
|
('Purchase Orders Access', 'access:purchase_orders', 'Can access the Purchase Orders page', 'Pages'),
|
|
('Import Access', 'access:import', 'Can access the Import page', 'Pages'),
|
|
('Settings Access', 'access:settings', 'Can access the Settings page', 'Pages'),
|
|
('AI Validation Debug Access', 'access:ai_validation_debug', 'Can access the AI Validation Debug page', 'Pages')
|
|
ON CONFLICT (code) DO NOTHING;
|
|
|
|
-- Settings section permissions
|
|
INSERT INTO permissions (name, code, description, category) VALUES
|
|
('Data Management', 'settings:data_management', 'Access to the Data Management settings section', 'Settings'),
|
|
('Stock Management', 'settings:stock_management', 'Access to the Stock Management settings section', 'Settings'),
|
|
('Performance Metrics', 'settings:performance_metrics', 'Access to the Performance Metrics settings section', 'Settings'),
|
|
('Calculation Settings', 'settings:calculation_settings', 'Access to the Calculation Settings section', 'Settings'),
|
|
('Template Management', 'settings:templates', 'Access to the Template Management settings section', 'Settings'),
|
|
('User Management', 'settings:user_management', 'Access to the User Management settings section', 'Settings')
|
|
ON CONFLICT (code) DO NOTHING;
|
|
|
|
-- Set any existing users as admin
|
|
UPDATE users SET is_admin = TRUE WHERE is_admin IS NULL;
|
|
|
|
-- Grant all permissions to admin users
|
|
INSERT INTO user_permissions (user_id, permission_id)
|
|
SELECT u.id, p.id
|
|
FROM users u, permissions p
|
|
WHERE u.is_admin = TRUE
|
|
ON CONFLICT DO NOTHING; |