You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 
 
 

491 lines
17 KiB

const Database = require('better-sqlite3');
const bcrypt = require('bcrypt');
const path = require('path');
const BCRYPT_ROUNDS = parseInt(process.env.BCRYPT_ROUNDS) || 12;
class HikeMapDB {
constructor(dbPath) {
this.dbPath = dbPath || path.join(__dirname, 'data', 'hikemap.db');
this.db = null;
}
init() {
this.db = new Database(this.dbPath);
this.db.pragma('journal_mode = WAL');
this.createTables();
console.log(`Database initialized at ${this.dbPath}`);
return this;
}
createTables() {
// Users table
this.db.exec(`
CREATE TABLE IF NOT EXISTS users (
id INTEGER PRIMARY KEY AUTOINCREMENT,
username TEXT UNIQUE NOT NULL,
email TEXT UNIQUE NOT NULL,
password_hash TEXT NOT NULL,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
total_points INTEGER DEFAULT 0,
finds_count INTEGER DEFAULT 0,
avatar_icon TEXT DEFAULT 'account',
avatar_color TEXT DEFAULT '#4CAF50',
is_admin BOOLEAN DEFAULT 0
)
`);
// Geocache finds table
this.db.exec(`
CREATE TABLE IF NOT EXISTS geocache_finds (
id INTEGER PRIMARY KEY AUTOINCREMENT,
user_id INTEGER NOT NULL,
geocache_id TEXT NOT NULL,
found_at DATETIME DEFAULT CURRENT_TIMESTAMP,
points_earned INTEGER NOT NULL,
is_first_finder BOOLEAN DEFAULT 0,
FOREIGN KEY (user_id) REFERENCES users(id),
UNIQUE(user_id, geocache_id)
)
`);
// Refresh tokens table for logout/token invalidation
this.db.exec(`
CREATE TABLE IF NOT EXISTS refresh_tokens (
id INTEGER PRIMARY KEY AUTOINCREMENT,
user_id INTEGER NOT NULL,
token_hash TEXT NOT NULL,
expires_at DATETIME NOT NULL,
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (user_id) REFERENCES users(id)
)
`);
// RPG stats table
this.db.exec(`
CREATE TABLE IF NOT EXISTS rpg_stats (
user_id INTEGER PRIMARY KEY,
character_name TEXT,
race TEXT DEFAULT 'human',
class TEXT NOT NULL DEFAULT 'trail_runner',
level INTEGER DEFAULT 1,
xp INTEGER DEFAULT 0,
hp INTEGER DEFAULT 100,
max_hp INTEGER DEFAULT 100,
mp INTEGER DEFAULT 50,
max_mp INTEGER DEFAULT 50,
atk INTEGER DEFAULT 12,
def INTEGER DEFAULT 8,
updated_at DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (user_id) REFERENCES users(id)
)
`);
// Migration: Add character_name and race columns if they don't exist
try {
this.db.exec(`ALTER TABLE rpg_stats ADD COLUMN character_name TEXT`);
} catch (e) { /* Column already exists */ }
try {
this.db.exec(`ALTER TABLE rpg_stats ADD COLUMN race TEXT DEFAULT 'human'`);
} catch (e) { /* Column already exists */ }
// Monster entourage table - stores monsters following the player
this.db.exec(`
CREATE TABLE IF NOT EXISTS monster_entourage (
id TEXT PRIMARY KEY,
user_id INTEGER NOT NULL,
monster_type TEXT NOT NULL,
level INTEGER NOT NULL,
hp INTEGER NOT NULL,
max_hp INTEGER NOT NULL,
atk INTEGER NOT NULL,
def INTEGER NOT NULL,
position_lat REAL,
position_lng REAL,
spawn_time INTEGER NOT NULL,
last_dialogue_time INTEGER DEFAULT 0,
FOREIGN KEY (user_id) REFERENCES users(id)
)
`);
// Create indexes for performance
this.db.exec(`
CREATE INDEX IF NOT EXISTS idx_geocache_finds_user ON geocache_finds(user_id);
CREATE INDEX IF NOT EXISTS idx_geocache_finds_geocache ON geocache_finds(geocache_id);
CREATE INDEX IF NOT EXISTS idx_refresh_tokens_user ON refresh_tokens(user_id);
CREATE INDEX IF NOT EXISTS idx_users_username ON users(username);
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
CREATE INDEX IF NOT EXISTS idx_monster_entourage_user ON monster_entourage(user_id);
`);
}
// User methods
async createUser(username, email, password) {
const passwordHash = await bcrypt.hash(password, BCRYPT_ROUNDS);
try {
const stmt = this.db.prepare(`
INSERT INTO users (username, email, password_hash)
VALUES (?, ?, ?)
`);
const result = stmt.run(username.toLowerCase(), email.toLowerCase(), passwordHash);
return { id: result.lastInsertRowid, username, email };
} catch (err) {
if (err.code === 'SQLITE_CONSTRAINT_UNIQUE') {
if (err.message.includes('username')) {
throw new Error('Username already exists');
}
if (err.message.includes('email')) {
throw new Error('Email already exists');
}
}
throw err;
}
}
async validateUser(usernameOrEmail, password) {
const stmt = this.db.prepare(`
SELECT * FROM users
WHERE username = ? OR email = ?
`);
const user = stmt.get(usernameOrEmail.toLowerCase(), usernameOrEmail.toLowerCase());
if (!user) {
return null;
}
const valid = await bcrypt.compare(password, user.password_hash);
if (!valid) {
return null;
}
// Don't return password hash
const { password_hash, ...safeUser } = user;
return safeUser;
}
getUserById(userId) {
const stmt = this.db.prepare(`
SELECT id, username, email, created_at, total_points, finds_count,
avatar_icon, avatar_color, is_admin
FROM users WHERE id = ?
`);
return stmt.get(userId);
}
getUserByUsername(username) {
const stmt = this.db.prepare(`
SELECT id, username, email, created_at, total_points, finds_count,
avatar_icon, avatar_color, is_admin
FROM users WHERE username = ?
`);
return stmt.get(username.toLowerCase());
}
updateUserAvatar(userId, icon, color) {
const stmt = this.db.prepare(`
UPDATE users SET avatar_icon = ?, avatar_color = ?
WHERE id = ?
`);
return stmt.run(icon, color, userId);
}
setUserAdmin(userId, isAdmin) {
const stmt = this.db.prepare(`
UPDATE users SET is_admin = ? WHERE id = ?
`);
return stmt.run(isAdmin ? 1 : 0, userId);
}
setUserAdminByUsername(username, isAdmin) {
const stmt = this.db.prepare(`
UPDATE users SET is_admin = ? WHERE username = ?
`);
return stmt.run(isAdmin ? 1 : 0, username.toLowerCase());
}
// Geocache find methods
recordFind(userId, geocacheId, pointsEarned, isFirstFinder = false) {
const transaction = this.db.transaction(() => {
// Insert the find record
const insertStmt = this.db.prepare(`
INSERT INTO geocache_finds (user_id, geocache_id, points_earned, is_first_finder)
VALUES (?, ?, ?, ?)
`);
try {
insertStmt.run(userId, geocacheId, pointsEarned, isFirstFinder ? 1 : 0);
} catch (err) {
if (err.code === 'SQLITE_CONSTRAINT_UNIQUE') {
throw new Error('You have already found this geocache');
}
throw err;
}
// Update user's total points and finds count
const updateStmt = this.db.prepare(`
UPDATE users
SET total_points = total_points + ?,
finds_count = finds_count + 1
WHERE id = ?
`);
updateStmt.run(pointsEarned, userId);
return { success: true, pointsEarned };
});
return transaction();
}
hasUserFoundGeocache(userId, geocacheId) {
const stmt = this.db.prepare(`
SELECT 1 FROM geocache_finds
WHERE user_id = ? AND geocache_id = ?
`);
return !!stmt.get(userId, geocacheId);
}
isFirstFinder(geocacheId) {
const stmt = this.db.prepare(`
SELECT 1 FROM geocache_finds
WHERE geocache_id = ?
LIMIT 1
`);
return !stmt.get(geocacheId);
}
getGeocacheFinders(geocacheId) {
const stmt = this.db.prepare(`
SELECT u.id, u.username, u.avatar_icon, u.avatar_color,
gf.found_at, gf.points_earned, gf.is_first_finder
FROM geocache_finds gf
JOIN users u ON gf.user_id = u.id
WHERE gf.geocache_id = ?
ORDER BY gf.found_at ASC
`);
return stmt.all(geocacheId);
}
getUserFinds(userId, limit = 50) {
const stmt = this.db.prepare(`
SELECT geocache_id, found_at, points_earned, is_first_finder
FROM geocache_finds
WHERE user_id = ?
ORDER BY found_at DESC
LIMIT ?
`);
return stmt.all(userId, limit);
}
// Leaderboard methods
getLeaderboard(period = 'all', limit = 50) {
let whereClause = '';
if (period === 'weekly') {
whereClause = "WHERE gf.found_at >= datetime('now', '-7 days')";
} else if (period === 'monthly') {
whereClause = "WHERE gf.found_at >= datetime('now', '-30 days')";
}
if (period === 'all') {
// For all-time, use the cached total_points
const stmt = this.db.prepare(`
SELECT id, username, avatar_icon, avatar_color, total_points, finds_count
FROM users
ORDER BY total_points DESC
LIMIT ?
`);
return stmt.all(limit);
} else {
// For weekly/monthly, calculate from finds
const stmt = this.db.prepare(`
SELECT u.id, u.username, u.avatar_icon, u.avatar_color,
SUM(gf.points_earned) as total_points,
COUNT(gf.id) as finds_count
FROM users u
JOIN geocache_finds gf ON u.id = gf.user_id
${whereClause}
GROUP BY u.id
ORDER BY total_points DESC
LIMIT ?
`);
return stmt.all(limit);
}
}
// Refresh token methods
async storeRefreshToken(userId, tokenHash, expiresAt) {
const stmt = this.db.prepare(`
INSERT INTO refresh_tokens (user_id, token_hash, expires_at)
VALUES (?, ?, ?)
`);
return stmt.run(userId, tokenHash, expiresAt);
}
getRefreshToken(tokenHash) {
const stmt = this.db.prepare(`
SELECT * FROM refresh_tokens
WHERE token_hash = ? AND expires_at > datetime('now')
`);
return stmt.get(tokenHash);
}
deleteRefreshToken(tokenHash) {
const stmt = this.db.prepare(`
DELETE FROM refresh_tokens WHERE token_hash = ?
`);
return stmt.run(tokenHash);
}
deleteUserRefreshTokens(userId) {
const stmt = this.db.prepare(`
DELETE FROM refresh_tokens WHERE user_id = ?
`);
return stmt.run(userId);
}
cleanExpiredTokens() {
const stmt = this.db.prepare(`
DELETE FROM refresh_tokens WHERE expires_at <= datetime('now')
`);
return stmt.run();
}
// RPG Stats methods
getRpgStats(userId) {
const stmt = this.db.prepare(`
SELECT character_name, race, class, level, xp, hp, max_hp, mp, max_mp, atk, def
FROM rpg_stats WHERE user_id = ?
`);
return stmt.get(userId);
}
hasCharacter(userId) {
const stmt = this.db.prepare(`
SELECT 1 FROM rpg_stats WHERE user_id = ? AND character_name IS NOT NULL
`);
return !!stmt.get(userId);
}
createCharacter(userId, characterData) {
const stmt = this.db.prepare(`
INSERT INTO rpg_stats (user_id, character_name, race, class, level, xp, hp, max_hp, mp, max_mp, atk, def, updated_at)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, datetime('now'))
ON CONFLICT(user_id) DO UPDATE SET
character_name = excluded.character_name,
race = excluded.race,
class = excluded.class,
level = excluded.level,
xp = excluded.xp,
hp = excluded.hp,
max_hp = excluded.max_hp,
mp = excluded.mp,
max_mp = excluded.max_mp,
atk = excluded.atk,
def = excluded.def,
updated_at = datetime('now')
`);
return stmt.run(
userId,
characterData.name,
characterData.race || 'human',
characterData.class || 'trail_runner',
characterData.level || 1,
characterData.xp || 0,
characterData.hp || 100,
characterData.maxHp || 100,
characterData.mp || 50,
characterData.maxMp || 50,
characterData.atk || 12,
characterData.def || 8
);
}
saveRpgStats(userId, stats) {
const stmt = this.db.prepare(`
INSERT INTO rpg_stats (user_id, character_name, race, class, level, xp, hp, max_hp, mp, max_mp, atk, def, updated_at)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, datetime('now'))
ON CONFLICT(user_id) DO UPDATE SET
character_name = COALESCE(excluded.character_name, rpg_stats.character_name),
race = COALESCE(excluded.race, rpg_stats.race),
class = excluded.class,
level = excluded.level,
xp = excluded.xp,
hp = excluded.hp,
max_hp = excluded.max_hp,
mp = excluded.mp,
max_mp = excluded.max_mp,
atk = excluded.atk,
def = excluded.def,
updated_at = datetime('now')
`);
return stmt.run(
userId,
stats.name || null,
stats.race || null,
stats.class || 'trail_runner',
stats.level || 1,
stats.xp || 0,
stats.hp || 100,
stats.maxHp || 100,
stats.mp || 50,
stats.maxMp || 50,
stats.atk || 12,
stats.def || 8
);
}
// Monster entourage methods
getMonsterEntourage(userId) {
const stmt = this.db.prepare(`
SELECT id, monster_type, level, hp, max_hp, atk, def,
position_lat, position_lng, spawn_time, last_dialogue_time
FROM monster_entourage WHERE user_id = ?
`);
return stmt.all(userId);
}
saveMonsterEntourage(userId, monsters) {
const deleteStmt = this.db.prepare(`DELETE FROM monster_entourage WHERE user_id = ?`);
const insertStmt = this.db.prepare(`
INSERT INTO monster_entourage
(id, user_id, monster_type, level, hp, max_hp, atk, def, position_lat, position_lng, spawn_time, last_dialogue_time)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
`);
const transaction = this.db.transaction(() => {
deleteStmt.run(userId);
for (const monster of monsters) {
insertStmt.run(
monster.id,
userId,
monster.type,
monster.level,
monster.hp,
monster.maxHp,
monster.atk,
monster.def,
monster.position?.lat || null,
monster.position?.lng || null,
monster.spawnTime,
monster.lastDialogueTime || 0
);
}
});
return transaction();
}
removeMonster(userId, monsterId) {
const stmt = this.db.prepare(`DELETE FROM monster_entourage WHERE user_id = ? AND id = ?`);
return stmt.run(userId, monsterId);
}
close() {
if (this.db) {
this.db.close();
}
}
}
module.exports = HikeMapDB;