Skip to content

Commit

Permalink
feat(binary uuids): implement binary(16) uuids
Browse files Browse the repository at this point in the history
This commit implements a proof-of-concept binary UUID storage scheme for
the cash module.  The integration tests have been updated accordingly.

**Overview**
The introduction of binary uuids means that a little more work must be
done in the controllers and sql to insert/retrieve data.  Some commands
in Node and SQL have been added to ease this process.  I'll document
these differences as `before` and `after` scenarios.

READ

Before:
```sql
SELECT uuid FROM table;
```

After:
```sql
SELECT BUID(uuid) AS uuid FROM table;
```
**Note**: it is important to alias the column with `AS` in order to
preserve the property name `uuid`.  The command `BUID()` has been added
to our MySQL database instance to convert binary uuids into hexadecimal
uuids.

WRITE

Before:
```js
var insertSql = 'INSERT INTO table SET ?;';
var updateSql = 'UPDATE table SET ? WHERE uuid = ?;';

var data = {
  uuid : /** some uuid */,
  /* other properties ... */
};

db.exec(insertSql, [ data ]).then(/* ... */).catch(/* .. */);
db.exec(updateSql, [ data, req.params.uuid ]).then(/* ... */).catch(/* .. */);
```

After:
```js
var insertSql = 'INSERT INTO table SET ?;';
var updateSql = 'UPDATE table SET ? WHERE uuid = ?;';

var data = {
  uuid : /** some uuid */,
  /* other properties ... */
};

// convert the hex uuid into a binary uuid
data.uuid = db.bid(data.uuid);

// insert with the new data
db.exec(insertSql, [ data ]).then(/* ... */).catch(/* .. */);
db.exec(updateSql, [ data, db.bid(req.params.uuid) ]).then(/* ... */).catch(/* .. */);
```

I'd be curious if we can come up with a better API for binary
conversions.  The currenct method is pragmatic, but possibly unclear.
  • Loading branch information
jniles committed Mar 9, 2016
1 parent e6d44cd commit 0790a1a
Show file tree
Hide file tree
Showing 5 changed files with 112 additions and 81 deletions.
1 change: 1 addition & 0 deletions .jshintrc
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,7 @@
"boss" : false,
"debug" : false,
"eqnull" : false,
"esversion" : 6,
"evil" : false,
"expr" : false,
"funcscope" : false,
Expand Down
110 changes: 57 additions & 53 deletions server/controllers/finance/cash.js
Original file line number Diff line number Diff line change
Expand Up @@ -12,8 +12,8 @@
* currencies. The API accepts a cashbox ID during cash payment creation and
* looks up the correct account based on the cashbox_id + currency.
*/
var db = require('../../lib/db');
var uuid = require('../../lib/guid');
const db = require('../../lib/db');
const uuid = require('node-uuid');

/** retrieves the details of a cash payment */
exports.detail = detail;
Expand All @@ -35,25 +35,29 @@ exports.debitNote = debitNote;

