Skip to content

Commit

Permalink
Implementation of the changes for session management persistence to t…
Browse files Browse the repository at this point in the history
…he database #102

Added all database schema changes and new functions for the above.
Created function and schema constants for the database calls and integrated them into the DAL layer.
  • Loading branch information
Chris Morris committed Jan 12, 2021
1 parent 0b7246b commit 5b3ba22
Show file tree
Hide file tree
Showing 34 changed files with 939 additions and 125 deletions.
51 changes: 51 additions & 0 deletions database/functions/R__caching.date_diff.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,51 @@
create or replace function caching.date_diff
(
_units character varying,
_start_t timestamp with time zone,
_end_t timestamp with time zone
)
returns integer
as $$
declare _diff_interval interval;
declare _diff integer = 0;
declare _years_diff integer = 0;
begin
if(_units in ('yy', 'yyyy', 'year', 'mm', 'm', 'month')) then
_years_diff = date_part('year', _end_t) - datepart('year', _start_t);

if(_units in ('yy', 'yyyy', 'year')) then
return _years_diff;
else
return _years_diff * 12 + (date_part('month', _end_t) - date_part('month', _start_t));
end if;
end if;

_diff_interval = _end_t - _start_t;
_diff = _diff + date_part('day', _diff_interval);

if(_units in ('wk', 'ww', 'week')) then
_diff = _diff / 7;
return _diff;
end if;

if(_units in ('dd', 'd', 'day')) then
return _diff;
end if;

_diff = _diff * 24 + date_part('hour', _diff_interval);

if(_units in ('hh', 'hour')) then
return _diff;
end if;

_diff = _diff * 60 + date_part('minute', _diff_interval);

if(_units in ('mi', 'n', 'minute')) then
return _diff;
end if;

_diff = _diff * 60 + date_part('second', _diff_interval);

return _diff;
end;
$$ language plpgsql;
13 changes: 13 additions & 0 deletions database/functions/R__caching.delete_cache_item.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
create or replace function caching.delete_cache_item
(
_dist_cache_id text
)
returns void
as $$
begin
delete from
caching.dist_cache
where
Id = _dist_cache_id;
end;
$$ language plpgsql;
13 changes: 13 additions & 0 deletions database/functions/R__caching.delete_expired_cache_items.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
create or replace function caching.delete_expired_cache_items
(
_utc_now timestamp with time zone
)
returns void
as $$
begin
delete from
caching.dist_cache
where
_utc_now > ExpiresAtTime;
end;
$$ language plpgsql;
22 changes: 22 additions & 0 deletions database/functions/R__caching.get_cache_item.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
create or replace function caching.get_cache_item
(
_dist_cache_id text,
_utc_now timestamp with time zone
)
returns table(Id text, Value bytea, ExpiresAtTime timestamp with time zone, SlidingExpirationInSeconds double precision, AbsoluteExpiration timestamp with time zone)
as $$
begin
return query
select
dc.Id,
dc.Value,
dc.ExpiresAtTime,
dc.SlidingExpirationInSeconds,
dc.AbsoluteExpiration
from
caching.dist_cache dc
where
dc.Id = _dist_cache_id
and _utc_now <= dc.ExpiresAtTime;
end;
$$ language plpgsql;
52 changes: 52 additions & 0 deletions database/functions/R__caching.set_cache.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
create or replace function caching.set_cache
(
_dist_cache_id text,
_dist_cache_value bytea,
_dist_cache_sliding_expiration_seconds double precision,
_dist_cache_absolute_expiration timestamp with time zone,
_utc_now timestamp with time zone
)
returns void
as $$
declare _expires_at_time timestamp(6) with time zone;
declare _row_count integer;
begin
case
when (_dist_cache_sliding_expiration_seconds is null)
then _expires_at_time := _dist_cache_absolute_expiration;
else
_expires_at_time := _utc_now + _dist_cache_sliding_expiration_seconds * interval '1 second';
end case;

update
caching.dist_cache
set
Value = _dist_cache_value,
ExpiresAtTime = _expires_at_time,
SlidingExpirationInSeconds = _dist_cache_sliding_expiration_seconds,
AbsoluteExpiration = _dist_cache_absolute_expiration
where
Id = _dist_cache_id;

get diagnostics _row_count := ROW_COUNT;

