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:
278
server/database/schema.ts
Normal file
278
server/database/schema.ts
Normal 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),
|
||||
}))
|
||||
Reference in New Issue
Block a user