forked from wmantly/mc-bot-town
storage
This commit is contained in:
477
nodejs/controller/storage/database.js
Normal file
477
nodejs/controller/storage/database.js
Normal file
@@ -0,0 +1,477 @@
|
||||
'use strict';
|
||||
|
||||
const sqlite3 = require('sqlite3').verbose();
|
||||
const { open } = require('sqlite');
|
||||
const path = require('path');
|
||||
const fs = require('fs');
|
||||
|
||||
class Database {
|
||||
constructor() {
|
||||
this.db = null;
|
||||
}
|
||||
|
||||
async initialize(dbPath) {
|
||||
// Ensure directory exists
|
||||
const dir = path.dirname(dbPath);
|
||||
if (!fs.existsSync(dir)) {
|
||||
fs.mkdirSync(dir, { recursive: true });
|
||||
}
|
||||
|
||||
this.db = await open({
|
||||
filename: dbPath,
|
||||
driver: sqlite3.Database
|
||||
});
|
||||
|
||||
await this.createTables();
|
||||
await this.insertDefaultPermissions();
|
||||
|
||||
console.log('Database initialized:', dbPath);
|
||||
return this.db;
|
||||
}
|
||||
|
||||
async createTables() {
|
||||
// Permissions table
|
||||
await this.db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS permissions (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
player_name TEXT UNIQUE NOT NULL,
|
||||
role TEXT DEFAULT 'team' NOT NULL CHECK(role IN ('owner', 'team', 'readonly')),
|
||||
joined_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
)
|
||||
`);
|
||||
|
||||
// Chests table
|
||||
await this.db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS chests (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
pos_x INTEGER NOT NULL,
|
||||
pos_y INTEGER NOT NULL,
|
||||
pos_z INTEGER NOT NULL,
|
||||
chest_type TEXT NOT NULL CHECK(chest_type IN ('single', 'double')),
|
||||
row INTEGER NOT NULL,
|
||||
column INTEGER NOT NULL,
|
||||
category TEXT,
|
||||
last_scan TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(pos_x, pos_y, pos_z)
|
||||
)
|
||||
`);
|
||||
|
||||
// Shulkers table
|
||||
await this.db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS shulkers (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
chest_id INTEGER NOT NULL,
|
||||
slot INTEGER NOT NULL,
|
||||
shulker_type TEXT DEFAULT 'shulker_box',
|
||||
category TEXT,
|
||||
item_focus TEXT,
|
||||
slot_count INTEGER DEFAULT 27,
|
||||
total_items INTEGER DEFAULT 0,
|
||||
last_scan TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
FOREIGN KEY (chest_id) REFERENCES chests(id) ON DELETE CASCADE
|
||||
)
|
||||
`);
|
||||
|
||||
// Shulker items table
|
||||
await this.db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS shulker_items (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
shulker_id INTEGER NOT NULL,
|
||||
item_name TEXT NOT NULL,
|
||||
item_id INTEGER NOT NULL,
|
||||
slot INTEGER NOT NULL,
|
||||
count INTEGER NOT NULL,
|
||||
nbt_data TEXT,
|
||||
FOREIGN KEY (shulker_id) REFERENCES shulkers(id) ON DELETE CASCADE,
|
||||
UNIQUE(shulker_id, item_id),
|
||||
CHECK(slot >= 0 AND slot <= 26),
|
||||
CHECK(count > 0 AND count <= 64)
|
||||
)
|
||||
`);
|
||||
|
||||
// Trades table
|
||||
await this.db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS trades (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
player_name TEXT NOT NULL,
|
||||
action TEXT NOT NULL CHECK(action IN ('deposit', 'withdraw')),
|
||||
items TEXT NOT NULL,
|
||||
timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
)
|
||||
`);
|
||||
|
||||
// Pending withdrawals table
|
||||
await this.db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS pending_withdrawals (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
player_name TEXT NOT NULL,
|
||||
item_id INTEGER NOT NULL,
|
||||
item_name TEXT NOT NULL,
|
||||
requested_count INTEGER NOT NULL,
|
||||
status TEXT DEFAULT 'pending' CHECK(status IN ('pending', 'ready', 'completed', 'cancelled')),
|
||||
timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
)
|
||||
`);
|
||||
|
||||
// Item index for fast searches
|
||||
await this.db.exec(`
|
||||
CREATE TABLE IF NOT EXISTS item_index (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
item_id INTEGER UNIQUE NOT NULL,
|
||||
item_name TEXT NOT NULL,
|
||||
total_count INTEGER DEFAULT 0,
|
||||
shulker_ids TEXT,
|
||||
last_updated TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
)
|
||||
`);
|
||||
}
|
||||
|
||||
async insertDefaultPermissions() {
|
||||
const conf = require('../../conf');
|
||||
const defaultPlayers = conf.storage?.defaultPlayers || [];
|
||||
|
||||
for (const player of defaultPlayers) {
|
||||
try {
|
||||
await this.db.run(
|
||||
'INSERT OR IGNORE INTO permissions (player_name, role) VALUES (?, ?)',
|
||||
[player.name, player.role]
|
||||
);
|
||||
} catch (error) {
|
||||
console.error('Error inserting default player:', player.name, error);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
// ========================================
|
||||
// Permissions
|
||||
// ========================================
|
||||
|
||||
async addPlayer(name, Role = 'team') {
|
||||
return await this.db.run(
|
||||
'INSERT INTO permissions (player_name, role) VALUES (?, ?)',
|
||||
[name, Role]
|
||||
);
|
||||
}
|
||||
|
||||
async removePlayer(name) {
|
||||
return await this.db.run('DELETE FROM permissions WHERE player_name = ?', [name]);
|
||||
}
|
||||
|
||||
async getPlayerRole(name) {
|
||||
const row = await this.db.get('SELECT role FROM permissions WHERE player_name = ?', [name]);
|
||||
return row ? row.role : null;
|
||||
}
|
||||
|
||||
async getAllPlayers() {
|
||||
return await this.db.all('SELECT * FROM permissions ORDER BY role DESC, player_name ASC');
|
||||
}
|
||||
|
||||
async checkPermission(name, requiredRole) {
|
||||
const role = await this.getPlayerRole(name);
|
||||
if (!role) return false;
|
||||
|
||||
const roles = ['readonly', 'team', 'owner'];
|
||||
return roles.indexOf(role) >= roles.indexOf(requiredRole);
|
||||
}
|
||||
|
||||
// ========================================
|
||||
// Chests
|
||||
// ========================================
|
||||
|
||||
async upsertChest(x, y, z, chestType, row, column, category = null) {
|
||||
return await this.db.run(`
|
||||
INSERT INTO chests (pos_x, pos_y, pos_z, chest_type, row, column, category)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?)
|
||||
ON CONFLICT(pos_x, pos_y, pos_z) DO UPDATE SET
|
||||
chest_type = excluded.chest_type,
|
||||
row = excluded.row,
|
||||
column = excluded.column,
|
||||
category = excluded.category,
|
||||
last_scan = CURRENT_TIMESTAMP
|
||||
`, [x, y, z, chestType, row, column, category]);
|
||||
}
|
||||
|
||||
async getChests() {
|
||||
return await this.db.all('SELECT * FROM chests ORDER BY row, column');
|
||||
}
|
||||
|
||||
async getChestById(id) {
|
||||
return await this.db.get('SELECT * FROM chests WHERE id = ?', [id]);
|
||||
}
|
||||
|
||||
async getChestByPosition(x, y, z) {
|
||||
return await this.db.get(
|
||||
'SELECT * FROM chests WHERE pos_x = ? AND pos_y = ? AND pos_z = ?',
|
||||
[x, y, z]
|
||||
);
|
||||
}
|
||||
|
||||
async deleteOrphanChests(knownChestPositions) {
|
||||
// knownChestPositions is array of {x, y, z}
|
||||
if (knownChestPositions.length === 0) return;
|
||||
|
||||
const placeholders = knownChestPositions.map(() => '(?, ?, ?)').join(', ');
|
||||
const values = knownChestPositions.flatMap(p => [p.x, p.y, p.z]);
|
||||
|
||||
return await this.db.run(`
|
||||
DELETE FROM chests
|
||||
WHERE (pos_x, pos_y, pos_z) NOT IN (${placeholders})
|
||||
`, values);
|
||||
}
|
||||
|
||||
// ========================================
|
||||
// Shulkers
|
||||
// ========================================
|
||||
|
||||
async upsertShulker(chestId, slot, shulkerType, category = null, itemFocus = null) {
|
||||
const result = await this.db.run(`
|
||||
INSERT INTO shulkers (chest_id, slot, shulker_type, category, item_focus)
|
||||
VALUES (?, ?, ?, ?, ?)
|
||||
ON CONFLICT(id) DO UPDATE SET
|
||||
slot_count = excluded.slot_count,
|
||||
total_items = excluded.total_items,
|
||||
last_scan = CURRENT_TIMESTAMP
|
||||
`, [chestId, slot, shulkerType, category, itemFocus]);
|
||||
|
||||
return result.lastID;
|
||||
}
|
||||
|
||||
async getShulkersByChest(chestId) {
|
||||
return await this.db.all('SELECT * FROM shulkers WHERE chest_id = ? ORDER BY slot', [chestId]);
|
||||
}
|
||||
|
||||
async getAllShulkers() {
|
||||
return await this.db.all('SELECT * FROM shulkers ORDER BY id');
|
||||
}
|
||||
|
||||
async getShulkerById(id) {
|
||||
return await this.db.get('SELECT * FROM shulkers WHERE id = ?', [id]);
|
||||
}
|
||||
|
||||
async findShulkerForItem(itemId, categoryName) {
|
||||
// Find shulker with matching item and space
|
||||
return await this.db.get(`
|
||||
SELECT s.*, si.count as slot_item_count
|
||||
FROM shulkers s
|
||||
INNER JOIN shulker_items si ON s.id = si.shulker_id
|
||||
WHERE s.item_focus = (SELECT item_name FROM shulker_items WHERE item_id = ? LIMIT 1)
|
||||
AND s.category = ?
|
||||
AND s.slot_count < 27
|
||||
LIMIT 1
|
||||
`, [itemId, categoryName]);
|
||||
}
|
||||
|
||||
async createEmptyShulker(chestId, slot, categoryName, shulkerType = 'shulker_box') {
|
||||
return await this.db.run(`
|
||||
INSERT INTO shulkers (chest_id, slot, shulker_type, category, item_focus, slot_count, total_items)
|
||||
VALUES (?, ?, ?, ?, NULL, 0, 0)
|
||||
`, [chestId, slot, shulkerType, categoryName]);
|
||||
}
|
||||
|
||||
async updateShulkerCounts(shulkerId, slotCount, totalItems) {
|
||||
return await this.db.run(`
|
||||
UPDATE shulkers
|
||||
SET slot_count = ?, total_items = ?, last_scan = CURRENT_TIMESTAMP
|
||||
WHERE id = ?
|
||||
`, [slotCount, totalItems, shulkerId]);
|
||||
}
|
||||
|
||||
async deleteShulker(id) {
|
||||
return await this.db.run('DELETE FROM shulkers WHERE id = ?', [id]);
|
||||
}
|
||||
|
||||
// ========================================
|
||||
// Shulker Items
|
||||
// ========================================
|
||||
|
||||
async upsertShulkerItem(shulkerId, itemId, itemName, slot, count, nbt = null) {
|
||||
return await this.db.run(`
|
||||
INSERT INTO shulker_items (shulker_id, item_id, item_name, slot, count, nbt_data)
|
||||
VALUES (?, ?, ?, ?, ?, ?)
|
||||
ON CONFLICT(shulker_id, item_id) DO UPDATE SET
|
||||
slot = excluded.slot,
|
||||
count = excluded.count,
|
||||
nbt_data = excluded.nbt_data
|
||||
`, [shulkerId, itemId, itemName, slot, count, nbt ? JSON.stringify(nbt) : null]);
|
||||
}
|
||||
|
||||
async getShulkerItems(shulkerId) {
|
||||
return await this.db.all('SELECT * FROM shulker_items WHERE shulker_id = ? ORDER BY slot', [shulkerId]);
|
||||
}
|
||||
|
||||
async deleteShulkerItem(shulkerId, itemId) {
|
||||
return await this.db.run('DELETE FROM shulker_items WHERE shulker_id = ? AND item_id = ?', [shulkerId, itemId]);
|
||||
}
|
||||
|
||||
async clearShulkerItems(shulkerId) {
|
||||
return await this.db.run('DELETE FROM shulker_items WHERE shulker_id = ?', [shulkerId]);
|
||||
}
|
||||
|
||||
// ========================================
|
||||
// Trades
|
||||
// ========================================
|
||||
|
||||
async logTrade(playerName, action, items) {
|
||||
return await this.db.run(
|
||||
'INSERT INTO trades (player_name, action, items) VALUES (?, ?, ?)',
|
||||
[playerName, action, JSON.stringify(items)]
|
||||
);
|
||||
}
|
||||
|
||||
async getRecentTrades(limit = 50) {
|
||||
return await this.db.all(
|
||||
'SELECT * FROM trades ORDER BY timestamp DESC LIMIT ?',
|
||||
[limit]
|
||||
);
|
||||
}
|
||||
|
||||
async getTradesByPlayer(playerName, limit = 50) {
|
||||
return await this.db.all(
|
||||
'SELECT * FROM trades WHERE player_name = ? ORDER BY timestamp DESC LIMIT ?',
|
||||
[playerName, limit]
|
||||
);
|
||||
}
|
||||
|
||||
// ========================================
|
||||
// Pending Withdrawals
|
||||
// ========================================
|
||||
|
||||
async queueWithdrawal(playerName, itemId, itemName, count) {
|
||||
return await this.db.run(`
|
||||
INSERT INTO pending_withdrawals (player_name, item_id, item_name, requested_count)
|
||||
VALUES (?, ?, ?, ?)
|
||||
`, [playerName, itemId, itemName, count]);
|
||||
}
|
||||
|
||||
async getPendingWithdrawals(playerName) {
|
||||
return await this.db.all(`
|
||||
SELECT * FROM pending_withdrawals
|
||||
WHERE player_name = ? AND status IN ('pending', 'ready')
|
||||
ORDER BY timestamp ASC
|
||||
`, [playerName]);
|
||||
}
|
||||
|
||||
async getWithdrawalById(id) {
|
||||
return await this.db.get('SELECT * FROM pending_withdrawals WHERE id = ?', [id]);
|
||||
}
|
||||
|
||||
async updateWithdrawStatus(id, status) {
|
||||
return await this.db.run(
|
||||
'UPDATE pending_withdrawals SET status = ? WHERE id = ?',
|
||||
[status, id]
|
||||
);
|
||||
}
|
||||
|
||||
async markCompletedWithdrawals(playerName) {
|
||||
return await this.db.run(`
|
||||
UPDATE pending_withdrawals
|
||||
SET status = 'completed'
|
||||
WHERE player_name = ? AND status = 'ready'
|
||||
`, [playerName]);
|
||||
}
|
||||
|
||||
// ========================================
|
||||
// Item Index
|
||||
// ========================================
|
||||
|
||||
async updateItemIndex(itemId, itemName, shulkerId, count) {
|
||||
// This is a simplified version - in production, you'd want to handle
|
||||
// the shulker_ids JSON aggregation more carefully
|
||||
return await this.db.run(`
|
||||
INSERT INTO item_index (item_id, item_name, total_count)
|
||||
VALUES (?, ?, ?)
|
||||
ON CONFLICT(item_id) DO UPDATE SET
|
||||
total_count = total_count + ?,
|
||||
last_updated = CURRENT_TIMESTAMP
|
||||
`, [itemId, itemName, count, count]);
|
||||
}
|
||||
|
||||
async rebuildItemIndex() {
|
||||
// Rebuild entire index from shulker_items
|
||||
return await this.db.exec(`
|
||||
INSERT OR REPLACE INTO item_index (item_id, item_name, total_count, shulker_ids, last_updated)
|
||||
SELECT
|
||||
si.item_id,
|
||||
si.item_name,
|
||||
SUM(si.count) as total_count,
|
||||
GROUP_CONCAT('{"id":' || si.shulker_id || ',"count":' || si.count || '}') as shulker_ids,
|
||||
CURRENT_TIMESTAMP
|
||||
FROM shulker_items si
|
||||
GROUP BY si.item_id, si.item_name
|
||||
`);
|
||||
}
|
||||
|
||||
async searchItems(query) {
|
||||
if (!query) {
|
||||
return await this.db.all('SELECT * FROM item_index ORDER BY item_name ASC');
|
||||
}
|
||||
return await this.db.all(
|
||||
"SELECT * FROM item_index WHERE item_name LIKE ? ORDER BY item_name ASC",
|
||||
[`%${query}%`]
|
||||
);
|
||||
}
|
||||
|
||||
async getItemDetails(itemId) {
|
||||
const item = await this.db.get('SELECT * FROM item_index WHERE item_id = ?', [itemId]);
|
||||
if (!item) return null;
|
||||
|
||||
// Parse shulker_ids and get chest details
|
||||
const shulkerIds = JSON.parse(`[${item.shulker_ids}]`);
|
||||
|
||||
const locations = await this.db.all(`
|
||||
SELECT
|
||||
s.id as shulker_id,
|
||||
s.chest_id,
|
||||
c.pos_x, c.pos_y, c.pos_z,
|
||||
js.value as count
|
||||
FROM json_each(?) as js
|
||||
INNER JOIN shulkers s ON s.id = JSON_EXTRACT(js.value, '$.id')
|
||||
INNER JOIN chests c ON c.id = s.chest_id
|
||||
`, [item.shulker_ids]);
|
||||
|
||||
return { ...item, locations };
|
||||
}
|
||||
|
||||
// ========================================
|
||||
// Stats
|
||||
// ========================================
|
||||
|
||||
async getStats() {
|
||||
const totalItems = await this.db.get('SELECT SUM(total_items) as total FROM shulkers');
|
||||
const totalShulkers = await this.db.get('SELECT COUNT(*) as total FROM shulkers');
|
||||
const totalChests = await this.db.get('SELECT COUNT(*) as total FROM chests');
|
||||
const emptyShulkers = await this.db.get("SELECT COUNT(*) as total FROM shulkers WHERE slot_count = 0");
|
||||
const recentTrades = await this.db.get('SELECT COUNT(*) as total FROM trades WHERE timestamp > datetime("now", "-1 day")');
|
||||
|
||||
// Category breakdown
|
||||
const categories = await this.db.all(`
|
||||
SELECT category, COUNT(*) as count
|
||||
FROM shulkers
|
||||
WHERE category IS NOT NULL
|
||||
GROUP BY category
|
||||
`);
|
||||
|
||||
const categoryMap = {};
|
||||
for (const cat of categories) {
|
||||
categoryMap[cat.category] = cat.count;
|
||||
}
|
||||
|
||||
return {
|
||||
totalItems: totalItems?.total || 0,
|
||||
totalShulkers: totalShulkers?.total || 0,
|
||||
totalChests: totalChests?.total || 0,
|
||||
emptyShulkers: emptyShulkers?.total || 0,
|
||||
recentTrades: recentTrades?.total || 0,
|
||||
categories: categoryMap
|
||||
};
|
||||
}
|
||||
|
||||
async close() {
|
||||
if (this.db) {
|
||||
await this.db.close();
|
||||
this.db = null;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
module.exports = new Database();
|
||||
Reference in New Issue
Block a user