From fec57bf1735936401d58d24228629acd1b34f5d0 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?S=C3=A9rgio=20Salgado?= Date: Mon, 6 Sep 2021 16:45:02 +0100 Subject: [PATCH] feat: add migration to add customer custom fields related tables feat: create CustomerCustomField type on graphql feat: add custom fields fetching to getCustomer and getCustomerList functions feat: add mutations to interact with customer custom fields --- lib/customers.js | 87 +++++++++++++++++-- .../graphql/resolvers/customer.resolver.js | 5 +- lib/new-admin/graphql/types/customer.type.js | 11 +++ .../1630624117042-customer-custom-fields.js | 23 +++++ 4 files changed, 118 insertions(+), 8 deletions(-) create mode 100644 migrations/1630624117042-customer-custom-fields.js diff --git a/lib/customers.js b/lib/customers.js index 3e2ba76c..c7aa00e3 100644 --- a/lib/customers.js +++ b/lib/customers.js @@ -479,7 +479,7 @@ function getCustomersList (phone = null, name = null, address = null, id = null) phone, sms_override, id_card_data, id_card_data_override, id_card_data_expiration, id_card_photo_path, id_card_photo_override, us_ssn, us_ssn_override, sanctions, sanctions_at, sanctions_override, total_txs, total_spent, created AS last_active, fiat AS last_tx_fiat, - fiat_code AS last_tx_fiat_code, tx_class AS last_tx_class + fiat_code AS last_tx_fiat_code, tx_class AS last_tx_class, custom_fields FROM ( SELECT c.id, c.authorized_override, greatest(0, date_part('day', c.suspended_until - NOW())) AS days_suspended, @@ -488,14 +488,21 @@ function getCustomersList (phone = null, name = null, address = null, id = null) c.phone, c.sms_override, c.id_card_data, c.id_card_data_override, c.id_card_data_expiration, c.id_card_photo_path, c.id_card_photo_override, c.us_ssn, c.us_ssn_override, c.sanctions, c.sanctions_at, c.sanctions_override, t.tx_class, t.fiat, t.fiat_code, t.created, - ROW_NUMBER() OVER (PARTITION BY c.id ORDER BY t.created desc) AS rn, - COALESCE(SUM(CASE WHEN error_code IS NULL OR error_code NOT IN ($1^) THEN t.fiat ELSE 0 END) OVER (PARTITION BY c.id), 0) AS total_spent, - SUM(CASE WHEN t.id IS NOT NULL THEN 1 ELSE 0 END) OVER (PARTITION BY c.id) AS total_txs + row_number() OVER (partition by c.id order by t.created desc) AS rn, + coalesce(sum(case when error_code is null or error_code not in ($1^) then t.fiat else 0 end) over (partition by c.id), 0) as total_spent, + sum(CASE WHEN t.id IS NOT NULL THEN 1 ELSE 0 END) OVER (partition by c.id) AS total_txs, + coalesce(sum(t.fiat) OVER (partition by c.id), 0) AS total_spent, ccf.custom_fields FROM customers c LEFT OUTER JOIN ( SELECT 'cashIn' AS tx_class, id, fiat, fiat_code, created, customer_id, error_code FROM cash_in_txs WHERE send_confirmed = true UNION SELECT 'cashOut' AS tx_class, id, fiat, fiat_code, created, customer_id, error_code FROM cash_out_txs WHERE confirmed_at IS NOT NULL) AS t ON c.id = t.customer_id + LEFT OUTER JOIN ( + SELECT cf.customer_id, json_agg(json_build_object('id', cf.custom_field_id, 'label', cf.label, 'value', cf.value)) AS custom_fields FROM ( + SELECT ccfp.custom_field_id, ccfp.customer_id, cfd.label, ccfp.value FROM custom_field_definitions cfd + LEFT OUTER JOIN customer_custom_field_pairs ccfp ON cfd.id = ccfp.custom_field_id + ) cf GROUP BY cf.customer_id + ) ccf ON c.id = ccf.customer_id WHERE c.id != $2 ) AS cl WHERE rn = 1 AND ($4 IS NULL OR phone = $4) @@ -523,7 +530,7 @@ function getCustomerById (id) { phone, sms_override, id_card_data, id_card_data_override, id_card_data_expiration, id_card_photo_path, id_card_photo_override, us_ssn, us_ssn_override, sanctions, sanctions_at, sanctions_override, total_txs, total_spent, created as last_active, fiat as last_tx_fiat, - fiat_code as last_tx_fiat_code, tx_class as last_tx_class, subscriber_info + fiat_code as last_tx_fiat_code, tx_class as last_tx_class, subscriber_info, custom_fields from ( select c.id, c.authorized_override, greatest(0, date_part('day', c.suspended_until - now())) as days_suspended, @@ -534,12 +541,18 @@ function getCustomerById (id) { c.sanctions_at, c.sanctions_override, c.subscriber_info, t.tx_class, t.fiat, t.fiat_code, t.created, row_number() over (partition by c.id order by t.created desc) as rn, sum(case when t.id is not null then 1 else 0 end) over (partition by c.id) as total_txs, - sum(case when error_code is null or error_code not in ($1^) then t.fiat else 0 end) over (partition by c.id) as total_spent + sum(case when error_code is null or error_code not in ($1^) then t.fiat else 0 end) over (partition by c.id) as total_spent, ccf.custom_fields from customers c left outer join ( select 'cashIn' as tx_class, id, fiat, fiat_code, created, customer_id, error_code from cash_in_txs where send_confirmed = true union select 'cashOut' as tx_class, id, fiat, fiat_code, created, customer_id, error_code from cash_out_txs where confirmed_at is not null) t on c.id = t.customer_id + LEFT OUTER JOIN ( + SELECT cf.customer_id, json_agg(json_build_object('id', cf.custom_field_id, 'label', cf.label, 'value', cf.value)) AS custom_fields FROM ( + SELECT ccfp.custom_field_id, ccfp.customer_id, cfd.label, ccfp.value FROM custom_field_definitions cfd + LEFT OUTER JOIN customer_custom_field_pairs ccfp ON cfd.id = ccfp.custom_field_id + ) cf GROUP BY cf.customer_id + ) ccf ON c.id = ccf.customer_id where c.id = $2 ) as cl where rn = 1` return db.oneOrNone(sql, [passableErrorCodes, id]) @@ -755,4 +768,64 @@ function updateFrontCamera (id, patch) { }) } -module.exports = { add, get, batch, getCustomersList, getCustomerById, getById, update, updateCustomer, updatePhotoCard, updateFrontCamera, updateIdCardData, updateTxCustomerPhoto } +function addCustomField(customerId, label, value) { + const sql = `SELECT * FROM custom_field_definitions WHERE label=$1 LIMIT 1` + return db.oneOrNone(sql, [label]) + .then(res => db.tx(t => { + if (_.isNil(res)) { + const fieldId = uuid.v4() + const q1 = t.none(`INSERT INTO custom_field_definitions (id, label) VALUES ($1, $2)`, [fieldId, label]) + const q2 = t.none(`INSERT INTO customer_custom_field_pairs (customer_id, custom_field_id, value) VALUES ($1, $2, $3)`, [customerId, fieldId, value]) + return t.batch([q1, q2]) + } + + if (!_.isNil(res) && !res.active) { + const q1 = t.none(`UPDATE custom_field_definitions SET active = true WHERE id=$1`, [res.id]) + const q2 = t.none(`INSERT INTO customer_custom_field_pairs (customer_id, custom_field_id, value) VALUES ($1, $2, $3)`, [customerId, res.id, value]) + return t.batch([q1, q2]) + } else if (!_.isNil(res) && res.active) { + const q1 = t.none(`INSERT INTO customer_custom_field_pairs (customer_id, custom_field_id, value) VALUES ($1, $2, $3)`, [customerId, res.id, value]) + return t.batch([q1]) + } + }) + ) +} + +function saveCustomField(customerId, fieldId, newValue) { + const sql = `UPDATE customer_custom_field_pairs SET value=$1 WHERE customer_id=$2 AND custom_field_id=$3` + return db.none(sql, [newValue, customerId, fieldId]) +} + +function removeCustomField(customerId, fieldId) { + const sql = `SELECT * FROM customer_custom_field_pairs WHERE custom_field_id=$1` + return db.any(sql, [fieldId]) + .then(res => db.tx(t => { + // Is the field to be removed the only one of its kind in the pairs table? + if (_.size(res) === 1) { + const q1 = t.none(`DELETE FROM customer_custom_field_pairs WHERE customer_id=$1 AND custom_field_id=$2`, [customerId, fieldId]) + const q2 = t.none(`UPDATE custom_field_definitions SET active = false WHERE id=$1`, [fieldId]) + return t.batch([q1, q2]) + } else { + const q1 = t.none(`DELETE FROM customer_custom_field_pairs WHERE customer_id=$1 AND custom_field_id=$2`, [customerId, fieldId]) + return t.batch([q1]) + } + })) +} + +module.exports = { + add, + get, + batch, + getCustomersList, + getCustomerById, + getById, + update, + updateCustomer, + updatePhotoCard, + updateFrontCamera, + updateIdCardData, + addCustomField, + saveCustomField, + removeCustomField, + updateTxCustomerPhoto +} diff --git a/lib/new-admin/graphql/resolvers/customer.resolver.js b/lib/new-admin/graphql/resolvers/customer.resolver.js index 6863e8b3..a26a86fd 100644 --- a/lib/new-admin/graphql/resolvers/customer.resolver.js +++ b/lib/new-admin/graphql/resolvers/customer.resolver.js @@ -16,7 +16,10 @@ const resolvers = { const token = !!context.req.cookies.lamassu_sid && context.req.session.user.id if (customerId === anonymous.uuid) return customers.getCustomerById(customerId) return customers.updateCustomer(customerId, customerInput, token) - } + }, + addCustomField: (...[, { customerId, label, value }]) => customers.addCustomField(customerId, label, value), + saveCustomField: (...[, { customerId, fieldId, newValue }]) => customers.saveCustomField(customerId, fieldId, newValue), + removeCustomField: (...[, [ { customerId, fieldId } ]]) => customers.removeCustomField(customerId, fieldId) } } diff --git a/lib/new-admin/graphql/types/customer.type.js b/lib/new-admin/graphql/types/customer.type.js index c6f5f7a7..de162770 100644 --- a/lib/new-admin/graphql/types/customer.type.js +++ b/lib/new-admin/graphql/types/customer.type.js @@ -1,6 +1,12 @@ const { gql } = require('apollo-server-express') const typeDef = gql` + type CustomerCustomField { + id: ID + label: String + value: String + } + type Customer { id: ID! authorizedOverride: String @@ -30,6 +36,7 @@ const typeDef = gql` lastTxClass: String transactions: [Transaction] subscriberInfo: JSONObject + customFields: [CustomerCustomField] } input CustomerInput { @@ -56,6 +63,7 @@ const typeDef = gql` lastTxClass: String suspendedUntil: Date subscriberInfo: Boolean + customFields: [JSONObject] } type Query { @@ -66,6 +74,9 @@ const typeDef = gql` type Mutation { setCustomer(customerId: ID!, customerInput: CustomerInput): Customer @auth + addCustomField(customerId: ID!, label: String!, value: String!): CustomerCustomField @auth + saveCustomField(customerId: ID!, fieldId: ID!, value: String!): CustomerCustomField @auth + removeCustomField(customerId: ID!, fieldId: ID!): CustomerCustomField @auth } ` diff --git a/migrations/1630624117042-customer-custom-fields.js b/migrations/1630624117042-customer-custom-fields.js new file mode 100644 index 00000000..5e77ce65 --- /dev/null +++ b/migrations/1630624117042-customer-custom-fields.js @@ -0,0 +1,23 @@ +var db = require('./db') + +exports.up = function (next) { + var sql = [ + `CREATE TABLE custom_field_definitions ( + id UUID PRIMARY KEY, + label TEXT NOT NULL UNIQUE, + active BOOLEAN DEFAULT true + )`, + `CREATE TABLE customer_custom_field_pairs ( + customer_id UUID REFERENCES customers(id) NOT NULL, + custom_field_id UUID REFERENCES custom_field_definitions(id) NOT NULL, + value TEXT NOT NULL, + UNIQUE (customer_id, custom_field_id) + )`, + ] + + db.multi(sql, next) +} + +exports.down = function (next) { + next() +}