CREATE TABLE users ( id SERIAL PRIMARY KEY, username VARCHAR(255) NOT NULL UNIQUE, password VARCHAR(255) NOT NULL, 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; -- Update users table with new fields ALTER TABLE "public"."users" ADD COLUMN IF NOT EXISTS "email" varchar UNIQUE, ADD COLUMN IF NOT EXISTS "is_admin" boolean DEFAULT FALSE, ADD COLUMN IF NOT EXISTS "is_active" boolean DEFAULT TRUE, ADD COLUMN IF NOT EXISTS "last_login" timestamp with time zone, ADD COLUMN IF NOT EXISTS "updated_at" timestamp with time zone DEFAULT CURRENT_TIMESTAMP; -- 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 -- Core page access permissions 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; -- Granular permissions for Products INSERT INTO permissions (name, code, description, category) VALUES ('View Products', 'view:products', 'Can view product listings', 'Products'), ('Create Products', 'create:products', 'Can create new products', 'Products'), ('Edit Products', 'edit:products', 'Can edit product details', 'Products'), ('Delete Products', 'delete:products', 'Can delete products', 'Products') ON CONFLICT (code) DO NOTHING; -- Granular permissions for Categories INSERT INTO permissions (name, code, description, category) VALUES ('View Categories', 'view:categories', 'Can view categories', 'Categories'), ('Create Categories', 'create:categories', 'Can create new categories', 'Categories'), ('Edit Categories', 'edit:categories', 'Can edit categories', 'Categories'), ('Delete Categories', 'delete:categories', 'Can delete categories', 'Categories') ON CONFLICT (code) DO NOTHING; -- Granular permissions for Vendors INSERT INTO permissions (name, code, description, category) VALUES ('View Vendors', 'view:vendors', 'Can view vendors', 'Vendors'), ('Create Vendors', 'create:vendors', 'Can create new vendors', 'Vendors'), ('Edit Vendors', 'edit:vendors', 'Can edit vendors', 'Vendors'), ('Delete Vendors', 'delete:vendors', 'Can delete vendors', 'Vendors') ON CONFLICT (code) DO NOTHING; -- Granular permissions for Purchase Orders INSERT INTO permissions (name, code, description, category) VALUES ('View Purchase Orders', 'view:purchase_orders', 'Can view purchase orders', 'Purchase Orders'), ('Create Purchase Orders', 'create:purchase_orders', 'Can create new purchase orders', 'Purchase Orders'), ('Edit Purchase Orders', 'edit:purchase_orders', 'Can edit purchase orders', 'Purchase Orders'), ('Delete Purchase Orders', 'delete:purchase_orders', 'Can delete purchase orders', 'Purchase Orders') ON CONFLICT (code) DO NOTHING; -- User management permissions INSERT INTO permissions (name, code, description, category) VALUES ('View Users', 'view:users', 'Can view user accounts', 'Users'), ('Create Users', 'create:users', 'Can create user accounts', 'Users'), ('Edit Users', 'edit:users', 'Can modify user accounts', 'Users'), ('Delete Users', 'delete:users', 'Can delete user accounts', 'Users'), ('Manage Permissions', 'manage:permissions', 'Can assign permissions to users', 'Users') ON CONFLICT (code) DO NOTHING; -- System permissions INSERT INTO permissions (name, code, description, category) VALUES ('Run Calculations', 'run:calculations', 'Can trigger system calculations', 'System'), ('Import Data', 'import:data', 'Can import data into the system', 'System'), ('System Settings', 'edit:system_settings', 'Can modify system settings', 'System') 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;