using CarCareTracker.External.Interfaces; using CarCareTracker.Models; using Npgsql; namespace CarCareTracker.External.Implementations { public class PGUserRecordDataAccess : IUserRecordDataAccess { private NpgsqlDataSource pgDataSource; private readonly ILogger _logger; private static string tableName = "userrecords"; public PGUserRecordDataAccess(IConfiguration config, ILogger logger) { pgDataSource = NpgsqlDataSource.Create(config["POSTGRES_CONNECTION"]); _logger = logger; try { //create table if not exist. string initCMD = $"CREATE SCHEMA IF NOT EXISTS app; CREATE TABLE IF NOT EXISTS app.{tableName} (id INT GENERATED BY DEFAULT AS IDENTITY primary key, username TEXT not null, emailaddress TEXT not null, password TEXT not null, isadmin BOOLEAN)"; using (var ctext = pgDataSource.CreateCommand(initCMD)) { ctext.ExecuteNonQuery(); } } catch (Exception ex) { _logger.LogError(ex.Message); } } public List GetUsers() { try { string cmd = $"SELECT id, username, emailaddress, password, isadmin FROM app.{tableName}"; var results = new List(); using (var ctext = pgDataSource.CreateCommand(cmd)) { using (NpgsqlDataReader reader = ctext.ExecuteReader()) while (reader.Read()) { UserData result = new UserData(); result.Id = int.Parse(reader["id"].ToString()); result.UserName = reader["username"].ToString(); result.EmailAddress = reader["emailaddress"].ToString(); result.Password = reader["password"].ToString(); result.IsAdmin = bool.Parse(reader["isadmin"].ToString()); results.Add(result); } } return results; } catch (Exception ex) { _logger.LogError(ex.Message); return new List(); } } public UserData GetUserRecordByUserName(string userName) { try { string cmd = $"SELECT id, username, emailaddress, password, isadmin FROM app.{tableName} WHERE username = @username"; var result = new UserData(); using (var ctext = pgDataSource.CreateCommand(cmd)) { ctext.Parameters.AddWithValue("username", userName); using (NpgsqlDataReader reader = ctext.ExecuteReader()) while (reader.Read()) { result.Id = int.Parse(reader["id"].ToString()); result.UserName = reader["username"].ToString(); result.EmailAddress = reader["emailaddress"].ToString(); result.Password = reader["password"].ToString(); result.IsAdmin = bool.Parse(reader["isadmin"].ToString()); } } return result; } catch (Exception ex) { _logger.LogError(ex.Message); return new UserData(); } } public UserData GetUserRecordByEmailAddress(string emailAddress) { try { string cmd = $"SELECT id, username, emailaddress, password, isadmin FROM app.{tableName} WHERE emailaddress = @emailaddress"; var result = new UserData(); using (var ctext = pgDataSource.CreateCommand(cmd)) { ctext.Parameters.AddWithValue("emailaddress", emailAddress); using (NpgsqlDataReader reader = ctext.ExecuteReader()) while (reader.Read()) { result.Id = int.Parse(reader["id"].ToString()); result.UserName = reader["username"].ToString(); result.EmailAddress = reader["emailaddress"].ToString(); result.Password = reader["password"].ToString(); result.IsAdmin = bool.Parse(reader["isadmin"].ToString()); } } return result; } catch (Exception ex) { _logger.LogError(ex.Message); return new UserData(); } } public UserData GetUserRecordById(int userId) { try { string cmd = $"SELECT id, username, emailaddress, password, isadmin FROM app.{tableName} WHERE id = @id"; var result = new UserData(); using (var ctext = pgDataSource.CreateCommand(cmd)) { ctext.Parameters.AddWithValue("id", userId); using (NpgsqlDataReader reader = ctext.ExecuteReader()) while (reader.Read()) { result.Id = int.Parse(reader["id"].ToString()); result.UserName = reader["username"].ToString(); result.EmailAddress = reader["emailaddress"].ToString(); result.Password = reader["password"].ToString(); result.IsAdmin = bool.Parse(reader["isadmin"].ToString()); } } return result; } catch (Exception ex) { _logger.LogError(ex.Message); return new UserData(); } } public bool SaveUserRecord(UserData userRecord) { try { if (userRecord.Id == default) { string cmd = $"INSERT INTO app.{tableName} (username, emailaddress, password, isadmin) VALUES(@username, @emailaddress, @password, @isadmin) RETURNING id"; using (var ctext = pgDataSource.CreateCommand(cmd)) { ctext.Parameters.AddWithValue("username", userRecord.UserName); ctext.Parameters.AddWithValue("emailaddress", userRecord.EmailAddress); ctext.Parameters.AddWithValue("password", userRecord.Password); ctext.Parameters.AddWithValue("isadmin", userRecord.IsAdmin); userRecord.Id = Convert.ToInt32(ctext.ExecuteScalar()); return userRecord.Id != default; } } else { string cmd = $"UPDATE app.{tableName} SET username = @username, emailaddress = @emailaddress, password = @password, isadmin = @isadmin WHERE id = @id"; using (var ctext = pgDataSource.CreateCommand(cmd)) { ctext.Parameters.AddWithValue("id", userRecord.Id); ctext.Parameters.AddWithValue("username", userRecord.UserName); ctext.Parameters.AddWithValue("emailaddress", userRecord.EmailAddress); ctext.Parameters.AddWithValue("password", userRecord.Password); ctext.Parameters.AddWithValue("isadmin", userRecord.IsAdmin); return ctext.ExecuteNonQuery() > 0; } } } catch (Exception ex) { _logger.LogError(ex.Message); return false; } } public bool DeleteUserRecord(int userId) { try { string cmd = $"DELETE FROM app.{tableName} WHERE id = @id"; using (var ctext = pgDataSource.CreateCommand(cmd)) { ctext.Parameters.AddWithValue("id", userId); return ctext.ExecuteNonQuery() > 0; } } catch (Exception ex) { _logger.LogError(ex.Message); return false; } } } }