telegram-shop/src/config/database.js
2024-11-15 02:26:13 +03:00

272 lines
8.1 KiB
JavaScript

import sqlite3 from 'sqlite3';
import { promisify } from 'util';
import { dirname } from 'path';
import { fileURLToPath } from 'url';
const __dirname = dirname(fileURLToPath(import.meta.url));
const DB_PATH = new URL('../../db/shop.db', import.meta.url).pathname;
// Create database with verbose mode for better error reporting
const db = new sqlite3.Database(DB_PATH, sqlite3.OPEN_CREATE | sqlite3.OPEN_READWRITE, (err) => {
if (err) {
console.error('Database connection error:', err);
process.exit(1);
}
console.log('Connected to SQLite database');
});
// Enable foreign keys
db.run('PRAGMA foreign_keys = ON');
// Promisify database operations
const runAsync = (sql, params = []) => {
return new Promise((resolve, reject) => {
db.run(sql, params, function(err) {
if (err) reject(err);
else resolve(this);
});
});
};
const allAsync = (sql, params = []) => {
return new Promise((resolve, reject) => {
db.all(sql, params, (err, rows) => {
if (err) reject(err);
else resolve(rows);
});
});
};
const getAsync = (sql, params = []) => {
return new Promise((resolve, reject) => {
db.get(sql, params, (err, row) => {
if (err) reject(err);
else resolve(row);
});
});
};
// Attach async methods to db object
db.runAsync = runAsync;
db.allAsync = allAsync;
db.getAsync = getAsync;
// Function to check if a column exists in a table
const checkColumnExists = async (tableName, columnName) => {
try {
const result = await db.allAsync(`
PRAGMA table_info(${tableName})
`);
return result.some(column => column.name === columnName);
} catch (error) {
console.error(`Error checking column ${columnName} in table ${tableName}:`, error);
return false;
}
};
// Function to clean up invalid foreign key references
const cleanUpInvalidForeignKeys = async () => {
try {
// Clean up invalid foreign key references in crypto_wallets table
await db.runAsync(`
DELETE FROM crypto_wallets
WHERE user_id NOT IN (SELECT id FROM users)
`);
console.log('Cleaned up invalid foreign key references in crypto_wallets table');
} catch (error) {
console.error('Error cleaning up invalid foreign key references:', error);
}
};
// Initialize database tables
const initDb = async () => {
try {
// Begin transaction for table creation
await db.runAsync('BEGIN TRANSACTION');
// Create users table
await db.runAsync(`
CREATE TABLE IF NOT EXISTS users (
id INTEGER PRIMARY KEY AUTOINCREMENT,
telegram_id TEXT UNIQUE NOT NULL,
username TEXT,
country TEXT,
city TEXT,
district TEXT,
status INTEGER DEFAULT 0,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
)
`);
// Create crypto_wallets table
await db.runAsync(`
CREATE TABLE IF NOT EXISTS crypto_wallets (
id INTEGER PRIMARY KEY AUTOINCREMENT,
user_id INTEGER NOT NULL,
wallet_type TEXT NOT NULL,
address TEXT NOT NULL,
derivation_path TEXT NOT NULL,
encrypted_mnemonic TEXT NOT NULL,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
UNIQUE(user_id, wallet_type)
)
`);
// Create transactions table
await db.runAsync(`
CREATE TABLE IF NOT EXISTS transactions (
id INTEGER PRIMARY KEY AUTOINCREMENT,
user_id INTEGER NOT NULL,
wallet_type TEXT NOT NULL,
tx_hash TEXT NOT NULL,
amount REAL NOT NULL,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
)
`);
// Check if user_id column exists in transactions table
const user_idExists = await checkColumnExists('transactions', 'user_id');
if (!user_idExists) {
await db.runAsync(`
ALTER TABLE transactions
ADD COLUMN user_id INTEGER NOT NULL
`);
console.log('Column user_id added to transactions table');
}
// Check if wallet_type column exists in transactions table
const wallet_typeExists = await checkColumnExists('transactions', 'wallet_type');
if (!wallet_typeExists) {
await db.runAsync(`
ALTER TABLE transactions
ADD COLUMN wallet_type TEXT NOT NULL
`);
console.log('Column wallet_type added to transactions table');
}
// Check if tx_hash column exists in transactions table
const tx_hashExists = await checkColumnExists('transactions', 'tx_hash');
if (!tx_hashExists) {
await db.runAsync(`
ALTER TABLE transactions
ADD COLUMN tx_hash TEXT NOT NULL
`);
console.log('Column tx_hash added to transactions table');
}
// Create products table
await db.runAsync(`
CREATE TABLE IF NOT EXISTS products (
id INTEGER PRIMARY KEY AUTOINCREMENT,
location_id INTEGER NOT NULL,
category_id INTEGER NOT NULL,
subcategory_id INTEGER NOT NULL,
name TEXT NOT NULL,
description TEXT,
private_data TEXT,
price REAL NOT NULL CHECK (price > 0),
quantity_in_stock INTEGER DEFAULT 0 CHECK (quantity_in_stock >= 0),
photo_url TEXT,
hidden_photo_url TEXT,
hidden_coordinates TEXT,
hidden_description TEXT,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (location_id) REFERENCES locations(id) ON DELETE CASCADE,
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
FOREIGN KEY (subcategory_id) REFERENCES subcategories(id) ON DELETE CASCADE
)
`);
// Create purchases table
await db.runAsync(`
CREATE TABLE IF NOT EXISTS purchases (
id INTEGER PRIMARY KEY AUTOINCREMENT,
user_id INTEGER NOT NULL,
product_id INTEGER NOT NULL,
wallet_type TEXT NOT NULL,
tx_hash TEXT NOT NULL,
quantity INTEGER NOT NULL CHECK (quantity > 0),
total_price REAL NOT NULL CHECK (total_price > 0),
purchase_date DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
FOREIGN KEY (product_id) REFERENCES products(id) ON DELETE CASCADE
)
`);
// Create locations table
await db.runAsync(`
CREATE TABLE IF NOT EXISTS locations (
id INTEGER PRIMARY KEY AUTOINCREMENT,
country TEXT NOT NULL,
city TEXT NOT NULL,
district TEXT NOT NULL,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
UNIQUE(country, city, district)
)
`);
// Create categories table
await db.runAsync(`
CREATE TABLE IF NOT EXISTS categories (
id INTEGER PRIMARY KEY AUTOINCREMENT,
location_id INTEGER NOT NULL,
name TEXT NOT NULL,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (location_id) REFERENCES locations(id) ON DELETE CASCADE,
UNIQUE(location_id, name)
)
`);
// Create subcategories table
await db.runAsync(`
CREATE TABLE IF NOT EXISTS subcategories (
id INTEGER PRIMARY KEY AUTOINCREMENT,
category_id INTEGER NOT NULL,
name TEXT NOT NULL,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (category_id) REFERENCES categories(id) ON DELETE CASCADE,
UNIQUE(category_id, name)
)
`);
// Commit transaction
await db.runAsync('COMMIT');
console.log('Database tables initialized successfully');
} catch (error) {
// Rollback transaction on error
await db.runAsync('ROLLBACK');
console.error('Error initializing database tables:', error);
throw error;
}
};
// Initialize the database
(async () => {
await initDb();
await cleanUpInvalidForeignKeys();
})().catch(error => {
console.error('Database initialization failed:', error);
process.exit(1);
});
// Handle database errors
db.on('error', (err) => {
console.error('Database error:', err);
});
// Handle process termination
process.on('SIGINT', () => {
db.close((err) => {
if (err) {
console.error('Error closing database:', err);
} else {
console.log('Database connection closed');
}
process.exit(err ? 1 : 0);
});
});
export default db;