if(_row_count = 0) then
insert into caching.dist_cache
(
Id,
Value,
ExpiresAtTime,
SlidingExpirationInSeconds,
AbsoluteExpiration
)
values
(
_dist_cache_id,
_dist_cache_value,
_expires_at_time,
_dist_cache_sliding_expiration_seconds,
_dist_cache_absolute_expiration
);
end if;
end;
$$ language plpgsql;
24 changes: 24 additions & 0 deletions database/functions/R__caching.update_cache_item.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
create or replace function caching.update_cache_item
(
_dist_cache_id text,
_utc_now timestamp with time zone
)
returns void
as $$
begin
update
caching.dist_cache
set
ExpiresAtTime =
case when
(select caching.date_diff('seconds', _utc_now, AbsoluteExpiration) <= SlidingExpirationInSeconds)
then AbsoluteExpiration
else _utc_now + SlidingExpirationInSeconds * interval '1 second'
end
where
Id = _dist_cache_id
and _utc_now <= ExpiresAtTime
and SlidingExpirationInSeconds is not null
and (AbsoluteExpiration is null or AbsoluteExpiration <> ExpiresAtTime);
end;
$$ language plpgsql;
19 changes: 19 additions & 0 deletions database/schema/V2.1__schema.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
create schema caching;

drop table caching.dist_cache;

create table caching.dist_cache
(
Id text not null,
Value bytea,
ExpiresAtTime timestamp with time zone,
SlidingExpirationInSeconds double precision,
AbsoluteExpiration timestamp with time zone,

constraint caching_distcache_id_pk primary key (Id)
);

grant usage on schema caching to app_user;
grant select, insert, update, delete on all tables in schema caching to app_user;
grant select, update on all sequences in schema caching to app_user;
grant execute on all functions in schema caching to app_user;
Original file line number Diff line number Diff line change
Expand Up @@ -11,67 +11,52 @@ public class ApplicationService : IApplicationService
{
private readonly ILogger<ApplicationService> _logger;
private readonly IDataService _dataService;
private readonly IAuditService _auditService;

public ApplicationService(IConfiguration configuration, ILogger<ApplicationService> logger, IDataService dataService, IAuditService auditService)
public ApplicationService(IConfiguration configuration, ILogger<ApplicationService> logger, IDataService dataService)
{
_logger = logger;
_dataService = dataService;
_auditService = auditService;
}

public DTO.Response.Application.Organisation GetOrganisation(string odsCode)
{
var functionName = "application.get_organisation";
var parameters = new DynamicParameters();
parameters.Add("_ods_code", odsCode, DbType.String, ParameterDirection.Input);
var result = _dataService.ExecuteFunction<DTO.Response.Application.Organisation>(functionName, parameters);
var result = _dataService.ExecuteFunction<DTO.Response.Application.Organisation>(Constants.Schemas.Application, Constants.Functions.GetOrganisation, parameters);
return result.FirstOrDefault();
}

public void SynchroniseOrganisation(DTO.Response.Application.Organisation organisation)
{
var functionName = "application.synchronise_organisation";
var parameters = new DynamicParameters();
parameters.Add("_ods_code", organisation.ODSCode);
parameters.Add("_organisation_type_name", organisation.OrganisationTypeCode);
parameters.Add("_organisation_name", organisation.OrganisationName);
parameters.Add("_address_line_1", organisation.PostalAddressFields[0]);
parameters.Add("_address_line_2", organisation.PostalAddressFields[1]);
parameters.Add("_locality", organisation.PostalAddressFields[2]);
parameters.Add("_city", organisation.PostalAddressFields[3]);
parameters.Add("_county", organisation.PostalAddressFields.Length > 4 ? organisation.PostalAddressFields[4] : string.Empty);
parameters.Add("_postcode", organisation.PostalCode);
_dataService.ExecuteFunction(functionName, parameters);
parameters.Add("_ods_code", organisation.ODSCode, DbType.String, ParameterDirection.Input);
parameters.Add("_organisation_type_name", organisation.OrganisationTypeCode, DbType.String, ParameterDirection.Input);
parameters.Add("_organisation_name", organisation.OrganisationName, DbType.String, ParameterDirection.Input);
parameters.Add("_address_line_1", organisation.PostalAddressFields[0], DbType.String, ParameterDirection.Input);
parameters.Add("_address_line_2", organisation.PostalAddressFields[1], DbType.String, ParameterDirection.Input);
parameters.Add("_locality", organisation.PostalAddressFields[2], DbType.String, ParameterDirection.Input);
parameters.Add("_city", organisation.PostalAddressFields[3], DbType.String, ParameterDirection.Input);
parameters.Add("_county", organisation.PostalAddressFields.Length > 4 ? organisation.PostalAddressFields[4] : string.Empty, DbType.String, ParameterDirection.Input);
parameters.Add("_postcode", organisation.PostalCode, DbType.String, ParameterDirection.Input);
_dataService.ExecuteFunction(Constants.Schemas.Application, Constants.Functions.SynchroniseOrganisation, parameters);
}
public DTO.Response.Application.User LogonUser(DTO.Request.Application.User user)
{
var functionName = "application.logon_user";
var parameters = new DynamicParameters();
parameters.Add("_email_address", user.EmailAddress);
parameters.Add("_display_name", user.DisplayName);
parameters.Add("_organisation_id", user.OrganisationId);
var result = _dataService.ExecuteFunction<DTO.Response.Application.User>(functionName, parameters);
parameters.Add("_email_address", user.EmailAddress, DbType.String, ParameterDirection.Input);
parameters.Add("_display_name", user.DisplayName, DbType.String, ParameterDirection.Input);
parameters.Add("_organisation_id", user.OrganisationId, DbType.Int32, ParameterDirection.Input);
var result = _dataService.ExecuteFunction<DTO.Response.Application.User>(Constants.Schemas.Application, Constants.Functions.LogonUser, parameters);
return result.FirstOrDefault();
}

public DTO.Response.Application.User LogoffUser(DTO.Request.Application.User user)
{
var functionName = "application.logoff_user";
var parameters = new DynamicParameters();
parameters.Add("_email_address", user.EmailAddress);
parameters.Add("_user_session_id", user.UserSessionId);
var result = _dataService.ExecuteFunction<DTO.Response.Application.User>(functionName, parameters);
parameters.Add("_email_address", user.EmailAddress, DbType.String, ParameterDirection.Input);
parameters.Add("_user_session_id", user.UserSessionId, DbType.Int32, ParameterDirection.Input);
var result = _dataService.ExecuteFunction<DTO.Response.Application.User>(Constants.Schemas.Application, Constants.Functions.LogoffUser, parameters);
return result.FirstOrDefault();
}

public void SetUserAuthorised(DTO.Request.Application.User user)
{
var functionName = "application.set_user_isauthorised";
var parameters = new DynamicParameters();
parameters.Add("_email_address", user.EmailAddress);
parameters.Add("_is_authorised", user.IsAuthorised);
_dataService.ExecuteFunction(functionName, parameters);
}
}
}
23 changes: 11 additions & 12 deletions source/gpconnect-appointment-checker.DAL/Audit/AuditService.cs
Original file line number Diff line number Diff line change
Expand Up @@ -20,31 +20,30 @@ public AuditService(IDataService dataService, IHttpContextAccessor context)

