Browse Source
- Updated the roles table schema to use role code as the primary key, enhancing readability in junction tables. - Modified related tables (user_roles, product_role_visibility) to reference role code instead of role ID. - Adjusted seeding logic and utility functions to accommodate the new primary key structure, ensuring consistent role management across the application. - Added a migration script to facilitate the database schema changes.main
5 changed files with 93 additions and 38 deletions
@ -0,0 +1,58 @@ |
|||||
|
-- Migration: Refactor roles table to use code as primary key |
||||
|
-- This migration drops and recreates the role-related tables with the new schema |
||||
|
|
||||
|
-- Drop existing tables (CASCADE removes dependent foreign keys) |
||||
|
DROP TABLE IF EXISTS "product_role_visibility" CASCADE;--> statement-breakpoint |
||||
|
DROP TABLE IF EXISTS "user_roles" CASCADE;--> statement-breakpoint |
||||
|
DROP TABLE IF EXISTS "roles" CASCADE;--> statement-breakpoint |
||||
|
|
||||
|
-- Recreate roles table with code as primary key |
||||
|
CREATE TABLE "roles" ( |
||||
|
"code" "role_code" PRIMARY KEY NOT NULL, |
||||
|
"display_name" text NOT NULL, |
||||
|
"description" text NOT NULL, |
||||
|
"requires_approval" boolean DEFAULT false NOT NULL, |
||||
|
"sort_order" integer DEFAULT 0 NOT NULL, |
||||
|
"active" boolean DEFAULT true NOT NULL, |
||||
|
"created_at" timestamp DEFAULT now() NOT NULL, |
||||
|
"updated_at" timestamp DEFAULT now() NOT NULL |
||||
|
); |
||||
|
--> statement-breakpoint |
||||
|
|
||||
|
-- Recreate user_roles table with roleCode instead of roleId |
||||
|
CREATE TABLE "user_roles" ( |
||||
|
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL, |
||||
|
"user_id" uuid NOT NULL, |
||||
|
"role_code" "role_code" NOT NULL, |
||||
|
"status" "role_request_status" DEFAULT 'pending' NOT NULL, |
||||
|
"organization_name" text, |
||||
|
"admin_notes" text, |
||||
|
"status_history" jsonb DEFAULT '[]' NOT NULL, |
||||
|
"created_at" timestamp DEFAULT now() NOT NULL, |
||||
|
"updated_at" timestamp DEFAULT now() NOT NULL |
||||
|
); |
||||
|
--> statement-breakpoint |
||||
|
|
||||
|
-- Recreate product_role_visibility table with roleCode instead of roleId |
||||
|
CREATE TABLE "product_role_visibility" ( |
||||
|
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL, |
||||
|
"product_id" uuid NOT NULL, |
||||
|
"role_code" "role_code" NOT NULL, |
||||
|
"created_at" timestamp DEFAULT now() NOT NULL |
||||
|
); |
||||
|
--> statement-breakpoint |
||||
|
|
||||
|
-- Add foreign key constraints |
||||
|
ALTER TABLE "user_roles" ADD CONSTRAINT "user_roles_user_id_users_id_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint |
||||
|
ALTER TABLE "user_roles" ADD CONSTRAINT "user_roles_role_code_roles_code_fk" FOREIGN KEY ("role_code") REFERENCES "public"."roles"("code") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint |
||||
|
ALTER TABLE "product_role_visibility" ADD CONSTRAINT "product_role_visibility_product_id_products_id_fk" FOREIGN KEY ("product_id") REFERENCES "public"."products"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint |
||||
|
ALTER TABLE "product_role_visibility" ADD CONSTRAINT "product_role_visibility_role_code_roles_code_fk" FOREIGN KEY ("role_code") REFERENCES "public"."roles"("code") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint |
||||
|
|
||||
|
-- Create indexes |
||||
|
CREATE INDEX "user_roles_user_id_role_code_unique" ON "user_roles" USING btree ("user_id","role_code");--> statement-breakpoint |
||||
|
CREATE INDEX "user_roles_user_id_idx" ON "user_roles" USING btree ("user_id");--> statement-breakpoint |
||||
|
CREATE INDEX "user_roles_role_code_idx" ON "user_roles" USING btree ("role_code");--> statement-breakpoint |
||||
|
CREATE INDEX "user_roles_status_idx" ON "user_roles" USING btree ("status");--> statement-breakpoint |
||||
|
CREATE INDEX "product_role_visibility_product_id_role_code_unique" ON "product_role_visibility" USING btree ("product_id","role_code");--> statement-breakpoint |
||||
|
CREATE INDEX "product_role_visibility_product_id_idx" ON "product_role_visibility" USING btree ("product_id");--> statement-breakpoint |
||||
|
CREATE INDEX "product_role_visibility_role_code_idx" ON "product_role_visibility" USING btree ("role_code"); |
||||
Loading…
Reference in new issue