From 1ba3bce6ebcb7bd33ad7be99520d4b70790bc1b4 Mon Sep 17 00:00:00 2001 From: vladimir Date: Sun, 19 Mar 2017 16:47:03 +0200 Subject: [PATCH 1/5] Add device type detect and stats calculation for open/click rate by device type and country --- lib/models/campaigns.js | 36 ++++++++++++++++++++++++++++++++++ lib/models/links.js | 23 +++++++++++----------- meta.json | 2 +- package.json | 1 + public/javascript/tables.js | 25 ++++++++++++++++++++++++ routes/campaigns.js | 39 +++++++++++++++++++++++++++++++++++++ routes/links.js | 5 ++--- setup/sql/upgrade-00022.sql | 11 +++++++++++ views/campaigns/clicked.hbs | 25 ++++++++++++++++++++++++ views/campaigns/opened.hbs | 24 +++++++++++++++++++++++ 10 files changed, 176 insertions(+), 15 deletions(-) create mode 100644 setup/sql/upgrade-00022.sql diff --git a/lib/models/campaigns.js b/lib/models/campaigns.js index b71d1bbf..2afe367c 100644 --- a/lib/models/campaigns.js +++ b/lib/models/campaigns.js @@ -193,7 +193,43 @@ module.exports.filterClickedSubscribers = (campaign, linkId, request, columns, c }); }); }); +}; +module.exports.statsClickedSubscribersByColumn = (campaign, linkId, request, column, limit, callback) => { + db.getConnection((err, connection) => { + if (err) { + return callback(err); + } + + let values = [campaign.list, linkId]; + let query = 'SELECT SQL_CALC_FOUND_ROWS ' + column + ' AS data, COUNT(*) AS cnt FROM `subscription__' + campaign.list + '` JOIN `campaign_tracker__' + campaign.id + '` ON `campaign_tracker__' + campaign.id + '`.`list`=? AND `campaign_tracker__' + campaign.id + '`.`subscriber`=`subscription__' + campaign.list + '`.`id` AND `campaign_tracker__' + campaign.id + '`.`link`=? GROUP BY ' + column + ' ORDER BY COUNT(' + column + ') DESC,' + column; + + connection.query(query, values, (err, rows) => { + connection.release(); + if (err) { + return callback(err); + } + + let data = {}; + let dataPercent = []; + let total = 0; + + rows.forEach(function (row, index) { + if (index < limit) { + data[row.data] = row.cnt; + } else { + data.other = (data.other ? data.other : 0) + row.cnt; + } + total += row.cnt; + }); + Object.keys(data).forEach(function (key) { + let name = key + ': ' + data[key]; + let value = parseInt(data[key] * 100 / total); + dataPercent.push([name, value]); + }); + return callback(null, dataPercent, total); + }); + }); }; module.exports.filterStatusSubscribers = (campaign, status, request, columns, callback) => { diff --git a/lib/models/links.js b/lib/models/links.js index 6c5a0bae..3a254788 100644 --- a/lib/models/links.js +++ b/lib/models/links.js @@ -13,6 +13,7 @@ let lists = require('./lists'); let log = require('npmlog'); let urllib = require('url'); let he = require('he'); +let ua_parser = require('device'); module.exports.resolve = (linkCid, callback) => { db.getConnection((err, connection) => { @@ -35,7 +36,7 @@ module.exports.resolve = (linkCid, callback) => { }); }; -module.exports.countClick = (remoteIp, campaignCid, listCid, subscriptionCid, linkId, callback) => { +module.exports.countClick = (remoteIp, useragent, campaignCid, listCid, subscriptionCid, linkId, callback) => { getSubscriptionData(campaignCid, listCid, subscriptionCid, (err, data) => { if (err) { return callback(err); @@ -57,9 +58,9 @@ module.exports.countClick = (remoteIp, campaignCid, listCid, subscriptionCid, li } let country = geoip.lookupCountry(remoteIp) || null; - - let query = 'INSERT INTO `campaign_tracker__' + data.campaign.id + '` (`list`, `subscriber`, `link`, `ip`, `country`) VALUES (?,?,?,?,?) ON DUPLICATE KEY UPDATE `count`=`count`+1'; - connection.query(query, [data.list.id, data.subscription.id, linkId, remoteIp, country], (err, result) => { + let device = ua_parser(useragent, { unknownUserAgentDeviceType: 'desktop', emptyUserAgentDeviceType: 'desktop' }); + let query = 'INSERT INTO `campaign_tracker__' + data.campaign.id + '` (`list`, `subscriber`, `link`, `ip`, `device_type`, `country`) VALUES (?,?,?,?,?,?) ON DUPLICATE KEY UPDATE `count`=`count`+1'; + connection.query(query, [data.list.id, data.subscription.id, linkId, remoteIp, device.type, country], (err, result) => { if (err && err.code !== 'ER_DUP_ENTRY') { return connection.rollback(() => { connection.release(); @@ -98,8 +99,8 @@ module.exports.countClick = (remoteIp, campaignCid, listCid, subscriptionCid, li }); } - let query = 'INSERT INTO `campaign_tracker__' + data.campaign.id + '` (`list`, `subscriber`, `link`, `ip`, `country`) VALUES (?,?,?,?,?)'; - connection.query(query, [data.list.id, data.subscription.id, 0, remoteIp, country], err => { + let query = 'INSERT INTO `campaign_tracker__' + data.campaign.id + '` (`list`, `subscriber`, `link`, `ip`, `device_type`, `country`) VALUES (?,?,?,?,?,?)'; + connection.query(query, [data.list.id, data.subscription.id, 0, remoteIp, device.type, country], err => { if (err && err.code !== 'ER_DUP_ENTRY') { return connection.rollback(() => { connection.release(); @@ -141,7 +142,7 @@ module.exports.countClick = (remoteIp, campaignCid, listCid, subscriptionCid, li }); // also count clicks as open events in case beacon image was blocked - module.exports.countOpen(remoteIp, campaignCid, listCid, subscriptionCid, () => false); + module.exports.countOpen(remoteIp, useragent, campaignCid, listCid, subscriptionCid, () => false); }); }); }); @@ -151,7 +152,7 @@ module.exports.countClick = (remoteIp, campaignCid, listCid, subscriptionCid, li }); }; -module.exports.countOpen = (remoteIp, campaignCid, listCid, subscriptionCid, callback) => { +module.exports.countOpen = (remoteIp, useragent, campaignCid, listCid, subscriptionCid, callback) => { getSubscriptionData(campaignCid, listCid, subscriptionCid, (err, data) => { if (err) { return callback(err); @@ -173,9 +174,9 @@ module.exports.countOpen = (remoteIp, campaignCid, listCid, subscriptionCid, cal } let country = geoip.lookupCountry(remoteIp) || null; - - let query = 'INSERT INTO `campaign_tracker__' + data.campaign.id + '` (`list`, `subscriber`, `link`, `ip`, `country`) VALUES (?,?,?,?,?) ON DUPLICATE KEY UPDATE `count`=`count`+1'; - connection.query(query, [data.list.id, data.subscription.id, -1, remoteIp, country], (err, result) => { + let device = ua_parser(useragent, { unknownUserAgentDeviceType: 'desktop', emptyUserAgentDeviceType: 'desktop' }); + let query = 'INSERT INTO `campaign_tracker__' + data.campaign.id + '` (`list`, `subscriber`, `link`, `ip`, `device_type`, `country`) VALUES (?,?,?,?,?,?) ON DUPLICATE KEY UPDATE `count`=`count`+1'; + connection.query(query, [data.list.id, data.subscription.id, -1, remoteIp, device.type, country], (err, result) => { if (err && err.code !== 'ER_DUP_ENTRY') { return connection.rollback(() => { connection.release(); diff --git a/meta.json b/meta.json index 731dc8bf..7bb9c8c4 100644 --- a/meta.json +++ b/meta.json @@ -1,3 +1,3 @@ { - "schemaVersion": 21 + "schemaVersion": 22 } diff --git a/package.json b/package.json index dab0933f..04a898a6 100644 --- a/package.json +++ b/package.json @@ -47,6 +47,7 @@ "csurf": "^1.9.0", "csv-generate": "^1.0.0", "csv-parse": "^1.2.0", + "device": "^0.3.8", "escape-html": "^1.0.3", "express": "^4.15.2", "express-session": "^1.15.1", diff --git a/public/javascript/tables.js b/public/javascript/tables.js index be592106..7faad36b 100644 --- a/public/javascript/tables.js +++ b/public/javascript/tables.js @@ -72,6 +72,31 @@ $('.data-table-ajax').each(function () { }); }); +$('.data-stats-pie-chart').each(function () { + var column = $(this).data('column') || 'country'; + var limit = $(this).data('limit') || 20; + var topicId = $(this).data('topicId'); + var topicUrl = $(this).data('topicUrl') || '/campaigns/clicked'; + var ajaxUrl = topicUrl + '/ajax/' + topicId + '/stats'; + var self = $(this); + + $.post(ajaxUrl, {column: column, limit: limit}, function(data) { + google.charts.load('current', {'packages':['corechart']}); + google.charts.setOnLoadCallback(drawChart); + + function drawChart() { + var gTable = new google.visualization.DataTable(); + gTable.addColumn('string', 'Column'); + gTable.addColumn('number', 'Value'); + gTable.addRows(data.data); + + var options = {'width':500, 'height':400}; + var chart = new google.visualization.PieChart(self[0]); + chart.draw(gTable, options); + } + }); +}); + $('.datestring').each(function () { $(this).html(moment($(this).data('date')).fromNow()); }); diff --git a/routes/campaigns.js b/routes/campaigns.js index 4ee1958a..81dcd2ba 100644 --- a/routes/campaigns.js +++ b/routes/campaigns.js @@ -581,6 +581,45 @@ router.post('/clicked/ajax/:id/:linkId', (req, res) => { }); }); +router.post('/clicked/ajax/:id/:linkId/stats', (req, res) => { + let linkId = Number(req.params.linkId) || 0; + campaigns.get(req.params.id, true, (err, campaign) => { + if (err || !campaign) { + return res.json({ + error: err && err.message || err || _('Campaign not found'), + data: [] + }); + } + lists.get(campaign.list, (err, list) => { + if (err) { + return res.json({ + error: err && err.message || err, + data: [] + }); + } + + let column = req.body.column; + let limit = req.body.limit; + + campaigns.statsClickedSubscribersByColumn(campaign, linkId, req.body, column, limit, (err, data, total) => { + if (err) { + return res.json({ + error: err.message || err, + data: [] + }); + } + + res.json({ + draw: req.body.draw, + total: total, + data: data + }); + }); + }); + }); +}); + + router.post('/status/ajax/:id/:status', (req, res) => { let status = Number(req.params.status) || 0; diff --git a/routes/links.js b/routes/links.js index 5da3ef43..f65bc57b 100644 --- a/routes/links.js +++ b/routes/links.js @@ -18,8 +18,7 @@ router.get('/:campaign/:list/:subscription', (req, res) => { 'Content-Type': 'image/gif', 'Content-Length': trackImg.length }); - - links.countOpen(req.ip, req.params.campaign, req.params.list, req.params.subscription, (err, opened) => { + links.countOpen(req.ip, req.headers['user-agent'], req.params.campaign, req.params.list, req.params.subscription, (err, opened) => { if (err) { log.error('Redirect', err.stack || err); } @@ -53,7 +52,7 @@ router.get('/:campaign/:list/:subscription/:link', (req, res) => { log.error('Redirect', 'Unresolved URL: <%s>', req.url); return notFound(); } - links.countClick(req.ip, req.params.campaign, req.params.list, req.params.subscription, linkId, (err, status) => { + links.countClick(req.ip, req.headers['user-agent'], req.params.campaign, req.params.list, req.params.subscription, linkId, (err, status) => { if (err) { log.error('Redirect', err.stack || err); } diff --git a/setup/sql/upgrade-00022.sql b/setup/sql/upgrade-00022.sql new file mode 100644 index 00000000..3867edd4 --- /dev/null +++ b/setup/sql/upgrade-00022.sql @@ -0,0 +1,11 @@ +# Header section +# Define incrementing schema version number +SET @schema_version = '22'; + +# Add field device_type to campaign_tracker +ALTER TABLE `campaign_tracker` ADD COLUMN `device_type` varchar(50) DEFAULT NULL AFTER `ip`; + +# Footer section +LOCK TABLES `settings` WRITE; +INSERT INTO `settings` (`key`, `value`) VALUES('db_schema_version', @schema_version) ON DUPLICATE KEY UPDATE `value`=@schema_version; +UNLOCK TABLES; diff --git a/views/campaigns/clicked.hbs b/views/campaigns/clicked.hbs index 9f71d470..d93f2ac4 100644 --- a/views/campaigns/clicked.hbs +++ b/views/campaigns/clicked.hbs @@ -69,6 +69,31 @@
{{#if aggregated}}{{#translate}}Subscribers who clicked on a link:{{/translate}}{{else}}{{#translate}}Subscribers who clicked on this link:{{/translate}}{{/if}}
+ {{#if aggregated}}{{else}} +
+ + + + + + + + + + + + +
+ {{#translate}}Stats by country{{/translate}} + + {{#translate}}Stats by device type{{/translate}} +
+
+
+
+
+
+ {{/if}}
diff --git a/views/campaigns/opened.hbs b/views/campaigns/opened.hbs index 20665d53..b4b3b823 100644 --- a/views/campaigns/opened.hbs +++ b/views/campaigns/opened.hbs @@ -16,12 +16,36 @@
{{{description}}}
{{/if}} +
{{#translate}}Subscribers who opened this message:{{/translate}}
+
+ +
+ + + + + + + + + + +
+ {{#translate}}Stats by country{{/translate}} + + {{#translate}}Stats by device type{{/translate}} +
+
+
+
+
+
From 7d768ebd48a987fcccc71c732558f2ba6e83167f Mon Sep 17 00:00:00 2001 From: vladimir Date: Mon, 20 Mar 2017 15:28:21 +0200 Subject: [PATCH 2/5] Fix link.id in opened links --- views/campaigns/clicked.hbs | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/views/campaigns/clicked.hbs b/views/campaigns/clicked.hbs index d93f2ac4..35a2bb6c 100644 --- a/views/campaigns/clicked.hbs +++ b/views/campaigns/clicked.hbs @@ -84,10 +84,10 @@ From e3cb6ca6794e51c2c8befd08b6a617b23f643fac Mon Sep 17 00:00:00 2001 From: vladimir Date: Mon, 20 Mar 2017 17:47:30 +0200 Subject: [PATCH 3/5] Fix formating and rewrite migration script --- setup/sql/upgrade-00022.sql | 31 ++++++++++++++++++++++- views/campaigns/clicked.hbs | 50 ++++++++++++++++++------------------- 2 files changed, 55 insertions(+), 26 deletions(-) diff --git a/setup/sql/upgrade-00022.sql b/setup/sql/upgrade-00022.sql index 3867edd4..ad926597 100644 --- a/setup/sql/upgrade-00022.sql +++ b/setup/sql/upgrade-00022.sql @@ -3,7 +3,36 @@ SET @schema_version = '22'; # Add field device_type to campaign_tracker -ALTER TABLE `campaign_tracker` ADD COLUMN `device_type` varchar(50) DEFAULT NULL AFTER `ip`; + +# Create ALTER TABLE PROCEDURE +DROP PROCEDURE IF EXISTS `alterbyregexp`; +DELIMITER // +CREATE PROCEDURE alterbyregexp(`table_regexp` VARCHAR(255), `altertext` VARCHAR(255)) +BEGIN +DECLARE done INT DEFAULT FALSE; +DECLARE tbl VARCHAR(255); +DECLARE curs CURSOR FOR SELECT table_name FROM information_schema.tables WHERE table_schema = (SELECT DATABASE()) and table_name like table_regexp; +DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; +OPEN curs; + +read_loop: LOOP +FETCH curs INTO tbl; +IF done THEN + LEAVE read_loop; +END IF; +SET @query = CONCAT('ALTER TABLE `', tbl, '`' , altertext); +PREPARE stmt FROM @query; +EXECUTE stmt; +DEALLOCATE PREPARE stmt; +END LOOP; +CLOSE curs; +END; +// +DELIMITER ; + +# Add field device_type to campaign_tracker +CALL alterbyregexp('campaign\_tracker%', 'ADD COLUMN `device_type` varchar(50) DEFAULT NULL AFTER `ip`'); +DROP PROCEDURE IF EXISTS `alterbyregexp`; # Footer section LOCK TABLES `settings` WRITE; diff --git a/views/campaigns/clicked.hbs b/views/campaigns/clicked.hbs index 35a2bb6c..01e98867 100644 --- a/views/campaigns/clicked.hbs +++ b/views/campaigns/clicked.hbs @@ -69,31 +69,31 @@
{{#if aggregated}}{{#translate}}Subscribers who clicked on a link:{{/translate}}{{else}}{{#translate}}Subscribers who clicked on this link:{{/translate}}{{/if}}
- {{#if aggregated}}{{else}} -
- -
-
+
-
+
- - - - - - - - - - -
- {{#translate}}Stats by country{{/translate}} - - {{#translate}}Stats by device type{{/translate}} -
-
-
-
-
-
- {{/if}} + {{#if aggregated}}{{else}} +
+ + + + + + + + + + + + +
+ {{#translate}}Stats by country{{/translate}} + + {{#translate}}Stats by device type{{/translate}} +
+
+
+
+
+
+ {{/if}}
From 97d5d1a462282e4ccf542f82d2b1463c6c702d11 Mon Sep 17 00:00:00 2001 From: vladimir Date: Tue, 21 Mar 2017 00:16:50 +0200 Subject: [PATCH 4/5] Replace if-else with unless function in clicked view --- views/campaigns/clicked.hbs | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/views/campaigns/clicked.hbs b/views/campaigns/clicked.hbs index 01e98867..c43976f3 100644 --- a/views/campaigns/clicked.hbs +++ b/views/campaigns/clicked.hbs @@ -69,7 +69,7 @@
{{#if aggregated}}{{#translate}}Subscribers who clicked on a link:{{/translate}}{{else}}{{#translate}}Subscribers who clicked on this link:{{/translate}}{{/if}}
- {{#if aggregated}}{{else}} + {{#unless aggregated}}
@@ -93,7 +93,7 @@
- {{/if}} + {{/unless}}
From 8caf334fcc9bd1613714f6683738640d2b0545de Mon Sep 17 00:00:00 2001 From: vladimir Date: Tue, 21 Mar 2017 01:06:05 +0200 Subject: [PATCH 5/5] Cosmetic changes --- lib/models/campaigns.js | 53 +++++++++++++++++++------------------ setup/sql/upgrade-00022.sql | 5 +--- 2 files changed, 28 insertions(+), 30 deletions(-) diff --git a/lib/models/campaigns.js b/lib/models/campaigns.js index 62208707..130225e0 100644 --- a/lib/models/campaigns.js +++ b/lib/models/campaigns.js @@ -13,6 +13,7 @@ let log = require('npmlog'); let mailer = require('../mailer'); let humanize = require('humanize'); let _ = require('../translate')._; +let util = require('util'); let allowedKeys = ['description', 'from', 'address', 'reply_to', 'subject', 'editor_name', 'editor_data', 'template', 'source_url', 'list', 'segment', 'html', 'text', 'tracking_disabled']; @@ -201,33 +202,33 @@ module.exports.statsClickedSubscribersByColumn = (campaign, linkId, request, col return callback(err); } - let values = [campaign.list, linkId]; - let query = 'SELECT SQL_CALC_FOUND_ROWS ' + column + ' AS data, COUNT(*) AS cnt FROM `subscription__' + campaign.list + '` JOIN `campaign_tracker__' + campaign.id + '` ON `campaign_tracker__' + campaign.id + '`.`list`=? AND `campaign_tracker__' + campaign.id + '`.`subscriber`=`subscription__' + campaign.list + '`.`id` AND `campaign_tracker__' + campaign.id + '`.`link`=? GROUP BY ' + column + ' ORDER BY COUNT(' + column + ') DESC,' + column; - - connection.query(query, values, (err, rows) => { - connection.release(); - if (err) { - return callback(err); - } - - let data = {}; - let dataPercent = []; - let total = 0; - - rows.forEach(function (row, index) { - if (index < limit) { - data[row.data] = row.cnt; - } else { - data.other = (data.other ? data.other : 0) + row.cnt; + let query_template = 'SELECT %s AS data, COUNT(*) AS cnt FROM `subscription__%d` JOIN `campaign_tracker__%d` ON `campaign_tracker__%d`.`list`=%d AND `campaign_tracker__%d`.`subscriber`=`subscription__%d`.`id` AND `campaign_tracker__%d`.`link`=%d GROUP BY `%s` ORDER BY COUNT(`%s`) DESC, `%s`'; + let query = util.format(query_template, column, campaign.list, campaign.id, campaign.id, campaign.list, campaign.id, campaign.list, campaign.id, linkId, column, column, column); + + connection.query(query, (err, rows) => { + connection.release(); + if (err) { + return callback(err); } - total += row.cnt; - }); - Object.keys(data).forEach(function (key) { - let name = key + ': ' + data[key]; - let value = parseInt(data[key] * 100 / total); - dataPercent.push([name, value]); - }); - return callback(null, dataPercent, total); + + let data = {}; + let dataPercent = []; + let total = 0; + + rows.forEach((row, index) => { + if (index < limit) { + data[row.data] = row.cnt; + } else { + data.other = (data.other ? data.other : 0) + row.cnt; + } + total += row.cnt; + }); + Object.keys(data).forEach(key => { + let name = key + ': ' + data[key]; + let value = parseInt(data[key] * 100 / total, 10); + dataPercent.push([name, value]); + }); + return callback(null, dataPercent, total); }); }); }; diff --git a/setup/sql/upgrade-00022.sql b/setup/sql/upgrade-00022.sql index ad926597..daf4a617 100644 --- a/setup/sql/upgrade-00022.sql +++ b/setup/sql/upgrade-00022.sql @@ -6,8 +6,7 @@ SET @schema_version = '22'; # Create ALTER TABLE PROCEDURE DROP PROCEDURE IF EXISTS `alterbyregexp`; -DELIMITER // -CREATE PROCEDURE alterbyregexp(`table_regexp` VARCHAR(255), `altertext` VARCHAR(255)) +CREATE PROCEDURE `alterbyregexp` (`table_regexp` VARCHAR(255), `altertext` VARCHAR(255)) BEGIN DECLARE done INT DEFAULT FALSE; DECLARE tbl VARCHAR(255); @@ -27,8 +26,6 @@ DEALLOCATE PREPARE stmt; END LOOP; CLOSE curs; END; -// -DELIMITER ; # Add field device_type to campaign_tracker CALL alterbyregexp('campaign\_tracker%', 'ADD COLUMN `device_type` varchar(50) DEFAULT NULL AFTER `ip`');