Add Drizzle ORM setup and database configuration

- Add drizzle.config.ts for database migrations
- Create server/database/ structure with schema
- Add drizzle-orm and postgres dependencies
- Add db:* npm scripts for database management
This commit is contained in:
Bastian Masanek
2025-10-30 14:28:42 +01:00
parent 9102dab881
commit ef9845c5c5
7 changed files with 1445 additions and 17 deletions

View File

@@ -0,0 +1,86 @@
CREATE TYPE "public"."order_status" AS ENUM('pending', 'paid', 'processing', 'completed', 'failed');--> statement-breakpoint
CREATE TYPE "public"."salutation" AS ENUM('male', 'female', 'other');--> statement-breakpoint
CREATE TABLE "cart_items" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"cart_id" uuid NOT NULL,
"product_id" uuid NOT NULL,
"quantity" integer DEFAULT 1 NOT NULL,
"added_at" timestamp DEFAULT now() NOT NULL
);
--> statement-breakpoint
CREATE TABLE "carts" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"user_id" uuid,
"session_id" text NOT NULL,
"created_at" timestamp DEFAULT now() NOT NULL,
"updated_at" timestamp DEFAULT now() NOT NULL
);
--> statement-breakpoint
CREATE TABLE "order_items" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"order_id" uuid NOT NULL,
"product_id" uuid NOT NULL,
"product_snapshot" jsonb NOT NULL,
"quantity" integer DEFAULT 1 NOT NULL,
"price_snapshot" numeric(10, 2) NOT NULL,
"created_at" timestamp DEFAULT now() NOT NULL
);
--> statement-breakpoint
CREATE TABLE "orders" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"order_number" text NOT NULL,
"user_id" uuid NOT NULL,
"total_amount" numeric(10, 2) NOT NULL,
"status" "order_status" DEFAULT 'pending' NOT NULL,
"billing_address" jsonb NOT NULL,
"payment_id" text,
"payment_completed_at" timestamp,
"created_at" timestamp DEFAULT now() NOT NULL,
"updated_at" timestamp DEFAULT now() NOT NULL,
CONSTRAINT "orders_order_number_unique" UNIQUE("order_number")
);
--> statement-breakpoint
CREATE TABLE "products" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"nav_product_id" text NOT NULL,
"name" text NOT NULL,
"description" text NOT NULL,
"price" numeric(10, 2) NOT NULL,
"stock_quantity" integer DEFAULT 0 NOT NULL,
"category" text NOT NULL,
"active" boolean DEFAULT true NOT NULL,
"created_at" timestamp DEFAULT now() NOT NULL,
"updated_at" timestamp DEFAULT now() NOT NULL,
CONSTRAINT "products_nav_product_id_unique" UNIQUE("nav_product_id")
);
--> statement-breakpoint
CREATE TABLE "users" (
"id" uuid PRIMARY KEY DEFAULT gen_random_uuid() NOT NULL,
"experimenta_id" text NOT NULL,
"email" text NOT NULL,
"first_name" text NOT NULL,
"last_name" text NOT NULL,
"salutation" "salutation",
"date_of_birth" timestamp,
"phone" text,
"street" text,
"post_code" text,
"city" text,
"country_code" text,
"created_at" timestamp DEFAULT now() NOT NULL,
"updated_at" timestamp DEFAULT now() NOT NULL,
CONSTRAINT "users_experimenta_id_unique" UNIQUE("experimenta_id")
);
--> statement-breakpoint
ALTER TABLE "cart_items" ADD CONSTRAINT "cart_items_cart_id_carts_id_fk" FOREIGN KEY ("cart_id") REFERENCES "public"."carts"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "cart_items" ADD CONSTRAINT "cart_items_product_id_products_id_fk" FOREIGN KEY ("product_id") REFERENCES "public"."products"("id") ON DELETE restrict ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "carts" ADD CONSTRAINT "carts_user_id_users_id_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "order_items" ADD CONSTRAINT "order_items_order_id_orders_id_fk" FOREIGN KEY ("order_id") REFERENCES "public"."orders"("id") ON DELETE cascade ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "order_items" ADD CONSTRAINT "order_items_product_id_products_id_fk" FOREIGN KEY ("product_id") REFERENCES "public"."products"("id") ON DELETE restrict ON UPDATE no action;--> statement-breakpoint
ALTER TABLE "orders" ADD CONSTRAINT "orders_user_id_users_id_fk" FOREIGN KEY ("user_id") REFERENCES "public"."users"("id") ON DELETE restrict ON UPDATE no action;--> statement-breakpoint
CREATE INDEX "orders_order_number_idx" ON "orders" USING btree ("order_number");--> statement-breakpoint
CREATE INDEX "orders_user_id_idx" ON "orders" USING btree ("user_id");--> statement-breakpoint
CREATE INDEX "orders_status_idx" ON "orders" USING btree ("status");--> statement-breakpoint
CREATE INDEX "products_nav_product_id_idx" ON "products" USING btree ("nav_product_id");--> statement-breakpoint
CREATE INDEX "products_active_idx" ON "products" USING btree ("active");--> statement-breakpoint
CREATE INDEX "products_category_idx" ON "products" USING btree ("category");

