forked from syntaxbullet/AuroraBot-discord
refactor: initial moves
This commit is contained in:
13
shared/db/DrizzleClient.ts
Normal file
13
shared/db/DrizzleClient.ts
Normal file
@@ -0,0 +1,13 @@
|
||||
import { drizzle } from "drizzle-orm/bun-sql";
|
||||
import { SQL } from "bun";
|
||||
import * as schema from "./schema";
|
||||
import { env } from "@shared/lib/env";
|
||||
|
||||
const connectionString = env.DATABASE_URL;
|
||||
export const postgres = new SQL(connectionString);
|
||||
|
||||
export const DrizzleClient = drizzle(postgres, { schema });
|
||||
|
||||
export const closeDatabase = async () => {
|
||||
await postgres.close();
|
||||
};
|
||||
43
shared/db/indexes.test.ts
Normal file
43
shared/db/indexes.test.ts
Normal file
@@ -0,0 +1,43 @@
|
||||
import { expect, test, describe } from "bun:test";
|
||||
import { postgres } from "./DrizzleClient";
|
||||
|
||||
describe("Database Indexes", () => {
|
||||
test("should have indexes on users table", async () => {
|
||||
const result = await postgres`
|
||||
SELECT indexname FROM pg_indexes
|
||||
WHERE tablename = 'users'
|
||||
`;
|
||||
const indexNames = (result as unknown as { indexname: string }[]).map(r => r.indexname);
|
||||
expect(indexNames).toContain("users_balance_idx");
|
||||
expect(indexNames).toContain("users_level_xp_idx");
|
||||
});
|
||||
|
||||
test("should have index on transactions table", async () => {
|
||||
const result = await postgres`
|
||||
SELECT indexname FROM pg_indexes
|
||||
WHERE tablename = 'transactions'
|
||||
`;
|
||||
const indexNames = (result as unknown as { indexname: string }[]).map(r => r.indexname);
|
||||
expect(indexNames).toContain("transactions_created_at_idx");
|
||||
});
|
||||
|
||||
test("should have indexes on moderation_cases table", async () => {
|
||||
const result = await postgres`
|
||||
SELECT indexname FROM pg_indexes
|
||||
WHERE tablename = 'moderation_cases'
|
||||
`;
|
||||
const indexNames = (result as unknown as { indexname: string }[]).map(r => r.indexname);
|
||||
expect(indexNames).toContain("moderation_cases_user_id_idx");
|
||||
expect(indexNames).toContain("moderation_cases_case_id_idx");
|
||||
});
|
||||
|
||||
test("should have indexes on user_timers table", async () => {
|
||||
const result = await postgres`
|
||||
SELECT indexname FROM pg_indexes
|
||||
WHERE tablename = 'user_timers'
|
||||
`;
|
||||
const indexNames = (result as unknown as { indexname: string }[]).map(r => r.indexname);
|
||||
expect(indexNames).toContain("user_timers_expires_at_idx");
|
||||
expect(indexNames).toContain("user_timers_lookup_idx");
|
||||
});
|
||||
});
|
||||
264
shared/db/schema.ts
Normal file
264
shared/db/schema.ts
Normal file
@@ -0,0 +1,264 @@
|
||||
import {
|
||||
pgTable,
|
||||
bigint,
|
||||
varchar,
|
||||
boolean,
|
||||
jsonb,
|
||||
timestamp,
|
||||
serial,
|
||||
text,
|
||||
integer,
|
||||
primaryKey,
|
||||
index,
|
||||
bigserial,
|
||||
check
|
||||
} from 'drizzle-orm/pg-core';
|
||||
import { relations, sql } from 'drizzle-orm';
|
||||
|
||||
// --- TABLES ---
|
||||
|
||||
// 1. Classes
|
||||
export const classes = pgTable('classes', {
|
||||
id: bigint('id', { mode: 'bigint' }).primaryKey(),
|
||||
name: varchar('name', { length: 255 }).unique().notNull(),
|
||||
balance: bigint('balance', { mode: 'bigint' }).default(0n),
|
||||
roleId: varchar('role_id', { length: 255 }),
|
||||
});
|
||||
|
||||
// 2. Users
|
||||
export const users = pgTable('users', {
|
||||
id: bigint('id', { mode: 'bigint' }).primaryKey(),
|
||||
classId: bigint('class_id', { mode: 'bigint' }).references(() => classes.id),
|
||||
username: varchar('username', { length: 255 }).unique().notNull(),
|
||||
isActive: boolean('is_active').default(true),
|
||||
|
||||
// Economy
|
||||
balance: bigint('balance', { mode: 'bigint' }).default(0n),
|
||||
xp: bigint('xp', { mode: 'bigint' }).default(0n),
|
||||
level: integer('level').default(1),
|
||||
dailyStreak: integer('daily_streak').default(0),
|
||||
|
||||
// Metadata
|
||||
settings: jsonb('settings').default({}),
|
||||
createdAt: timestamp('created_at', { withTimezone: true }).defaultNow(),
|
||||
updatedAt: timestamp('updated_at', { withTimezone: true }).defaultNow(),
|
||||
}, (table) => [
|
||||
index('users_username_idx').on(table.username),
|
||||
index('users_balance_idx').on(table.balance),
|
||||
index('users_level_xp_idx').on(table.level, table.xp),
|
||||
]);
|
||||
|
||||
// 3. Items
|
||||
export const items = pgTable('items', {
|
||||
id: serial('id').primaryKey(),
|
||||
name: varchar('name', { length: 255 }).unique().notNull(),
|
||||
description: text('description'),
|
||||
rarity: varchar('rarity', { length: 20 }).default('Common'),
|
||||
|
||||
// Economy & Visuals
|
||||
type: varchar('type', { length: 50 }).notNull().default('MATERIAL'),
|
||||
// Examples: 'CONSUMABLE', 'EQUIPMENT', 'MATERIAL'
|
||||
usageData: jsonb('usage_data').default({}),
|
||||
price: bigint('price', { mode: 'bigint' }),
|
||||
iconUrl: text('icon_url').notNull(),
|
||||
imageUrl: text('image_url').notNull(),
|
||||
});
|
||||
|
||||
// 4. Inventory (Join Table)
|
||||
export const inventory = pgTable('inventory', {
|
||||
userId: bigint('user_id', { mode: 'bigint' })
|
||||
.references(() => users.id, { onDelete: 'cascade' }).notNull(),
|
||||
itemId: integer('item_id')
|
||||
.references(() => items.id, { onDelete: 'cascade' }).notNull(),
|
||||
quantity: bigint('quantity', { mode: 'bigint' }).default(1n),
|
||||
}, (table) => [
|
||||
primaryKey({ columns: [table.userId, table.itemId] }),
|
||||
check('quantity_check', sql`${table.quantity} > 0`)
|
||||
]);
|
||||
|
||||
// 5. Transactions
|
||||
export const transactions = pgTable('transactions', {
|
||||
id: bigserial('id', { mode: 'bigint' }).primaryKey(),
|
||||
userId: bigint('user_id', { mode: 'bigint' })
|
||||
.references(() => users.id, { onDelete: 'cascade' }),
|
||||
relatedUserId: bigint('related_user_id', { mode: 'bigint' })
|
||||
.references(() => users.id, { onDelete: 'set null' }),
|
||||
amount: bigint('amount', { mode: 'bigint' }).notNull(),
|
||||
type: varchar('type', { length: 50 }).notNull(),
|
||||
description: text('description'),
|
||||
createdAt: timestamp('created_at', { withTimezone: true }).defaultNow(),
|
||||
}, (table) => [
|
||||
index('transactions_created_at_idx').on(table.createdAt),
|
||||
]);
|
||||
|
||||
export const itemTransactions = pgTable('item_transactions', {
|
||||
id: bigserial('id', { mode: 'bigint' }).primaryKey(),
|
||||
userId: bigint('user_id', { mode: 'bigint' })
|
||||
.references(() => users.id, { onDelete: 'cascade' }).notNull(),
|
||||
relatedUserId: bigint('related_user_id', { mode: 'bigint' })
|
||||
.references(() => users.id, { onDelete: 'set null' }), // who they got it from/gave it to
|
||||
itemId: integer('item_id')
|
||||
.references(() => items.id, { onDelete: 'cascade' }).notNull(),
|
||||
quantity: bigint('quantity', { mode: 'bigint' }).notNull(), // positive = gain, negative = loss
|
||||
type: varchar('type', { length: 50 }).notNull(), // e.g., 'TRADE', 'SHOP_BUY', 'DROP'
|
||||
description: text('description'),
|
||||
createdAt: timestamp('created_at', { withTimezone: true }).defaultNow(),
|
||||
});
|
||||
|
||||
// 6. Quests
|
||||
export const quests = pgTable('quests', {
|
||||
id: serial('id').primaryKey(),
|
||||
name: varchar('name', { length: 255 }).notNull(),
|
||||
description: text('description'),
|
||||
triggerEvent: varchar('trigger_event', { length: 50 }).notNull(),
|
||||
requirements: jsonb('requirements').notNull().default({}),
|
||||
rewards: jsonb('rewards').notNull().default({}),
|
||||
});
|
||||
|
||||
// 7. User Quests (Join Table)
|
||||
export const userQuests = pgTable('user_quests', {
|
||||
userId: bigint('user_id', { mode: 'bigint' })
|
||||
.references(() => users.id, { onDelete: 'cascade' }).notNull(),
|
||||
questId: integer('quest_id')
|
||||
.references(() => quests.id, { onDelete: 'cascade' }).notNull(),
|
||||
progress: integer('progress').default(0),
|
||||
completedAt: timestamp('completed_at', { withTimezone: true }),
|
||||
}, (table) => [
|
||||
primaryKey({ columns: [table.userId, table.questId] })
|
||||
]);
|
||||
|
||||
// 8. User Timers (Generic: Cooldowns, Effects, Access)
|
||||
export const userTimers = pgTable('user_timers', {
|
||||
userId: bigint('user_id', { mode: 'bigint' })
|
||||
.references(() => users.id, { onDelete: 'cascade' }).notNull(),
|
||||
type: varchar('type', { length: 50 }).notNull(), // 'COOLDOWN', 'EFFECT', 'ACCESS'
|
||||
key: varchar('key', { length: 100 }).notNull(), // 'daily', 'chn_12345', 'xp_boost'
|
||||
expiresAt: timestamp('expires_at', { withTimezone: true }).notNull(),
|
||||
metadata: jsonb('metadata').default({}), // Store channelId, specific buff amounts, etc.
|
||||
}, (table) => [
|
||||
primaryKey({ columns: [table.userId, table.type, table.key] }),
|
||||
index('user_timers_expires_at_idx').on(table.expiresAt),
|
||||
index('user_timers_lookup_idx').on(table.userId, table.type, table.key),
|
||||
]);
|
||||
// 9. Lootdrops
|
||||
export const lootdrops = pgTable('lootdrops', {
|
||||
messageId: varchar('message_id', { length: 255 }).primaryKey(),
|
||||
channelId: varchar('channel_id', { length: 255 }).notNull(),
|
||||
rewardAmount: integer('reward_amount').notNull(),
|
||||
currency: varchar('currency', { length: 50 }).notNull(),
|
||||
claimedBy: bigint('claimed_by', { mode: 'bigint' }).references(() => users.id, { onDelete: 'set null' }),
|
||||
createdAt: timestamp('created_at', { withTimezone: true }).defaultNow().notNull(),
|
||||
expiresAt: timestamp('expires_at', { withTimezone: true }),
|
||||
});
|
||||
|
||||
// 10. Moderation Cases
|
||||
export const moderationCases = pgTable('moderation_cases', {
|
||||
id: bigserial('id', { mode: 'bigint' }).primaryKey(),
|
||||
caseId: varchar('case_id', { length: 50 }).unique().notNull(),
|
||||
type: varchar('type', { length: 20 }).notNull(), // 'warn', 'timeout', 'kick', 'ban', 'note', 'prune'
|
||||
userId: bigint('user_id', { mode: 'bigint' }).notNull(),
|
||||
username: varchar('username', { length: 255 }).notNull(),
|
||||
moderatorId: bigint('moderator_id', { mode: 'bigint' }).notNull(),
|
||||
moderatorName: varchar('moderator_name', { length: 255 }).notNull(),
|
||||
reason: text('reason').notNull(),
|
||||
metadata: jsonb('metadata').default({}),
|
||||
active: boolean('active').default(true).notNull(),
|
||||
createdAt: timestamp('created_at', { withTimezone: true }).defaultNow().notNull(),
|
||||
resolvedAt: timestamp('resolved_at', { withTimezone: true }),
|
||||
resolvedBy: bigint('resolved_by', { mode: 'bigint' }),
|
||||
resolvedReason: text('resolved_reason'),
|
||||
}, (table) => [
|
||||
index('moderation_cases_user_id_idx').on(table.userId),
|
||||
index('moderation_cases_case_id_idx').on(table.caseId),
|
||||
]);
|
||||
|
||||
|
||||
|
||||
export const classesRelations = relations(classes, ({ many }) => ({
|
||||
users: many(users),
|
||||
}));
|
||||
|
||||
export const usersRelations = relations(users, ({ one, many }) => ({
|
||||
class: one(classes, {
|
||||
fields: [users.classId],
|
||||
references: [classes.id],
|
||||
}),
|
||||
inventory: many(inventory),
|
||||
transactions: many(transactions),
|
||||
quests: many(userQuests),
|
||||
timers: many(userTimers),
|
||||
}));
|
||||
|
||||
export const itemsRelations = relations(items, ({ many }) => ({
|
||||
inventoryEntries: many(inventory),
|
||||
}));
|
||||
|
||||
export const inventoryRelations = relations(inventory, ({ one }) => ({
|
||||
user: one(users, {
|
||||
fields: [inventory.userId],
|
||||
references: [users.id],
|
||||
}),
|
||||
item: one(items, {
|
||||
fields: [inventory.itemId],
|
||||
references: [items.id],
|
||||
}),
|
||||
}));
|
||||
|
||||
export const transactionsRelations = relations(transactions, ({ one }) => ({
|
||||
user: one(users, {
|
||||
fields: [transactions.userId],
|
||||
references: [users.id],
|
||||
}),
|
||||
}));
|
||||
|
||||
export const questsRelations = relations(quests, ({ many }) => ({
|
||||
userEntries: many(userQuests),
|
||||
}));
|
||||
|
||||
export const userQuestsRelations = relations(userQuests, ({ one }) => ({
|
||||
user: one(users, {
|
||||
fields: [userQuests.userId],
|
||||
references: [users.id],
|
||||
}),
|
||||
quest: one(quests, {
|
||||
fields: [userQuests.questId],
|
||||
references: [quests.id],
|
||||
}),
|
||||
}));
|
||||
|
||||
export const userTimersRelations = relations(userTimers, ({ one }) => ({
|
||||
user: one(users, {
|
||||
fields: [userTimers.userId],
|
||||
references: [users.id],
|
||||
}),
|
||||
}));
|
||||
|
||||
export const itemTransactionsRelations = relations(itemTransactions, ({ one }) => ({
|
||||
user: one(users, {
|
||||
fields: [itemTransactions.userId],
|
||||
references: [users.id],
|
||||
}),
|
||||
relatedUser: one(users, {
|
||||
fields: [itemTransactions.relatedUserId],
|
||||
references: [users.id],
|
||||
}),
|
||||
item: one(items, {
|
||||
fields: [itemTransactions.itemId],
|
||||
references: [items.id],
|
||||
}),
|
||||
}));
|
||||
|
||||
export const moderationCasesRelations = relations(moderationCases, ({ one }) => ({
|
||||
user: one(users, {
|
||||
fields: [moderationCases.userId],
|
||||
references: [users.id],
|
||||
}),
|
||||
moderator: one(users, {
|
||||
fields: [moderationCases.moderatorId],
|
||||
references: [users.id],
|
||||
}),
|
||||
resolver: one(users, {
|
||||
fields: [moderationCases.resolvedBy],
|
||||
references: [users.id],
|
||||
}),
|
||||
}));
|
||||
Reference in New Issue
Block a user