From bb0afcd703a9de369992721810c53b3b631a8eed Mon Sep 17 00:00:00 2001 From: Subhamoy Biswas Date: Wed, 19 Nov 2025 22:34:32 +0530 Subject: [PATCH] refactor: improved db performance --- src-tauri/src/migrations.rs | 11 ++ src/services/database.ts | 280 +++++++++--------------------------- 2 files changed, 77 insertions(+), 214 deletions(-) diff --git a/src-tauri/src/migrations.rs b/src-tauri/src/migrations.rs index 0236d97..b3e5b92 100644 --- a/src-tauri/src/migrations.rs +++ b/src-tauri/src/migrations.rs @@ -148,5 +148,16 @@ pub fn get_migrations() -> Vec { END; ", kind: MigrationKind::Up, + }, + Migration { + version: 3, + description: "add_performance_indexes", + sql: " + CREATE INDEX IF NOT EXISTS idx_downloads_video_id ON downloads(video_id); + CREATE INDEX IF NOT EXISTS idx_downloads_playlist_id ON downloads(playlist_id); + CREATE INDEX IF NOT EXISTS idx_downloads_status_updated ON downloads(download_status, updated_at DESC); + CREATE INDEX IF NOT EXISTS idx_downloads_id_desc ON downloads(id DESC); + ", + kind: MigrationKind::Up, }] } diff --git a/src/services/database.ts b/src/services/database.ts index 5c09f57..bfdad49 100644 --- a/src/services/database.ts +++ b/src/services/database.ts @@ -1,105 +1,17 @@ -import { Download, DownloadState } from '@/types/download' +import { DownloadState } from '@/types/download' import { KvStoreTable } from '@/types/kvStore' import { PlaylistInfo } from '@/types/playlist' import { SettingsTable } from '@/types/settings' import { VideoInfo } from '@/types/video' import Database from '@tauri-apps/plugin-sql' -// ------ Database schema ------ -// CREATE TABLE IF NOT EXISTS video_info ( -// id INTEGER PRIMARY KEY NOT NULL, -// video_id TEXT UNIQUE NOT NULL, -// title TEXT NOT NULL, -// url TEXT NOT NULL, -// host TEXT NOT NULL, -// thumbnail TEXT, -// channel TEXT, -// duration_string TEXT, -// release_date TEXT, -// view_count INTEGER, -// like_count INTEGER -// ); -// CREATE TABLE IF NOT EXISTS playlist_info ( -// id INTEGER PRIMARY KEY NOT NULL, -// playlist_id TEXT UNIQUE NOT NULL, -// playlist_title TEXT NOT NULL, -// playlist_url TEXT NOT NULL, -// playlist_n_entries INTEGER NOT NULL, -// playlist_channel TEXT, -// ); -// CREATE TABLE IF NOT EXISTS downloads ( -// id INTEGER PRIMARY KEY NOT NULL, -// download_id TEXT UNIQUE NOT NULL, -// download_status TEXT NOT NULL, -// video_id TEXT NOT NULL, -// format_id TEXT NOT NULL, -// subtitle_id TEXT, -// queue_index INTEGER, -// playlist_id TEXT, -// playlist_index INTEGER, -// resolution TEXT, -// ext TEXT, -// abr REAL, -// vbr REAL, -// acodec TEXT, -// vcodec TEXT, -// dynamic_range TEXT, -// process_id INTEGER, -// status TEXT, -// progress REAL, -// total INTEGER, -// downloaded INTEGER, -// speed REAL, -// eta INTEGER, -// filepath TEXT, -// filetype TEXT, -// filesize INTEGER, -// FOREIGN KEY (video_id) REFERENCES video_info (video_id) -// FOREIGN KEY (playlist_id) REFERENCES playlist_info (playlist_id) -// ); -// CREATE TABLE IF NOT EXISTS settings ( -// id INTEGER PRIMARY KEY NOT NULL, -// key TEXT UNIQUE NOT NULL, -// value TEXT -// ); - export const saveVideoInfo = async (videoInfo: VideoInfo) => { const db = await Database.load('sqlite:database.db') - const result = await db.select( - 'SELECT * FROM video_info WHERE video_id = $1', - [videoInfo.video_id] - ) - if (result.length > 0) { - return await db.execute( - `UPDATE video_info SET - title = $2, - url = $3, - host = $4, - thumbnail = $5, - channel = $6, - duration_string = $7, - release_date = $8, - view_count = $9, - like_count = $10 - WHERE video_id = $1`, - [ - videoInfo.video_id, - videoInfo.title, - videoInfo.url, - videoInfo.host, - videoInfo.thumbnail, - videoInfo.channel, - videoInfo.duration_string, - videoInfo.release_date, - videoInfo.view_count, - videoInfo.like_count - ] - ) - } return await db.execute( `INSERT INTO video_info ( video_id, - title, url, + title, + url, host, thumbnail, channel, @@ -107,7 +19,17 @@ export const saveVideoInfo = async (videoInfo: VideoInfo) => { release_date, view_count, like_count - ) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)`, + ) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10) + ON CONFLICT(video_id) DO UPDATE SET + title = $2, + url = $3, + host = $4, + thumbnail = $5, + channel = $6, + duration_string = $7, + release_date = $8, + view_count = $9, + like_count = $10`, [ videoInfo.video_id, videoInfo.title, @@ -125,27 +47,6 @@ export const saveVideoInfo = async (videoInfo: VideoInfo) => { export const savePlaylistInfo = async (playlistInfo: PlaylistInfo) => { const db = await Database.load('sqlite:database.db') - const result = await db.select( - 'SELECT * FROM playlist_info WHERE playlist_id = $1', - [playlistInfo.playlist_id] - ) - if (result.length > 0) { - return await db.execute( - `UPDATE playlist_info SET - playlist_title = $2, - playlist_url = $3, - playlist_n_entries = $4, - playlist_channel = $5 - WHERE playlist_id = $1`, - [ - playlistInfo.playlist_id, - playlistInfo.playlist_title, - playlistInfo.playlist_url, - playlistInfo.playlist_n_entries, - playlistInfo.playlist_channel - ] - ) - } return await db.execute( `INSERT INTO playlist_info ( playlist_id, @@ -153,7 +54,12 @@ export const savePlaylistInfo = async (playlistInfo: PlaylistInfo) => { playlist_url, playlist_n_entries, playlist_channel - ) VALUES ($1, $2, $3, $4, $5)`, + ) VALUES ($1, $2, $3, $4, $5) + ON CONFLICT(playlist_id) DO UPDATE SET + playlist_title = $2, + playlist_url = $3, + playlist_n_entries = $4, + playlist_channel = $5`, [ playlistInfo.playlist_id, playlistInfo.playlist_title, @@ -166,83 +72,6 @@ export const savePlaylistInfo = async (playlistInfo: PlaylistInfo) => { export const saveDownloadState = async (downloadState: DownloadState) => { const db = await Database.load('sqlite:database.db') - const result = await db.select( - 'SELECT * FROM downloads WHERE download_id = $1', - [downloadState.download_id] - ) - if (result.length > 0) { - return await db.execute( - `UPDATE downloads SET - download_status = $2, - video_id = $3, - format_id = $4, - subtitle_id = $5, - queue_index = $6, - playlist_id = $7, - playlist_index = $8, - process_id = $9, - resolution = $10, - ext = $11, - abr = $12, - vbr = $13, - acodec = $14, - vcodec = $15, - dynamic_range = $16, - status = $17, - progress = $18, - total = $19, - downloaded = $20, - speed = $21, - eta = $22, - filepath = $23, - filetype = $24, - filesize = $25, - output_format = $26, - embed_metadata = $27, - embed_thumbnail = $28, - sponsorblock_remove = $29, - sponsorblock_mark = $30, - use_aria2 = $31, - custom_command = $32, - queue_config = $33 - WHERE download_id = $1`, - [ - downloadState.download_id, - downloadState.download_status, - downloadState.video_id, - downloadState.format_id, - downloadState.subtitle_id, - downloadState.queue_index, - downloadState.playlist_id, - downloadState.playlist_index, - downloadState.process_id, - downloadState.resolution, - downloadState.ext, - downloadState.abr, - downloadState.vbr, - downloadState.acodec, - downloadState.vcodec, - downloadState.dynamic_range, - downloadState.status, - downloadState.progress, - downloadState.total, - downloadState.downloaded, - downloadState.speed, - downloadState.eta, - downloadState.filepath, - downloadState.filetype, - downloadState.filesize, - downloadState.output_format, - downloadState.embed_metadata, - downloadState.embed_thumbnail, - downloadState.sponsorblock_remove, - downloadState.sponsorblock_mark, - downloadState.use_aria2, - downloadState.custom_command, - downloadState.queue_config - ] - ) - } return await db.execute( `INSERT INTO downloads ( download_id, @@ -277,7 +106,40 @@ export const saveDownloadState = async (downloadState: DownloadState) => { use_aria2, custom_command, queue_config - ) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28, $29, $30, $31, $32, $33)`, + ) VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18, $19, $20, $21, $22, $23, $24, $25, $26, $27, $28, $29, $30, $31, $32, $33) + ON CONFLICT(download_id) DO UPDATE SET + download_status = $2, + video_id = $3, + format_id = $4, + subtitle_id = $5, + queue_index = $6, + playlist_id = $7, + playlist_index = $8, + process_id = $9, + resolution = $10, + ext = $11, + abr = $12, + vbr = $13, + acodec = $14, + vcodec = $15, + dynamic_range = $16, + status = $17, + progress = $18, + total = $19, + downloaded = $20, + speed = $21, + eta = $22, + filepath = $23, + filetype = $24, + filesize = $25, + output_format = $26, + embed_metadata = $27, + embed_thumbnail = $28, + sponsorblock_remove = $29, + sponsorblock_mark = $30, + use_aria2 = $31, + custom_command = $32, + queue_config = $33`, [ downloadState.download_id, downloadState.download_status, @@ -388,19 +250,14 @@ export const fetchAllSettings = async () => { export const saveSettingsKey = async (key: string, value: unknown) => { const db = await Database.load('sqlite:database.db') - const result = await db.select( - 'SELECT * FROM settings WHERE key = $1', - [key] - ) const jsonValue = JSON.stringify(value) - if (result.length > 0) { - return await db.execute( - `UPDATE settings SET value = json_object('value', json($2)) WHERE key = $1`, - [key, jsonValue] - ) - } return await db.execute( - `INSERT INTO settings (key, value) VALUES ($1, json_object('value', json($2)))`, + `INSERT INTO settings ( + key, + value + ) VALUES ($1, json_object('value', json($2))) + ON CONFLICT(key) DO UPDATE SET + value = json_object('value', json($2))`, [key, jsonValue] ) } @@ -432,19 +289,14 @@ export const fetchAllKvPairs = async () => { export const saveKvPair = async (key: string, value: unknown) => { const db = await Database.load('sqlite:database.db') - const result = await db.select( - 'SELECT * FROM kv_store WHERE key = $1', - [key] - ) const jsonValue = JSON.stringify(value) - if (result.length > 0) { - return await db.execute( - `UPDATE kv_store SET value = json_object('value', json($2)) WHERE key = $1`, - [key, jsonValue] - ) - } return await db.execute( - `INSERT INTO kv_store (key, value) VALUES ($1, json_object('value', json($2)))`, + `INSERT INTO kv_store ( + key, + value + ) VALUES ($1, json_object('value', json($2))) + ON CONFLICT(key) DO UPDATE SET + value = json_object('value', json($2))`, [key, jsonValue] ) }