using Contime.model; using Microsoft.Data.Sqlite; using System.Globalization; namespace Contime.data { public class DataAccess { private readonly string _connectionString; public DataAccess(string dbFileName = "contime.db") { _connectionString = $"Data Source={dbFileName}"; } public void InitializeDatabase() { using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = @" CREATE TABLE IF NOT EXISTS workdays ( id INTEGER PRIMARY KEY AUTOINCREMENT, workday_date TEXT NOT NULL UNIQUE ); CREATE TABLE IF NOT EXISTS tasks ( id INTEGER PRIMARY KEY AUTOINCREMENT, description TEXT NOT NULL, created_date TEXT NOT NULL, completed_date TEXT, status TEXT NOT NULL CHECK(status IN ('open', 'closed')) ); CREATE TABLE IF NOT EXISTS task_times ( id INTEGER PRIMARY KEY AUTOINCREMENT, task_id INTEGER NOT NULL, workday_id INTEGER NOT NULL, start_time TEXT NOT NULL, end_time TEXT, FOREIGN KEY (task_id) REFERENCES tasks(id) ON DELETE CASCADE, FOREIGN KEY (workday_id) REFERENCES workdays(id) ON DELETE CASCADE ); "; command.ExecuteNonQuery(); } } public long GetOrCreateWorkday(DateTime date) { using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var selectCmd = connection.CreateCommand(); selectCmd.CommandText = "SELECT id FROM workdays WHERE workday_date = $date"; selectCmd.Parameters.AddWithValue("$date", date.ToString("yyyy-MM-dd")); var result = selectCmd.ExecuteScalar(); if (result != null) { return (long)result; } else { var insertCmd = connection.CreateCommand(); insertCmd.CommandText = "INSERT INTO workdays (workday_date) VALUES ($date); SELECT last_insert_rowid();"; insertCmd.Parameters.AddWithValue("$date", date.ToString("yyyy-MM-dd")); return (long)insertCmd.ExecuteScalar(); } } } public List GetAllTasks() { var tasks = new List(); using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = @" SELECT t.id, t.description, t.status, COALESCE(SUM(CAST((julianday(tt.end_time) - julianday(tt.start_time)) * 86400 AS INTEGER)), 0) FROM tasks t LEFT JOIN task_times tt ON t.id = tt.task_id AND tt.end_time IS NOT NULL GROUP BY t.id, t.description, t.status ORDER BY t.created_date DESC"; using (var reader = command.ExecuteReader()) { while (reader.Read()) { var taskItem = new TaskItem( id: reader.GetInt64(0), name: reader.GetString(1), status: reader.GetString(2), elapsedTime: TimeSpan.FromSeconds(reader.GetInt32(3)) ); tasks.Add(taskItem); } } } return tasks; } public void AddTask(string description) { using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = "INSERT INTO tasks (description, created_date, status) VALUES ($desc, $date, 'open')"; command.Parameters.AddWithValue("$desc", description); command.Parameters.AddWithValue("$date", DateTime.UtcNow.ToString("o")); command.ExecuteNonQuery(); } } public void UpdateTaskStatus(long taskId, string status, bool isCompletion) { using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = isCompletion ? "UPDATE tasks SET status = $status, completed_date = $date WHERE id = $id" : "UPDATE tasks SET status = $status, completed_date = NULL WHERE id = $id"; command.Parameters.AddWithValue("$status", status); command.Parameters.AddWithValue("$id", taskId); if (isCompletion) command.Parameters.AddWithValue("$date", DateTime.UtcNow.ToString("o")); command.ExecuteNonQuery(); } } public long StartTaskTime(long taskId, long workdayId) { using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = "INSERT INTO task_times (task_id, workday_id, start_time) VALUES ($taskId, $workdayId, $startTime); SELECT last_insert_rowid();"; command.Parameters.AddWithValue("$taskId", taskId); command.Parameters.AddWithValue("$workdayId", workdayId); command.Parameters.AddWithValue("$startTime", DateTime.UtcNow.ToString("o")); return (long)command.ExecuteScalar(); } } public void EndTaskTime(long taskTimeId) { using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = "UPDATE task_times SET end_time = $endTime WHERE id = $id"; command.Parameters.AddWithValue("$endTime", DateTime.UtcNow.ToString("o")); command.Parameters.AddWithValue("$id", taskTimeId); command.ExecuteNonQuery(); } } public TimeSpan GetTotalTimeForDate(DateTime date) { long totalSeconds = 0; using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = @" SELECT start_time, end_time FROM task_times WHERE end_time IS NOT NULL"; using (var reader = command.ExecuteReader()) { while (reader.Read()) { var start = DateTime.Parse(reader.GetString(0), CultureInfo.InvariantCulture, DateTimeStyles.RoundtripKind).ToLocalTime(); var end = DateTime.Parse(reader.GetString(1), CultureInfo.InvariantCulture, DateTimeStyles.RoundtripKind).ToLocalTime(); if (start.Date == date.Date) { var effectiveEnd = (end.Date > start.Date) ? start.Date.AddDays(1) : end; totalSeconds += (long)(effectiveEnd - start).TotalSeconds; } } } } return TimeSpan.FromSeconds(totalSeconds); } public TimeSpan GetTotalTimeForCurrentWeek() { long totalSeconds = 0; var today = DateTime.Today; // Sunday is 0, so we adjust to make Monday the start of the week (1) int diff = (7 + (int)today.DayOfWeek - (int)DayOfWeek.Monday) % 7; var startOfWeek = today.AddDays(-1 * diff).Date; var endOfWeek = startOfWeek.AddDays(6); using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = @" SELECT start_time, end_time FROM task_times WHERE end_time IS NOT NULL"; using (var reader = command.ExecuteReader()) { while (reader.Read()) { var start = DateTime.Parse(reader.GetString(0), CultureInfo.InvariantCulture, DateTimeStyles.RoundtripKind).ToLocalTime(); var end = DateTime.Parse(reader.GetString(1), CultureInfo.InvariantCulture, DateTimeStyles.RoundtripKind).ToLocalTime(); if (start.Date >= startOfWeek && start.Date <= endOfWeek) { totalSeconds += (long)(end - start).TotalSeconds; } } } } return TimeSpan.FromSeconds(totalSeconds); } public List<(DateTime Date, string TaskName, TimeSpan Duration)> GetAllTimeEntriesForExport() { var entries = new List<(DateTime Date, string TaskName, TimeSpan Duration)>(); using (var connection = new SqliteConnection(_connectionString)) { connection.Open(); var command = connection.CreateCommand(); command.CommandText = @" SELECT t.description, tt.start_time, tt.end_time FROM task_times tt JOIN tasks t ON tt.task_id = t.id WHERE tt.end_time IS NOT NULL ORDER BY tt.start_time"; using (var reader = command.ExecuteReader()) { while (reader.Read()) { var taskName = reader.GetString(0); var startTime = DateTime.Parse(reader.GetString(1), CultureInfo.InvariantCulture, DateTimeStyles.RoundtripKind).ToLocalTime(); var endTime = DateTime.Parse(reader.GetString(2), CultureInfo.InvariantCulture, DateTimeStyles.RoundtripKind).ToLocalTime(); var currentDate = startTime.Date; while (currentDate <= endTime.Date) { var startOfThisDay = (currentDate == startTime.Date) ? startTime : currentDate; var endOfThisDay = (currentDate == endTime.Date) ? endTime : currentDate.AddDays(1).AddTicks(-1); var durationThisDay = endOfThisDay - startOfThisDay; entries.Add((currentDate, taskName, durationThisDay)); currentDate = currentDate.AddDays(1); } } } } return entries; } } }