migrate from SQLite to PostgreSQL with Drizzle ORM

- Updated all packages to latest versions (React 19, Next.js 14.2.32)
- Replaced sqlite3 with pg and drizzle-orm dependencies
- Created complete PostgreSQL schema with relationships and indexes
- Migrated all API endpoints from SQLite to Drizzle queries
- Added database seeding with sample data
- Updated authentication to use bcrypt instead of pbkdf2
- Configured connection pooling for PostgreSQL
- Updated app version to 1.0.0
- All endpoints tested and working correctly
This commit is contained in:
2025-09-06 12:56:33 +02:00
parent 52bde64e7f
commit 860070a302
26 changed files with 2526 additions and 2403 deletions

228
lib/db/schema.ts Normal file
View File

@@ -0,0 +1,228 @@
import {
pgTable,
serial,
varchar,
text,
boolean,
integer,
timestamp,
decimal,
pgEnum,
uniqueIndex,
index
} from 'drizzle-orm/pg-core';
import { relations } from 'drizzle-orm';
// Enums
export const roleEnum = pgEnum('role', ['admin', 'moderator']);
export const sourceTypeEnum = pgEnum('source_type', [
'website', 'facebook_page', 'facebook_group', 'instagram',
'blog', 'news_site', 'youtube', 'tiktok', 'telegram', 'other'
]);
export const sourceStatusEnum = pgEnum('source_status', [
'pending', 'verified', 'rejected', 'under_review'
]);
export const languageEnum = pgEnum('language', ['sk', 'cs', 'en', 'other']);
export const priorityEnum = pgEnum('priority', ['low', 'medium', 'high', 'urgent']);
export const reportStatusEnum = pgEnum('report_status', [
'pending', 'in_review', 'approved', 'rejected', 'duplicate'
]);
// Users table
export const users = pgTable('users', {
id: serial('id').primaryKey(),
email: varchar('email', { length: 255 }).notNull().unique(),
passwordHash: varchar('password_hash', { length: 255 }).notNull(),
name: varchar('name', { length: 100 }).notNull(),
role: roleEnum('role').default('moderator'),
isActive: boolean('is_active').default(true),
lastLogin: timestamp('last_login'),
createdAt: timestamp('created_at').defaultNow(),
updatedAt: timestamp('updated_at').defaultNow()
});
// Categories table
export const categories = pgTable('categories', {
id: serial('id').primaryKey(),
name: varchar('name', { length: 100 }).notNull().unique(),
slug: varchar('slug', { length: 100 }).notNull().unique(),
description: text('description'),
color: varchar('color', { length: 7 }).default('#6B7280'),
priority: integer('priority').default(1),
icon: varchar('icon', { length: 50 }),
isActive: boolean('is_active').default(true),
createdAt: timestamp('created_at').defaultNow(),
updatedAt: timestamp('updated_at').defaultNow()
}, (table) => {
return {
slugIdx: uniqueIndex('idx_categories_slug').on(table.slug),
priorityIdx: index('idx_categories_priority').on(table.priority)
};
});
// Sources table
export const sources = pgTable('sources', {
id: serial('id').primaryKey(),
url: varchar('url', { length: 1000 }).notNull().unique(),
domain: varchar('domain', { length: 255 }).notNull(),
title: varchar('title', { length: 500 }),
description: text('description'),
type: sourceTypeEnum('type').notNull(),
status: sourceStatusEnum('status').default('pending'),
riskLevel: integer('risk_level').default(1),
language: languageEnum('language').default('sk'),
evidenceUrls: text('evidence_urls'), // JSON
reportedBy: varchar('reported_by', { length: 255 }),
verifiedBy: integer('verified_by').references(() => users.id),
rejectionReason: text('rejection_reason'),
followerCount: integer('follower_count').default(0),
lastChecked: timestamp('last_checked'),
metadata: text('metadata').default('{}'), // JSON
createdAt: timestamp('created_at').defaultNow(),
updatedAt: timestamp('updated_at').defaultNow()
}, (table) => {
return {
domainIdx: index('idx_sources_domain').on(table.domain),
statusIdx: index('idx_sources_status').on(table.status),
riskLevelIdx: index('idx_sources_risk_level').on(table.riskLevel),
typeIdx: index('idx_sources_type').on(table.type),
createdAtIdx: index('idx_sources_created_at').on(table.createdAt),
verifiedByIdx: index('idx_sources_verified_by').on(table.verifiedBy),
statusRiskIdx: index('idx_sources_status_risk').on(table.status, table.riskLevel)
};
});
// Source Categories junction table
export const sourceCategories = pgTable('source_categories', {
id: serial('id').primaryKey(),
sourceId: integer('source_id').notNull().references(() => sources.id, { onDelete: 'cascade' }),
categoryId: integer('category_id').notNull().references(() => categories.id, { onDelete: 'cascade' }),
confidenceScore: decimal('confidence_score', { precision: 3, scale: 2 }).default('1.0'),
addedBy: integer('added_by').references(() => users.id),
createdAt: timestamp('created_at').defaultNow()
}, (table) => {
return {
sourceIdIdx: index('idx_source_categories_source_id').on(table.sourceId),
categoryIdIdx: index('idx_source_categories_category_id').on(table.categoryId),
uniqueSourceCategory: uniqueIndex('unique_source_category').on(table.sourceId, table.categoryId)
};
});
// Reports table
export const reports = pgTable('reports', {
id: serial('id').primaryKey(),
sourceUrl: varchar('source_url', { length: 1000 }).notNull(),
sourceDomain: varchar('source_domain', { length: 255 }).notNull(),
reporterEmail: varchar('reporter_email', { length: 255 }),
reporterName: varchar('reporter_name', { length: 100 }),
categorySuggestions: text('category_suggestions'), // JSON
description: text('description').notNull(),
evidenceUrls: text('evidence_urls'), // JSON
priority: priorityEnum('priority').default('medium'),
status: reportStatusEnum('status').default('pending'),
assignedTo: integer('assigned_to').references(() => users.id),
adminNotes: text('admin_notes'),
processedAt: timestamp('processed_at'),
ipAddress: varchar('ip_address', { length: 45 }),
userAgent: text('user_agent'),
createdAt: timestamp('created_at').defaultNow(),
updatedAt: timestamp('updated_at').defaultNow()
}, (table) => {
return {
statusIdx: index('idx_reports_status').on(table.status),
sourceDomainIdx: index('idx_reports_source_domain').on(table.sourceDomain),
priorityIdx: index('idx_reports_priority').on(table.priority),
createdAtIdx: index('idx_reports_created_at').on(table.createdAt),
assignedToIdx: index('idx_reports_assigned_to').on(table.assignedTo)
};
});
// API Keys table
export const apiKeys = pgTable('api_keys', {
id: serial('id').primaryKey(),
keyHash: varchar('key_hash', { length: 255 }).notNull().unique(),
name: varchar('name', { length: 100 }).notNull(),
description: text('description'),
ownerEmail: varchar('owner_email', { length: 255 }).notNull(),
permissions: text('permissions').default('["read"]'), // JSON
rateLimit: integer('rate_limit').default(1000),
isActive: boolean('is_active').default(true),
usageCount: integer('usage_count').default(0),
lastUsed: timestamp('last_used'),
expiresAt: timestamp('expires_at'),
createdAt: timestamp('created_at').defaultNow(),
updatedAt: timestamp('updated_at').defaultNow()
}, (table) => {
return {
keyHashIdx: uniqueIndex('idx_api_keys_hash').on(table.keyHash),
ownerIdx: index('idx_api_keys_owner').on(table.ownerEmail)
};
});
// Audit Logs table
export const auditLogs = pgTable('audit_logs', {
id: serial('id').primaryKey(),
userId: integer('user_id').references(() => users.id),
action: varchar('action', { length: 50 }).notNull(),
resourceType: varchar('resource_type', { length: 50 }).notNull(),
resourceId: integer('resource_id'),
details: text('details'), // JSON
ipAddress: varchar('ip_address', { length: 45 }),
createdAt: timestamp('created_at').defaultNow()
}, (table) => {
return {
userIdIdx: index('idx_audit_logs_user_id').on(table.userId),
createdAtIdx: index('idx_audit_logs_created_at').on(table.createdAt),
actionIdx: index('idx_audit_logs_action').on(table.action),
resourceTypeIdx: index('idx_audit_logs_resource_type').on(table.resourceType)
};
});
// Relations
export const usersRelations = relations(users, ({ many }) => ({
verifiedSources: many(sources),
sourceCategories: many(sourceCategories),
assignedReports: many(reports),
auditLogs: many(auditLogs)
}));
export const categoriesRelations = relations(categories, ({ many }) => ({
sourceCategories: many(sourceCategories)
}));
export const sourcesRelations = relations(sources, ({ one, many }) => ({
verifiedBy: one(users, {
fields: [sources.verifiedBy],
references: [users.id]
}),
sourceCategories: many(sourceCategories)
}));
export const sourceCategoriesRelations = relations(sourceCategories, ({ one }) => ({
source: one(sources, {
fields: [sourceCategories.sourceId],
references: [sources.id]
}),
category: one(categories, {
fields: [sourceCategories.categoryId],
references: [categories.id]
}),
addedBy: one(users, {
fields: [sourceCategories.addedBy],
references: [users.id]
})
}));
export const reportsRelations = relations(reports, ({ one }) => ({
assignedTo: one(users, {
fields: [reports.assignedTo],
references: [users.id]
})
}));
export const auditLogsRelations = relations(auditLogs, ({ one }) => ({
user: one(users, {
fields: [auditLogs.userId],
references: [users.id]
})
}));