public void AddEntry(DTO.Request.Audit.Entry auditEntry)
{
var functionName = "audit.add_entry";
var parameters = new DynamicParameters();
if (_context.HttpContext?.User?.GetClaimValue("UserId", nullIfEmpty: true) != null)
{
parameters.Add("_user_id", Convert.ToInt32(_context.HttpContext?.User?.GetClaimValue("UserId")), DbType.Int32);
parameters.Add("_user_id", Convert.ToInt32(_context.HttpContext?.User?.GetClaimValue("UserId")), DbType.Int32, ParameterDirection.Input);
}
else
{
parameters.Add("_user_id", DBNull.Value, DbType.Int32);
parameters.Add("_user_id", DBNull.Value, DbType.Int32, ParameterDirection.Input);
}
if (_context.HttpContext?.User?.GetClaimValue("UserSessionId", nullIfEmpty: true) != null)
{
parameters.Add("_user_session_id", Convert.ToInt32(_context.HttpContext?.User?.GetClaimValue("UserSessionId")), DbType.Int32);
parameters.Add("_user_session_id", Convert.ToInt32(_context.HttpContext?.User?.GetClaimValue("UserSessionId")), DbType.Int32, ParameterDirection.Input);
}
else
{
parameters.Add("_user_session_id", DBNull.Value, DbType.Int32);
parameters.Add("_user_session_id", DBNull.Value, DbType.Int32, ParameterDirection.Input);
}
parameters.Add("_entry_type_id", auditEntry.EntryTypeId);
parameters.Add("_item1", auditEntry.Item1);
parameters.Add("_item2", auditEntry.Item2);
parameters.Add("_item3", auditEntry.Item3);
parameters.Add("_details", auditEntry.Details);
parameters.Add("_entry_elapsed_ms", auditEntry.EntryElapsedMs);
_dataService.ExecuteFunction(functionName, parameters);
parameters.Add("_entry_type_id", auditEntry.EntryTypeId, DbType.Int32, ParameterDirection.Input);
parameters.Add("_item1", auditEntry.Item1, DbType.String, ParameterDirection.Input);
parameters.Add("_item2", auditEntry.Item2, DbType.String, ParameterDirection.Input);
parameters.Add("_item3", auditEntry.Item3, DbType.String, ParameterDirection.Input);
parameters.Add("_details", auditEntry.Details, DbType.String, ParameterDirection.Input);
parameters.Add("_entry_elapsed_ms", auditEntry.EntryElapsedMs, DbType.Int32, ParameterDirection.Input);
_dataService.ExecuteFunction(Constants.Schemas.Audit, Constants.Functions.AddEntry, parameters);
}
}
}
Loading

0 comments on commit 5b3ba22

Please sign in to comment.