Skip to content
This repository has been archived by the owner on Jan 28, 2024. It is now read-only.

Commit

Permalink
Merge pull request #1 from Fdawgs/feat/sql-connections
Browse files Browse the repository at this point in the history
Add route functionality
  • Loading branch information
Fdawgs committed Jan 7, 2021
2 parents 585ae91 + 4664590 commit 991b616
Show file tree
Hide file tree
Showing 16 changed files with 963 additions and 77 deletions.
13 changes: 7 additions & 6 deletions .env.template
Original file line number Diff line number Diff line change
Expand Up @@ -54,17 +54,18 @@ AUTH_BEARER_TOKEN_ARRAY=[{"service": "test", "value": "testtoken"}]

### Database connection ###################################

DB_USER=
DB_PASSWORD=
DB_SERVER=
DB_DATABASE=
# Examples:
# 'mssql://username:password@localhost/database'
# 'Server=localhost,1433;Database=database;User Id=username;Password=password;Encrypt=true'
DB_CONNECTION_STRING=

# PATIENT PREFERENCES
# Name and schema of patient preferences table
DB_PATIENT_PREFERENCES_TABLE='patient.preferences'
# Name and schema of patient preferences type table
DB_PATIENT_PREFERENCE_VALUE_TABLE='lookup.preferenceValue'
DB_PATIENT_PREFERENCES_VALUE_TABLE='lookup.preferenceValue'
# Name and schema of patient preference value table
DB_PATIENT_PREFERENCE_TYPE_TABLE='lookup.preferenceType'
DB_PATIENT_PREFERENCES_TYPE_TABLE='lookup.preferenceType'
# READ RECEIPTS
# Name and schema of document read receipt table
DB_READ_RECEIPT_DOCS_TABLE='receipt.documents'
Expand Down
2 changes: 1 addition & 1 deletion README.md
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@ This is [Yeovil District Hospital NHSFT](https://yeovilhospital.co.uk/)'s backen

- [Node.js](https://nodejs.org/en/)
- [SQL Server](https://www.microsoft.com/en-gb/sql-server/sql-server-downloads)
- [Yarn](https://yarnpkg.com)
- [Yarn](https://classic.yarnpkg.com)

## Deployment

Expand Down
3 changes: 2 additions & 1 deletion package.json
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,7 @@
"changelog": "conventional-changelog -p @commitlint/config-conventional -s -i CHANGELOG.md && prettier CHANGELOG.md --write",
"jest": "jest --detectOpenHandles --runInBand",
"jest-coverage": "jest --coverage --runInBand",
"license-checker": "license-checker --production --summary --onlyAllow=\"MIT;ISC;BSD-3-Clause;BSD-2-Clause\" --excludePackages=\"obfuscated-querystring@0.0.2\"",
"license-checker": "license-checker --production --summary",
"lint": "eslint . --cache --ext js,jsx,ts,tsx --ignore-path .gitignore",
"lint:prettier": "prettier . --write --ignore-path .gitignore",
"lint:prettier:ci": "prettier . --check --ignore-path .gitignore",
Expand Down Expand Up @@ -84,6 +84,7 @@
"file-stream-rotator": "^0.5.7",
"fluent-json-schema": "^2.0.3",
"http-errors": "^1.8.0",
"mssql": "^6.3.1",
"pino": "^6.9.0"
}
}
24 changes: 24 additions & 0 deletions src/config/config.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,13 @@ describe("configuration", () => {
]);
const AUTH_BEARER_TOKEN_ARRAY =
'[{"service": "test", "value": "testtoken"}]';
const DB_CONNECTION_STRING =
"Server=localhost,1433;Database=database;User Id=username;Password=password;Encrypt=true";
const DB_DOCUMENT_REGISTER_TABLE = "YDHAPPDOC.dbo.SPINDEX";
const DB_PATIENT_PREFERENCES_TABLE = "patient.preferences";
const DB_PATIENT_PREFERENCES_TYPE_TABLE = "lookup.preferenceType";
const DB_PATIENT_PREFERENCES_VALUE_TABLE = "lookup.preferenceValue";
const DB_READ_RECEIPT_DOCS_TABLE = "receipt.documents";

Object.assign(process.env, {
SERVICE_HOST,
Expand All @@ -36,6 +43,12 @@ describe("configuration", () => {
CORS_ORIGIN,
LOG_LEVEL,
AUTH_BEARER_TOKEN_ARRAY,
DB_CONNECTION_STRING,
DB_DOCUMENT_REGISTER_TABLE,
DB_PATIENT_PREFERENCES_TABLE,
DB_PATIENT_PREFERENCES_TYPE_TABLE,
DB_PATIENT_PREFERENCES_VALUE_TABLE,
DB_READ_RECEIPT_DOCS_TABLE,
});

const config = await getConfig();
Expand Down Expand Up @@ -69,6 +82,17 @@ describe("configuration", () => {
methods: ["Accept"],
allowedHeaders: ["GET", "OPTIONS"],
});

expect(config.database).toEqual({
connection: DB_CONNECTION_STRING,
tables: {
documentRegister: DB_DOCUMENT_REGISTER_TABLE,
patientPref: DB_PATIENT_PREFERENCES_TABLE,
patientPrefTypeLookup: DB_PATIENT_PREFERENCES_TYPE_TABLE,
patientPrefValueLookup: DB_PATIENT_PREFERENCES_VALUE_TABLE,
readReceipt: DB_READ_RECEIPT_DOCS_TABLE,
},
});
});

test("Should return values according to environment variables - PFX enabled and CORS enabled", async () => {
Expand Down
18 changes: 17 additions & 1 deletion src/config/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -63,7 +63,13 @@ async function getConfig() {
)
.prop("LOG_ROTATION_MAX_LOGS", S.anyOf([S.string(), S.null()]))
.prop("LOG_ROTATION_MAX_SIZE", S.anyOf([S.string(), S.null()]))
.prop("AUTH_BEARER_TOKEN_ARRAY", S.anyOf([S.string(), S.null()])),
.prop("AUTH_BEARER_TOKEN_ARRAY", S.anyOf([S.string(), S.null()]))
.prop("DB_CONNECTION_STRING", S.string())
.prop("DB_DOCUMENT_REGISTER_TABLE", S.string())
.prop("DB_PATIENT_PREFERENCES_TABLE", S.string())
.prop("DB_PATIENT_PREFERENCES_TYPE_TABLE", S.string())
.prop("DB_PATIENT_PREFERENCES_VALUE_TABLE", S.string())
.prop("DB_READ_RECEIPT_DOCS_TABLE", S.string()),
});

const config = {
Expand Down Expand Up @@ -120,6 +126,16 @@ async function getConfig() {
},
},
},
database: {
connection: env.DB_CONNECTION_STRING,
tables: {
documentRegister: env.DB_DOCUMENT_REGISTER_TABLE,
patientPref: env.DB_PATIENT_PREFERENCES_TABLE,
patientPrefTypeLookup: env.DB_PATIENT_PREFERENCES_TYPE_TABLE,
patientPrefValueLookup: env.DB_PATIENT_PREFERENCES_VALUE_TABLE,
readReceipt: env.DB_READ_RECEIPT_DOCS_TABLE,
},
},
};

if (env.AUTH_BEARER_TOKEN_ARRAY) {
Expand Down
41 changes: 41 additions & 0 deletions src/plugins/fastify-mssql/index.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
const fastifyPlugin = require("fastify-plugin");
const sql = require("mssql");

/**
* @author Frazer Smith
* @description Decorator plugin that adds Microsoft SQL Server client.
* @param {Function} server - Fastify instance.
* @param {object|string} options - mssql configuration values either as an object with options or as a connection string.
* Example connection string: `mssql://username:password@localhost/database`.
* @param {string=} options.user - User name to use for authentication.
* @param {string=} options.password - Password to use for authentication.
* @param {string} options.server - Server to connect to.
* You can use 'localhost\instance' to connect to named instance.
* @param {number=} options.port - Port to connect to (default: `1433`).
* Do not set when connecting to named instance.
* @param {string=} options.domain - Once you set domain, driver will
* connect to SQL Server using domain login.
* @param {string=} options.database - Database to connect to
* (default: dependent on server configuration).
* @param {number=} options.connectionTimeout - Connection timeout in ms
* (default: `15000`).
* @param {number=} options.requestTimeout - Request timeout in ms
* (default: `15000`).
* NOTE: msnodesqlv8 driver doesn't support timeouts < 1 second.
* When passed via connection string, the key must be `request timeout`
* @param {boolean=} options.stream - Stream recordsets/rows instead of returning
* them all at once as an argument of callback (default: `false`).
* You can also enable streaming for each request independently (`request.stream = true`).
* Always set to true if you plan to work with large amount of rows.
* @param {boolean=} options.parseJSON - Parse JSON recordsets to JS objects
* (default: `false`).
* @param {object=} options.pool - See pool options here: https://github.com/vincit/tarn.js/#usage
*/
async function plugin(server, options) {
const mssql = await sql.connect(options);

server.decorate("mssql", mssql);
server.addHook("onClose", async (instance, done) => mssql.close(done));
}

module.exports = fastifyPlugin(plugin);
150 changes: 147 additions & 3 deletions src/routes/documents/index.js
Original file line number Diff line number Diff line change
@@ -1,3 +1,9 @@
const createError = require("http-errors");
const sqlServer = require("mssql");

const clean = require("../../utils/clean-objects");
const convertDateParamOperator = require("../../utils/convert-date-param-operation");

const {
registerGetSchema,
receiptPutSchema,
Expand All @@ -16,7 +22,89 @@ async function route(server, options) {
url: "/register",
schema: registerGetSchema,
async handler(req, res) {
res.send("hi");
try {
const page = parseInt(req.query.page, 10) - 1 || 0;
const perPage = parseInt(req.query.perPage, 10) || 1;

// Build WHERE clause using lastModified querystring param
const operator = convertDateParamOperator(
escape(req.query.lastModified).substring(0, 2)
);
// eslint-disable-next-line no-restricted-globals
if (isNaN(req.query.lastModified.substring(0, 2))) {
req.query.lastModified = req.query.lastModified.substring(
2,
req.query.lastModified.length
);
}

// Create meta object with pagination data
const count = await server.mssql
.request()
.input(
"timestamp",
sqlServer.DateTime,
req.query.lastModified
).query(`SELECT COUNT(*) AS total
FROM ${options.database.tables.documentRegister}
WHERE Modified ${operator} @timestamp`);

const result = {
data: [],
meta: {
pagination: {
total: count.recordset[0].total,
per_page: perPage,
current_page: page + 1,
total_pages: Math.ceil(
count.recordset[0].total / perPage
),
},
},
};

const queryResult = await server.mssql
.request()
.input(
"timestamp",
sqlServer.DateTime,
req.query.lastModified
)
.query(
`SELECT GUID AS 'guid',
fhir_id,
Title AS 'title',
Specialty AS 'specialty',
Clinic AS 'clinic',
Document_Type AS 'document_type',
Filesname AS 'file_name',
URL AS 'url',
CreatedDate AS 'created_date',
Modified AS 'modified'
FROM ${options.database.tables.documentRegister}
WHERE Modified ${operator} @timestamp
ORDER BY Modified DESC
OFFSET ${page * perPage} ROWS
FETCH NEXT ${perPage} ROWS ONLY`
);

if (
queryResult.recordset &&
queryResult.recordset.length !== 0
) {
result.data = clean(queryResult.recordset);
res.send(result);
} else {
res.send(
createError(404, "Invalid or expired search results")
);
}
} catch (err) {
server.log.error(err);
res.send(
createError(500, "Unable to return result(s) from database")
);
}
},
});

Expand All @@ -25,7 +113,39 @@ async function route(server, options) {
url: "/receipt/:id",
schema: receiptPutSchema,
async handler(req, res) {
res.send("hi");
try {
await server.mssql
.request()
.input("guid", sqlServer.Char(36), req.params.id)
.input(
"patientId",
sqlServer.VarChar(255),
req.query.patientId
)
.input("timestamp", sqlServer.VarChar, req.query.timestamp)
.query(
`IF EXISTS(SELECT guid
FROM ${options.database.tables.readReceipt}
WHERE guid = @guid
AND patientId = @patientId)
UPDATE ${options.database.tables.readReceipt}
SET ts = @timestamp
WHERE guid = @guid
AND patientId = @patientId
ELSE
INSERT INTO ${options.database.tables.readReceipt} (guid, patientId, ts)
VALUES(@guid, @patientId, @timestamp)`
);
res.status(204);
} catch (err) {
server.log.error(err);
res.send(
createError(
500,
"Unable to update read receipt in database"
)
);
}
},
});

Expand All @@ -34,7 +154,31 @@ async function route(server, options) {
url: "/receipt/:id",
schema: receiptDeleteSchema,
async handler(req, res) {
res.send("hi");
try {
await server.mssql
.request()
.input("guid", sqlServer.Char(36), req.params.id)
.input(
"patientId",
sqlServer.VarChar(255),
req.query.patientId
)
.query(
`DELETE
FROM ${options.database.tables.readReceipt}
WHERE guid = @guid
AND patientId = @patientId`
);
res.status(204);
} catch (err) {
server.log.error(err);
res.send(
createError(
500,
"Unable to update delete read receipt from database"
)
);
}
},
});
}
Expand Down
Loading

0 comments on commit 991b616

Please sign in to comment.