View File

@@ -0,0 +1,645 @@
{
"id": "edf5f532-2f87-4dfd-8478-0861f6542e29",
"prevId": "00000000-0000-0000-0000-000000000000",
"version": "7",
"dialect": "postgresql",
"tables": {
"public.cart_items": {
"name": "cart_items",
"schema": "",
"columns": {
"id": {
"name": "id",
"type": "uuid",
"primaryKey": true,
"notNull": true,
"default": "gen_random_uuid()"
},
"cart_id": {
"name": "cart_id",
"type": "uuid",
"primaryKey": false,
"notNull": true
},
"product_id": {
"name": "product_id",
"type": "uuid",
"primaryKey": false,
"notNull": true
},
"quantity": {
"name": "quantity",
"type": "integer",
"primaryKey": false,
"notNull": true,
"default": 1
},
"added_at": {
"name": "added_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
}
},
"indexes": {},
"foreignKeys": {
"cart_items_cart_id_carts_id_fk": {
"name": "cart_items_cart_id_carts_id_fk",
"tableFrom": "cart_items",
"tableTo": "carts",
"columnsFrom": [
"cart_id"
],
"columnsTo": [
"id"
],
"onDelete": "cascade",
"onUpdate": "no action"
},
"cart_items_product_id_products_id_fk": {
"name": "cart_items_product_id_products_id_fk",
"tableFrom": "cart_items",
"tableTo": "products",
"columnsFrom": [
"product_id"
],
"columnsTo": [
"id"
],
"onDelete": "restrict",
"onUpdate": "no action"
}
},
"compositePrimaryKeys": {},
"uniqueConstraints": {},
"policies": {},
"checkConstraints": {},
"isRLSEnabled": false
},
"public.carts": {
"name": "carts",
"schema": "",
"columns": {
"id": {
"name": "id",
"type": "uuid",
"primaryKey": true,
"notNull": true,
"default": "gen_random_uuid()"
},
"user_id": {
"name": "user_id",
"type": "uuid",
"primaryKey": false,
"notNull": false
},
"session_id": {
"name": "session_id",
"type": "text",
"primaryKey": false,
"notNull": true
},
"created_at": {
"name": "created_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
},
"updated_at": {
"name": "updated_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
}
},
"indexes": {},
"foreignKeys": {
"carts_user_id_users_id_fk": {
"name": "carts_user_id_users_id_fk",
"tableFrom": "carts",
"tableTo": "users",
"columnsFrom": [
"user_id"
],
"columnsTo": [
"id"
],
"onDelete": "cascade",
"onUpdate": "no action"
}
},
"compositePrimaryKeys": {},
"uniqueConstraints": {},
"policies": {},
"checkConstraints": {},
"isRLSEnabled": false
},
"public.order_items": {
"name": "order_items",
"schema": "",
"columns": {
"id": {
"name": "id",
"type": "uuid",
"primaryKey": true,
"notNull": true,
"default": "gen_random_uuid()"
},
"order_id": {
"name": "order_id",
"type": "uuid",
"primaryKey": false,
"notNull": true
},
"product_id": {
"name": "product_id",
"type": "uuid",
"primaryKey": false,
"notNull": true
},
"product_snapshot": {
"name": "product_snapshot",
"type": "jsonb",
"primaryKey": false,
"notNull": true
},
"quantity": {
"name": "quantity",
"type": "integer",
"primaryKey": false,
"notNull": true,
"default": 1
},
"price_snapshot": {
"name": "price_snapshot",
"type": "numeric(10, 2)",
"primaryKey": false,
"notNull": true
},
"created_at": {
"name": "created_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
}
},
"indexes": {},
"foreignKeys": {
"order_items_order_id_orders_id_fk": {
"name": "order_items_order_id_orders_id_fk",
"tableFrom": "order_items",
"tableTo": "orders",
"columnsFrom": [
"order_id"
],
"columnsTo": [
"id"
],
"onDelete": "cascade",
"onUpdate": "no action"
},
"order_items_product_id_products_id_fk": {
"name": "order_items_product_id_products_id_fk",
"tableFrom": "order_items",
"tableTo": "products",
"columnsFrom": [
"product_id"
],
"columnsTo": [
"id"
],
"onDelete": "restrict",
"onUpdate": "no action"
}
},
"compositePrimaryKeys": {},
"uniqueConstraints": {},
"policies": {},
"checkConstraints": {},
"isRLSEnabled": false
},
"public.orders": {
"name": "orders",
"schema": "",
"columns": {
"id": {
"name": "id",
"type": "uuid",
"primaryKey": true,
"notNull": true,
"default": "gen_random_uuid()"
},
"order_number": {
"name": "order_number",
"type": "text",
"primaryKey": false,
"notNull": true
},
"user_id": {
"name": "user_id",
"type": "uuid",
"primaryKey": false,
"notNull": true
},
"total_amount": {
"name": "total_amount",
"type": "numeric(10, 2)",
"primaryKey": false,
"notNull": true
},
"status": {
"name": "status",
"type": "order_status",
"typeSchema": "public",
"primaryKey": false,
"notNull": true,
"default": "'pending'"
},
"billing_address": {
"name": "billing_address",
"type": "jsonb",
"primaryKey": false,
"notNull": true
},
"payment_id": {
"name": "payment_id",
"type": "text",
"primaryKey": false,
"notNull": false
},
"payment_completed_at": {
"name": "payment_completed_at",
"type": "timestamp",
"primaryKey": false,
"notNull": false
},
"created_at": {
"name": "created_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
},
"updated_at": {
"name": "updated_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
}
},
"indexes": {
"orders_order_number_idx": {
"name": "orders_order_number_idx",
"columns": [
{
"expression": "order_number",
"isExpression": false,
"asc": true,
"nulls": "last"
}
],
"isUnique": false,
"concurrently": false,
"method": "btree",
"with": {}
},
"orders_user_id_idx": {
"name": "orders_user_id_idx",
"columns": [
{
"expression": "user_id",
"isExpression": false,
"asc": true,
"nulls": "last"
}
],
"isUnique": false,
"concurrently": false,
"method": "btree",
"with": {}
},
"orders_status_idx": {
"name": "orders_status_idx",
"columns": [
{
"expression": "status",
"isExpression": false,
"asc": true,
"nulls": "last"
}
],
"isUnique": false,
"concurrently": false,
"method": "btree",
"with": {}
}
},
"foreignKeys": {
"orders_user_id_users_id_fk": {
"name": "orders_user_id_users_id_fk",
"tableFrom": "orders",
"tableTo": "users",
"columnsFrom": [
"user_id"
],
"columnsTo": [
"id"
],
"onDelete": "restrict",
"onUpdate": "no action"
}
},
"compositePrimaryKeys": {},
"uniqueConstraints": {
"orders_order_number_unique": {
"name": "orders_order_number_unique",
"nullsNotDistinct": false,
"columns": [
"order_number"
]
}
},
"policies": {},
"checkConstraints": {},
"isRLSEnabled": false
},
"public.products": {
"name": "products",
"schema": "",
"columns": {
"id": {
"name": "id",
"type": "uuid",
"primaryKey": true,
"notNull": true,
"default": "gen_random_uuid()"
},
"nav_product_id": {
"name": "nav_product_id",
"type": "text",
"primaryKey": false,
"notNull": true
},
"name": {
"name": "name",
"type": "text",
"primaryKey": false,
"notNull": true
},
"description": {
"name": "description",
"type": "text",
"primaryKey": false,
"notNull": true
},
"price": {
"name": "price",
"type": "numeric(10, 2)",
"primaryKey": false,
"notNull": true
},
"stock_quantity": {
"name": "stock_quantity",
"type": "integer",
"primaryKey": false,
"notNull": true,
"default": 0
},
"category": {
"name": "category",
"type": "text",
"primaryKey": false,
"notNull": true
},
"active": {
"name": "active",
"type": "boolean",
"primaryKey": false,
"notNull": true,
"default": true
},
"created_at": {
"name": "created_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
},
"updated_at": {
"name": "updated_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
}
},
"indexes": {
"products_nav_product_id_idx": {
"name": "products_nav_product_id_idx",
"columns": [
{
"expression": "nav_product_id",
"isExpression": false,
"asc": true,
"nulls": "last"
}
],
"isUnique": false,
"concurrently": false,
"method": "btree",
"with": {}
},
"products_active_idx": {
"name": "products_active_idx",
"columns": [
{
"expression": "active",
"isExpression": false,
"asc": true,
"nulls": "last"
}
],
"isUnique": false,
"concurrently": false,
"method": "btree",
"with": {}
},
"products_category_idx": {
"name": "products_category_idx",
"columns": [
{
"expression": "category",
"isExpression": false,
"asc": true,
"nulls": "last"
}
],
"isUnique": false,
"concurrently": false,
"method": "btree",
"with": {}
}
},
"foreignKeys": {},
"compositePrimaryKeys": {},
"uniqueConstraints": {
"products_nav_product_id_unique": {
"name": "products_nav_product_id_unique",
"nullsNotDistinct": false,
"columns": [
"nav_product_id"
]
}
},
"policies": {},
"checkConstraints": {},
"isRLSEnabled": false
},
"public.users": {
"name": "users",
"schema": "",
"columns": {
"id": {
"name": "id",
"type": "uuid",
"primaryKey": true,
"notNull": true,
"default": "gen_random_uuid()"
},
"experimenta_id": {
"name": "experimenta_id",
"type": "text",
"primaryKey": false,
"notNull": true
},
"email": {
"name": "email",
"type": "text",
"primaryKey": false,
"notNull": true
},
"first_name": {
"name": "first_name",
"type": "text",
"primaryKey": false,
"notNull": true
},
"last_name": {
"name": "last_name",
"type": "text",
"primaryKey": false,
"notNull": true
},
"salutation": {
"name": "salutation",
"type": "salutation",
"typeSchema": "public",
"primaryKey": false,
"notNull": false
},
"date_of_birth": {
"name": "date_of_birth",
"type": "timestamp",
"primaryKey": false,
"notNull": false
},
"phone": {
"name": "phone",
"type": "text",
"primaryKey": false,
"notNull": false
},
"street": {
"name": "street",
"type": "text",
"primaryKey": false,
"notNull": false
},
"post_code": {
"name": "post_code",
"type": "text",
"primaryKey": false,
"notNull": false
},
"city": {
"name": "city",
"type": "text",
"primaryKey": false,
"notNull": false
},
"country_code": {
"name": "country_code",
"type": "text",
"primaryKey": false,
"notNull": false
},
"created_at": {
"name": "created_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
},
"updated_at": {
"name": "updated_at",
"type": "timestamp",
"primaryKey": false,
"notNull": true,
"default": "now()"
}
},
"indexes": {},
"foreignKeys": {},
"compositePrimaryKeys": {},
"uniqueConstraints": {
"users_experimenta_id_unique": {
"name": "users_experimenta_id_unique",
"nullsNotDistinct": false,
"columns": [
"experimenta_id"
]
}
},
"policies": {},
"checkConstraints": {},
"isRLSEnabled": false
}
},
"enums": {
"public.order_status": {
"name": "order_status",
"schema": "public",
"values": [
"pending",
"paid",
"processing",
"completed",
"failed"
]
},
"public.salutation": {
"name": "salutation",
"schema": "public",
"values": [
"male",
"female",
"other"
]
}
},
"schemas": {},
"sequences": {},
"roles": {},
"policies": {},
"views": {},
"_meta": {
"columns": {},
"schemas": {},
"tables": {}
}
}