// looks up a single cash record and associated cash_items
// sets the "canceled" flag if a cash_discard record exists.
function lookupCashRecord(uuid, codes) {
function lookupCashRecord(id, codes) {
'use strict';

var record;
var cashRecordSql =
'SELECT cash.uuid, cash.project_id, CONCAT(project.abbr, cash.reference) AS reference, ' +
let record;

const cashRecordSql =
'SELECT BUID(cash.uuid) as uuid, cash.project_id, CONCAT(project.abbr, cash.reference) AS reference, ' +
'cash.date, cash.debtor_uuid, cash.currency_id, cash.amount, ' +
'cash.description, cash.cashbox_id, cash.is_caution, cash.user_id ' +
'FROM cash JOIN project ON cash.project_id = project.id ' +
'WHERE cash.uuid = ?;';

var cashItemsRecordSql =
'SELECT cash_item.uuid, cash_item.amount, cash_item.invoice_uuid ' +
const cashItemsRecordSql =
'SELECT BUID(cash_item.uuid) AS uuid, cash_item.amount, cash_item.invoice_uuid ' +
'FROM cash_item WHERE cash_item.cash_uuid = ?;';

var cashDiscardRecordSql =
'SELECT cash_uuid FROM cash_discard WHERE cash_uuid = ?;';
const cashDiscardRecordSql =
'SELECT BUID(cash_uuid) AS uuid FROM cash_discard WHERE cash_uuid = ?;';

// parse the uuid into a buffer
const buffer = db.bid(id);

return db.exec(cashRecordSql, [uuid])
return db.exec(cashRecordSql, [ buffer ])
.then(function (rows) {

if (rows.length === 0) {
Expand All @@ -63,14 +67,14 @@ function lookupCashRecord(uuid, codes) {
// store the record for return
record = rows[0];

return db.exec(cashItemsRecordSql, [uuid]);
return db.exec(cashItemsRecordSql, [ buffer ]);
})
.then(function (rows) {

// bind the cash items to the "items" property and return
record.items = rows;

return db.exec(cashDiscardRecordSql, [uuid]);
return db.exec(cashDiscardRecordSql, [ buffer ]);
})
.then(function (rows) {

Expand All @@ -84,22 +88,15 @@ function lookupCashRecord(uuid, codes) {

/**
* GET /cash
* TODO - Query Paramters:
* start={date}
* end={date}
* debtor={uuid}
* type={ 'cash' | 'caution' },
* project={id}
*
* Lists the cash payments with optional filtering parameters.
* @returns payments An array of { uuid, reference, date } JSON objects
*
* @returns {array} payments - an array of { uuid, reference, date } JSONs
*/
function list(req, res, next) {
'use strict';

// base query
var sql =
'SELECT cash.uuid, CONCAT(project.abbr, cash.reference) AS reference, ' +
const sql =
'SELECT BUID(cash.uuid) AS uuid, CONCAT(project.abbr, cash.reference) AS reference, ' +
'cash.date, cash.amount ' +
'FROM cash JOIN project ON cash.project_id = project.id;';

Expand Down Expand Up @@ -127,9 +124,9 @@ function list(req, res, next) {
function detail(req, res, next) {
'use strict';

var uuid = req.params.uuid;
const id = req.params.uuid;

lookupCashRecord(uuid, req.codes)
lookupCashRecord(id, req.codes)
.then(function (record) {
res.status(200).json(record);
})
Expand All @@ -140,19 +137,20 @@ function detail(req, res, next) {

/**
* POST /cash
* Creates a cash payment against several sales or a cautionary payment. The
* API also supports future offline functionality by either accepting a UUID or
* generating it if it is not present.
* Creates a cash payment against one or many previous sales or a cautionary
* payment. If a UUID is not provided, one is automatically generated.
*/
function create(req, res, next) {
'use strict';

var data = req.body.payment;
// alias insertion data
let data = req.body.payment;

// generate a UUID if it not provided.
// @TODO - should we validate that this is an _actual_ uuid, or should this
// be sufficient?
data.uuid = data.uuid || uuid();
const id = data.uuid || uuid.v4();

// convert the uuid into a binary buffer
data.uuid = db.bid(id);

// trust the server's session info over the client's
data.project_id = req.session.project.id;
Expand All @@ -162,19 +160,21 @@ function create(req, res, next) {
if (data.date) { data.date = new Date(data.date); }

// account for the cash items
var items = data.items;
let items = data.items;

// remove the cash items so that the SQL query is properly formatted
delete data.items;

// if items exist, tranform them into an array of arrays for db formatting
if (items) {
items = items.map(function (item) {
item.uuid = item.uuid || uuid();
item.uuid = item.uuid || uuid.v4();
item.cash_uuid = data.uuid;
return [
item.uuid, item.cash_uuid,
item.amount, item.sale_uuid
db.bid(item.uuid),
item.cash_uuid,
item.amount,
item.sale_uuid
];
});
}
Expand All @@ -187,14 +187,14 @@ function create(req, res, next) {
});
}

var writeCashSql =
const writeCashSql =
'INSERT INTO cash SET ?;';

var writeCashItemsSql =
const writeCashItemsSql =
'INSERT INTO cash_item (uuid, cash_uuid, amount, invoice_uuid) ' +
'VALUES ?;';

var transaction = db.transaction();
let transaction = db.transaction();
transaction.addQuery(writeCashSql, [ data ]);

// only add the "items" query if we are NOT making a caution
Expand All @@ -205,7 +205,9 @@ function create(req, res, next) {

transaction.execute()
.then(function () {
res.status(201).json({ uuid : data.uuid });
res.status(201).json({
uuid : id
});
})
.catch(next)
.done();
Expand All @@ -216,23 +218,26 @@ function create(req, res, next) {
* PUT /cash/:uuid
* Updates the non-financial details associated with a cash payment.
* NOTE - this will not update the cash_item or cash_discard tables.
*
* @todo - remove protected fields check -- the database should do this
* automatically
*/
function update(req, res, next) {
'use strict';

var uuid = req.params.uuid;
var updateSql = 'UPDATE cash SET ? WHERE uuid = ?;';
const id = req.params.uuid;
const updateSql = 'UPDATE cash SET ? WHERE uuid = ?;';

// protected database fields that are unavailable for updates.
var protect = [
const protect = [
'is_caution', 'amount', 'user_id', 'cashbox_id',
'currency_id', 'date', 'project_id'
];

// loop through update keys and ensure that we are only updating non-protected
// fields
var keys = Object.keys(req.body);
var hasProtectedKey = keys.some(function (key) {
let keys = Object.keys(req.body);
let hasProtectedKey = keys.some(function (key) {
return protect.indexOf(key) > -1;
});

Expand All @@ -248,17 +253,17 @@ function update(req, res, next) {
if (req.body.date) { req.body.date = new Date(req.body.date); }

// if checks pass, we are free to continue with our updates to the db
lookupCashRecord(uuid, req.codes)
lookupCashRecord(id, req.codes)
.then(function (record) {

// if we get here, we know we have a cash record by this UUID.
// we can try to update it.
return db.exec(updateSql, [ req.body, req.params.uuid ]);
return db.exec(updateSql, [ req.body, db.bid(req.params.uuid) ]);
})
.then(function () {

// fetch the changed object from the database
return lookupCashRecord(uuid);
return lookupCashRecord(id);
})
.then(function (record) {

Expand All @@ -280,15 +285,14 @@ function debitNote(req, res, next) {
next();
}


/**
* retrieves cash payment uuids from a reference string (e.g. HBB123)
* GET /cash/references/:reference
* retrieves cash payment uuids from a reference string (e.g. HBB123)
*/
function reference(req, res, next) {

var sql =
'SELECT c.uuid FROM (' +
const sql =
'SELECT BUID(c.uuid) AS uuid FROM (' +
'SELECT cash.uuid, CONCAT(project.abbr, cash.reference) AS reference ' +
'FROM cash JOIN project ON cash.project_id = project.id' +
')c WHERE c.reference = ?;';
Expand Down
18 changes: 17 additions & 1 deletion server/lib/db.js
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,7 @@ var q = require('q');
var mysql = require('mysql');
var winston = require('winston');
var util = require('util');
const uuid = require('node-uuid');

var con;

Expand Down Expand Up @@ -167,11 +168,26 @@ function sanitize(x) {
return con.escape(x);
}

/**
* Converts a (dash separated) string uuid to a binary buffer for insertion
* into the database.
*
* @method bid
* @param {string} hexUuid - a 36 character length string to be inserted into
* the database
* @returns {buffer} uuid - a 16-byte binary buffer for insertion into the
* database
*/
function bid(hexUuid) {
return new Buffer(uuid.parse(hexUuid));
}

module.exports = {
initialise: initialise,
exec: exec,
transaction: transaction,
execute: util.deprecate(execute, 'db.execute() is deprecated, use db.exec() instead.'),
sanitize: util.deprecate(sanitize, 'db.sanitize() is deprecated, use db.escape instead.'),
escape: sanitize
escape: sanitize,
bid: bid
};
46 changes: 34 additions & 12 deletions server/models/updates/synt.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,28 @@

DELETE FROM unit WHERE id = 134;

-- SQL FUNCTIONS

DELIMITER //

-- converts a hex uuid (36 chars) into a binary uuid (16 bytes)
CREATE FUNCTION HUID(_uuid CHAR(36))
RETURNS BINARY(16) DETERMINISTIC
RETURN UNHEX(REPLACE(_uuid, '-', ''));
//

-- converts a binary uuid (16 bytes) to dash-delimited hex UUID (36 characters)
CREATE FUNCTION BUID(b BINARY(16))
RETURNS CHAR(36) DETERMINISTIC
BEGIN
DECLARE hex CHAR(32);
SET hex = HEX(b);
RETURN LCASE(CONCAT_WS('-', SUBSTR(hex,1, 8), SUBSTR(hex, 9,4), SUBSTR(hex, 13,4), SUBSTR(hex, 17,4), SUBSTR(hex, 21, 12)));
END
//

DELIMITER ;

--
-- General upgrades to the entire database
--
Expand Down Expand Up @@ -91,7 +113,7 @@ DROP TABLE cash;

-- schema for cash table
CREATE TABLE `cash` (
`uuid` CHAR(36) NOT NULL,
`uuid` BINARY(16) NOT NULL,
`project_id` SMALLINT(5) UNSIGNED NOT NULL,
`reference` INT(10) UNSIGNED NOT NULL DEFAULT 0,
`date` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
Expand All @@ -117,21 +139,21 @@ CREATE TABLE `cash` (

-- schema for cash_item table
CREATE TABLE `cash_item` (
`uuid` char(36) NOT NULL,
`cash_uuid` char(36) NOT NULL,
`amount` decimal(19,2) unsigned NOT NULL DEFAULT 0.00,
`invoice_uuid` char(36) DEFAULT NULL,
`uuid` BINARY(16) NOT NULL,
`cash_uuid` BINARY(16) NOT NULL,
`amount` DECIMAL(19,2) UNSIGNED NOT NULL DEFAULT 0.00,
`invoice_uuid` CHAR(36) DEFAULT NULL,
PRIMARY KEY (`uuid`),
KEY `cash_uuid` (`cash_uuid`),
FOREIGN KEY (`cash_uuid`) REFERENCES `cash` (`uuid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

-- schema for cash_discard table
CREATE TABLE `cash_discard` (
`uuid` CHAR(36) NOT NULL,
`uuid` BINARY(16) NOT NULL,
`project_id` SMALLINT(5) UNSIGNED NOT NULL,
`reference` INT(10) UNSIGNED NOT NULL,
`cash_uuid` CHAR(36) NOT NULL,
`cash_uuid` BINARY(16) NOT NULL,
`date` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`description` text,
`user_id` SMALLINT(5) UNSIGNED NOT NULL,
Expand All @@ -145,21 +167,21 @@ CREATE TABLE `cash_discard` (
FOREIGN KEY (`cash_uuid`) REFERENCES `cash` (`uuid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

-- new triggers to manage creation of references
CREATE TRIGGER cash_calculate_reference BEFORE INSERT ON cash
-- new triggers to manage creation of references and uuid transforms
CREATE TRIGGER cash_before_insert BEFORE INSERT ON cash
FOR EACH ROW SET NEW.reference = (SELECT IFNULL(MAX(reference) + 1, 1) FROM cash WHERE cash.project_id = new.project_id);

-- migrate data for cash
INSERT INTO `cash` (uuid, project_id, reference, `date`, debtor_uuid, currency_id, amount, user_id, cashbox_id, description, is_caution)
SELECT uuid, project_id, reference, `date`, `deb_cred_uuid`, currency_id, cost, user_id, cashbox_id, description, is_caution
SELECT HUID(uuid), project_id, reference, `date`, `deb_cred_uuid`, currency_id, cost, user_id, cashbox_id, description, is_caution
FROM `cash_migrate`;

INSERT INTO `cash_item` (uuid, cash_uuid, amount, invoice_uuid)
SELECT uuid, cash_uuid, allocated_cost, invoice_uuid
SELECT HUID(uuid), HUID(cash_uuid), allocated_cost, invoice_uuid
FROM `cash_item_migrate`;

INSERT INTO `cash_discard` (uuid, project_id, reference, cash_uuid, `date`, description, user_id)
SELECT uuid, project_id, reference, cash_uuid, `date`, description, 1
SELECT HUID(uuid), project_id, reference, HUID(cash_uuid), `date`, description, 1
FROM `cash_discard_migrate`;

--
Expand Down
Loading

0 comments on commit 0790a1a

Please sign in to comment.