View File

@@ -0,0 +1,13 @@
{
"version": "7",
"dialect": "postgresql",
"entries": [
{
"idx": 0,
"version": "7",
"when": 1761820599588,
"tag": "0000_tiresome_malcolm_colcord",
"breakpoints": true
}
]
}

278
server/database/schema.ts Normal file
View File

@@ -0,0 +1,278 @@
/**
* Database Schema for my.experimenta.science
*
* This schema defines the core data model for the experimenta e-commerce platform.
* It manages user profiles, products, shopping carts, and orders.
*
* Key Design Decisions:
*
* 1. UUID Primary Keys:
* - We use UUIDs instead of serial/auto-increment IDs for all primary keys
* - Benefits:
* * Globally unique across distributed systems (no coordination needed)
* * Can be generated client-side without database round-trip
* * More secure - prevents enumeration attacks (guessing IDs)
* * Future-proof for horizontal scaling and multi-region deployment
* - Trade-off: Slightly larger index size (16 bytes vs 4/8 bytes for integers)
* - Implementation: Using PostgreSQL's gen_random_uuid() via defaultRandom()
*
* 2. JSONB for Flexible Data:
* - billing_address (orders table): Stores address snapshot at time of purchase
* - product_snapshot (order_items table): Stores immutable product details
* - Why JSONB instead of normalized tables:
* * Immutability: Order data should never change, even if user updates profile
* * Flexibility: Can store varying address formats without schema changes
* * Performance: Avoids complex joins for order history queries
* * Simplicity: Reduces number of tables and foreign key constraints
* - PostgreSQL JSONB provides efficient indexing and query capabilities if needed
*
* 3. Decimal Types for Money:
* - All price and amount fields use decimal(10, 2) - exact precision with 2 decimal places
* - Why not float/double:
* * Floating-point arithmetic has rounding errors (0.1 + 0.2 ≠ 0.3)
* * Financial calculations require exact precision for legal/tax compliance
* * Example: €19.99 * 3 = €59.97 exactly (not €59.970000000001)
* - precision: 10 allows up to €99,999,999.99 (sufficient for individual orders)
* - Note: When sending to X-API/NAV ERP, convert to cents (integer) to avoid precision loss
*
* 4. Timestamps for Audit Trail:
* - Every table has created_at (when record was created)
* - Most tables have updated_at (last modification time)
* - Benefits:
* * Debugging: Track when issues occurred
* * Analytics: Understand user behavior patterns
* * Compliance: Required for financial record-keeping
* * Data integrity: Detect stale or corrupted data
* - Implementation: Using PostgreSQL's timestamp with timezone (timestamptz)
*
* 5. Foreign Key Constraints:
* - onDelete: 'cascade' - Deleting parent removes children (e.g., cart → cart_items)
* - onDelete: 'restrict' - Prevent deletion if children exist (e.g., user with orders)
* - Ensures referential integrity at database level (not just application logic)
*
* 6. Indexes for Query Performance:
* - Strategic indexes on frequently queried columns:
* * products: nav_product_id, active, category (ERP sync, filtering)
* * orders: order_number (lookup), user_id (user history), status (admin filtering)
* - Trade-off: Faster reads, slightly slower writes (acceptable for e-commerce)
*
* 7. Enums for Type Safety:
* - PostgreSQL enums for status fields (salutation, order_status)
* - Benefits:
* * Database-level validation (prevents invalid values)
* * Type safety in TypeScript (via Drizzle inference)
* * Self-documenting code (clear set of valid values)
* - Note: Adding new enum values requires migration (ALTER TYPE)
*/
import { relations } from 'drizzle-orm'
import {
boolean,
decimal,
index,
integer,
jsonb,
pgEnum,
pgTable,
text,
timestamp,
uuid,
} from 'drizzle-orm/pg-core'
/**
* Enums
*/
// User salutation options
export const salutationEnum = pgEnum('salutation', ['male', 'female', 'other'])
// Order status lifecycle
export const orderStatusEnum = pgEnum('order_status', [
'pending',
'paid',
'processing',
'completed',
'failed',
])
/**
* Users Table
* Stores local user profiles linked to Cidaas authentication
*/
export const users = pgTable('users', {
id: uuid('id').primaryKey().defaultRandom(),
experimentaId: text('experimenta_id').unique().notNull(), // Cidaas sub (user ID)
email: text('email').notNull(),
firstName: text('first_name').notNull(),
lastName: text('last_name').notNull(),
// Optional profile fields
salutation: salutationEnum('salutation'),
dateOfBirth: timestamp('date_of_birth', { mode: 'date' }),
phone: text('phone'),
// Billing address fields (optional, filled during checkout or profile edit)
street: text('street'),
postCode: text('post_code'),
city: text('city'),
countryCode: text('country_code'), // ISO 3166-1 alpha-2 (e.g., 'DE', 'AT')
createdAt: timestamp('created_at').defaultNow().notNull(),
updatedAt: timestamp('updated_at').defaultNow().notNull(),
})
/**
* Products Table
* Synced from NAV ERP via push API
*/
export const products = pgTable(
'products',
{
id: uuid('id').primaryKey().defaultRandom(),
navProductId: text('nav_product_id').unique().notNull(), // NAV ERP product identifier
name: text('name').notNull(),
description: text('description').notNull(),
price: decimal('price', { precision: 10, scale: 2 }).notNull(), // EUR with 2 decimal places
stockQuantity: integer('stock_quantity').notNull().default(0),
category: text('category').notNull(), // e.g., 'makerspace-annual-pass'
active: boolean('active').notNull().default(true), // Whether product is available for purchase
createdAt: timestamp('created_at').defaultNow().notNull(),
updatedAt: timestamp('updated_at').defaultNow().notNull(),
},
(table) => ({
navProductIdIdx: index('products_nav_product_id_idx').on(table.navProductId),
activeIdx: index('products_active_idx').on(table.active),
categoryIdx: index('products_category_idx').on(table.category),
})
)
/**
* Carts Table
* Shopping carts for both authenticated and guest users
*/
export const carts = pgTable('carts', {
id: uuid('id').primaryKey().defaultRandom(),
userId: uuid('user_id').references(() => users.id, { onDelete: 'cascade' }), // null for guest carts
sessionId: text('session_id').notNull(), // Browser session identifier for guest carts
createdAt: timestamp('created_at').defaultNow().notNull(),
updatedAt: timestamp('updated_at').defaultNow().notNull(),
})
/**
* Cart Items Table
* Individual line items in a shopping cart
*/
export const cartItems = pgTable('cart_items', {
id: uuid('id').primaryKey().defaultRandom(),
cartId: uuid('cart_id')
.notNull()
.references(() => carts.id, { onDelete: 'cascade' }),
productId: uuid('product_id')
.notNull()
.references(() => products.id, { onDelete: 'restrict' }), // Don't allow deleting products with cart items
quantity: integer('quantity').notNull().default(1),
addedAt: timestamp('added_at').defaultNow().notNull(),
})
/**
* Orders Table
* Completed orders submitted to NAV ERP via X-API
*/
export const orders = pgTable(
'orders',
{
id: uuid('id').primaryKey().defaultRandom(),
orderNumber: text('order_number').unique().notNull(), // Human-readable order number (e.g., 'EXP-2024-001234')
userId: uuid('user_id')
.notNull()
.references(() => users.id, { onDelete: 'restrict' }), // Don't allow deleting users with orders
totalAmount: decimal('total_amount', { precision: 10, scale: 2 }).notNull(), // EUR with 2 decimal places
status: orderStatusEnum('status').notNull().default('pending'),
// Billing address snapshot at time of order
billingAddress: jsonb('billing_address').notNull(), // { street, postCode, city, countryCode, salutation, firstName, lastName }
// Payment information
paymentId: text('payment_id'), // PayPal transaction ID
paymentCompletedAt: timestamp('payment_completed_at'),
createdAt: timestamp('created_at').defaultNow().notNull(),
updatedAt: timestamp('updated_at').defaultNow().notNull(),
},
(table) => ({
orderNumberIdx: index('orders_order_number_idx').on(table.orderNumber),
userIdIdx: index('orders_user_id_idx').on(table.userId),
statusIdx: index('orders_status_idx').on(table.status),
})
)
/**
* Order Items Table
* Individual line items in an order with product snapshot
*/
export const orderItems = pgTable('order_items', {
id: uuid('id').primaryKey().defaultRandom(),
orderId: uuid('order_id')
.notNull()
.references(() => orders.id, { onDelete: 'cascade' }),
productId: uuid('product_id')
.notNull()
.references(() => products.id, { onDelete: 'restrict' }), // Don't allow deleting products with order items
productSnapshot: jsonb('product_snapshot').notNull(), // Immutable product details at time of purchase { name, description, navProductId }
quantity: integer('quantity').notNull().default(1),
priceSnapshot: decimal('price_snapshot', { precision: 10, scale: 2 }).notNull(), // Price at time of purchase
createdAt: timestamp('created_at').defaultNow().notNull(),
})
/**
* Relations
* Define table relationships for Drizzle's relational query API
*/
export const usersRelations = relations(users, ({ many }) => ({
carts: many(carts),
orders: many(orders),
}))
export const cartsRelations = relations(carts, ({ one, many }) => ({
user: one(users, {
fields: [carts.userId],
references: [users.id],
}),
items: many(cartItems),
}))
export const cartItemsRelations = relations(cartItems, ({ one }) => ({
cart: one(carts, {
fields: [cartItems.cartId],
references: [carts.id],
}),
product: one(products, {
fields: [cartItems.productId],
references: [products.id],
}),
}))
export const ordersRelations = relations(orders, ({ one, many }) => ({
user: one(users, {
fields: [orders.userId],
references: [users.id],
}),
items: many(orderItems),
}))
export const orderItemsRelations = relations(orderItems, ({ one }) => ({
order: one(orders, {
fields: [orderItems.orderId],
references: [orders.id],
}),
product: one(products, {
fields: [orderItems.productId],
references: [products.id],
}),
}))
export const productsRelations = relations(products, ({ many }) => ({
cartItems: many(cartItems),
orderItems: many(orderItems),
}))