diff --git a/CHANGELOG.txt b/CHANGELOG.txt
index 3388268f..2de87ea2 100644
--- a/CHANGELOG.txt
+++ b/CHANGELOG.txt
@@ -1,5 +1,9 @@
# Changelog
+## 1.8.0 2016-05-13
+
+ * Show details about subscribers who clicked on a specific link
+
## 1.7.0 2016-05-11
* Updated API, added new option **REQUIRE_CONFIRMATION** for subscriptions to send confirmation email before subscribing
diff --git a/lib/models/campaigns.js b/lib/models/campaigns.js
index 52e80c4d..4386080f 100644
--- a/lib/models/campaigns.js
+++ b/lib/models/campaigns.js
@@ -127,6 +127,73 @@ module.exports.filter = (request, parent, callback) => {
}
};
+module.exports.filterClickedSubscribers = (campaign, linkId, request, columns, callback) => {
+ db.getConnection((err, connection) => {
+ if (err) {
+ return callback(err);
+ }
+
+ let query = 'SELECT COUNT(`subscription__' + campaign.list + '`.`id`) AS total 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`=?';
+ let values = [campaign.list, linkId];
+
+ connection.query(query, values, (err, total) => {
+ if (err) {
+ connection.release();
+ return callback(err);
+ }
+ total = total && total[0] && total[0].total || 0;
+
+ let ordering = [];
+
+ if (request.order && request.order.length) {
+
+ request.order.forEach(order => {
+ let orderField = columns[Number(order.column)];
+ let orderDirection = (order.dir || '').toString().toLowerCase() === 'desc' ? 'DESC' : 'ASC';
+ if (orderField) {
+ ordering.push('`' + orderField + '` ' + orderDirection);
+ }
+ });
+ }
+
+ if (!ordering.length) {
+ ordering.push('`email` ASC');
+ }
+
+ let args = [Number(request.length) || 50, Number(request.start) || 0];
+
+ if (request.search && request.search.value) {
+ query = 'SELECT SQL_CALC_FOUND_ROWS * 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`=? WHERE email LIKE ? OR first_name LIKE ? OR last_name LIKE ? ORDER BY ' + ordering.join(', ') + ' LIMIT ? OFFSET ?';
+
+ let searchVal = '%' + request.search.value.replace(/\\/g, '\\\\').replace(/([%_])/g, '\\$1') + '%';
+ args = values.concat([searchVal, searchVal, searchVal]).concat(args);
+ } else {
+ query = 'SELECT SQL_CALC_FOUND_ROWS * 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`=? ORDER BY ' + ordering.join(', ') + ' LIMIT ? OFFSET ?';
+ args = values.concat(args);
+ }
+
+ connection.query(query, args, (err, rows) => {
+ if (err) {
+ connection.release();
+ return callback(err);
+ }
+ connection.query('SELECT FOUND_ROWS() AS total', (err, filteredTotal) => {
+ connection.release();
+ if (err) {
+ return callback(err);
+ }
+
+ let subscriptions = rows.map(row => tools.convertKeys(row));
+
+ filteredTotal = filteredTotal && filteredTotal[0] && filteredTotal[0].total || 0;
+ return callback(null, subscriptions, total, filteredTotal);
+ });
+ });
+ });
+ });
+
+};
+
module.exports.getByCid = (cid, callback) => {
cid = (cid || '').toString().trim();
if (!cid) {
@@ -226,8 +293,14 @@ module.exports.get = (id, withSegment, callback) => {
});
};
-module.exports.getLinks = (id, callback) => {
+module.exports.getLinks = (id, linkId, callback) => {
+ if (!callback && typeof linkId === 'function') {
+ callback = linkId;
+ linkId = false;
+ }
+
id = Number(id) || 0;
+ linkId = Number(linkId) || 0;
if (id < 1) {
return callback(new Error('Missing Campaign ID'));
@@ -238,8 +311,18 @@ module.exports.getLinks = (id, callback) => {
return callback(err);
}
- let query = 'SELECT `id`, `url`, `clicks` FROM links WHERE `campaign`=? LIMIT 1000';
- connection.query(query, [id], (err, rows) => {
+ let query;
+ let values;
+
+ if (!linkId) {
+ query = 'SELECT `id`, `url`, `clicks` FROM links WHERE `campaign`=? LIMIT 1000';
+ values = [id];
+ } else {
+ query = 'SELECT `id`, `url`, `clicks` FROM links WHERE `id`=? AND `campaign`=? LIMIT 1';
+ values = [linkId, id];
+ }
+
+ connection.query(query, values, (err, rows) => {
connection.release();
if (err) {
return callback(err);
diff --git a/lib/models/fields.js b/lib/models/fields.js
index ebe92c5d..87ad301c 100644
--- a/lib/models/fields.js
+++ b/lib/models/fields.js
@@ -429,7 +429,7 @@ module.exports.getRow = (fieldList, values, useDate, showAll, onlyExisting) => {
};
}).filter(subField => subField)
};
- item.value = item.options.filter(subField => showAll || subField.visible && subField.value).map(subField => subField.name).join(', ');
+ item.value = item.options.filter(subField => (showAll || subField.visible) && subField.value).map(subField => subField.name).join(', ');
item.mergeValue = item.value || field.defaultValue;
row.push(item);
break;
diff --git a/lib/tools.js b/lib/tools.js
index c194c440..baa6609c 100644
--- a/lib/tools.js
+++ b/lib/tools.js
@@ -178,7 +178,7 @@ function formatMessage(serviceUrl, campaign, list, subscription, message, filter
return message.replace(/\[([a-z0-9_]+)(?:\/([^\]]+))?\]/ig, (match, identifier, fallback) => {
identifier = identifier.toUpperCase();
let value = (getValue(identifier) || fallback || '').trim();
- return value ? filter(value) : match;
+ return value ? filter(value) : '';
});
}
diff --git a/meta.json b/meta.json
index 0aa4b5e3..bab3b5df 100644
--- a/meta.json
+++ b/meta.json
@@ -1,3 +1,3 @@
{
- "schemaVersion": 9
+ "schemaVersion": 10
}
diff --git a/package.json b/package.json
index 5fbdf7dd..d68608f4 100644
--- a/package.json
+++ b/package.json
@@ -1,7 +1,7 @@
{
"name": "mailtrain",
"private": true,
- "version": "1.7.0",
+ "version": "1.8.0",
"description": "Self hosted email newsletter app",
"main": "index.js",
"scripts": {
diff --git a/routes/campaigns.js b/routes/campaigns.js
index ed5819a2..bd9f66c8 100644
--- a/routes/campaigns.js
+++ b/routes/campaigns.js
@@ -3,6 +3,7 @@
let express = require('express');
let router = new express.Router();
let lists = require('../lib/models/lists');
+let fields = require('../lib/models/fields');
let templates = require('../lib/models/templates');
let campaigns = require('../lib/models/campaigns');
let settings = require('../lib/models/settings');
@@ -157,7 +158,56 @@ router.get('/edit/:id', passport.csrfProtection, (req, res, next) => {
view = 'campaigns/edit';
}
- res.render(view, campaign);
+ lists.get(campaign.list, (err, list) => {
+ if (err) {
+ req.flash('danger', err.message || err);
+ return res.redirect('/');
+ }
+ if (!list) {
+ req.flash('danger', 'Selected list does not exist');
+ res.render(view, campaign);
+ return;
+ }
+
+ fields.list(list.id, (err, fieldList) => {
+ if (err && !fieldList) {
+ fieldList = [];
+ }
+
+ let mergeTags = [
+ // indent
+ {
+ key: 'LINK_UNSUBSCRIBE',
+ value: 'URL that points to the preferences page of the subscriber'
+ }, {
+ key: 'LINK_PREFERENCES',
+ value: 'URL that points to the unsubscribe page'
+ }, {
+ key: 'LINK_BROWSER',
+ value: 'URL to preview the message in a browser'
+ }, {
+ key: 'FIRST_NAME',
+ value: 'First name'
+ }, {
+ key: 'LAST_NAME',
+ value: 'Last name'
+ }, {
+ key: 'FULL_NAME',
+ value: 'Full name (first and last name combined)'
+ }
+ ];
+
+ fieldList.forEach(field => {
+ mergeTags.push({
+ key: field.key,
+ value: field.name
+ });
+ });
+
+ campaign.mergeTags = mergeTags;
+ res.render(view, campaign);
+ });
+ });
});
});
});
@@ -268,6 +318,9 @@ router.get('/view/:id', passport.csrfProtection, (req, res) => {
campaign.isScheduled = campaign.scheduled && campaign.scheduled > new Date();
+ // show only messages that weren't bounced as delivered
+ campaign.delivered = campaign.delivered - campaign.bounced;
+
campaign.openRate = campaign.delivered ? Math.round((campaign.opened / campaign.delivered) * 100) : 0;
campaign.clicksRate = campaign.delivered ? Math.round((campaign.clicks / campaign.delivered) * 100) : 0;
@@ -286,7 +339,8 @@ router.get('/view/:id', passport.csrfProtection, (req, res) => {
}
return link;
});
- campaign.showOverview = true;
+ campaign.showOverview = !req.query.tab || req.query.tab === 'overview';
+ campaign.showLinks = req.query.tab === 'links';
res.render('campaigns/view', campaign);
});
@@ -294,6 +348,86 @@ router.get('/view/:id', passport.csrfProtection, (req, res) => {
});
});
+router.get('/clicked/:id/:linkId', passport.csrfProtection, (req, res) => {
+ campaigns.get(req.params.id, true, (err, campaign) => {
+ if (err || !campaign) {
+ req.flash('danger', err && err.message || err || 'Could not find campaign with specified ID');
+ return res.redirect('/campaigns');
+ }
+
+ lists.get(campaign.list, (err, list) => {
+ if (err || !campaign) {
+ req.flash('danger', err && err.message || err);
+ return res.redirect('/campaigns');
+ }
+
+ campaign.csrfToken = req.csrfToken();
+ campaign.list = list;
+
+ // show only messages that weren't bounced as delivered
+ campaign.delivered = campaign.delivered - campaign.bounced;
+
+ campaigns.getLinks(campaign.id, req.params.linkId, (err, links) => {
+ if (err) {
+ // ignore
+ }
+ let index = 0;
+ campaign.link = (links || []).map(link => {
+ link.index = ++index;
+ link.totalPercentage = campaign.delivered ? Math.round(((link.clicks / campaign.delivered) * 100) * 1000) / 1000 : 0;
+ link.relPercentage = campaign.clicks ? Math.round(((link.clicks / campaign.clicks) * 100) * 1000) / 1000 : 0;
+ link.short = link.url.replace(/^https?:\/\/(www.)?/i, '');
+ if (link.short > 63) {
+ link.short = link.short.substr(0, 60) + '…';
+ }
+ return link;
+ }).shift();
+ campaign.showOverview = true;
+ res.render('campaigns/clicked', campaign);
+ });
+
+ });
+ });
+});
+
+router.post('/clicked/ajax/:id/:linkId', (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: []
+ });
+ }
+
+ let columns = ['#', 'email', 'first_name', 'last_name', 'campaign_tracker__' + campaign.id + '`.`created', 'count'];
+ campaigns.filterClickedSubscribers(campaign, linkId, req.body, columns, (err, data, total, filteredTotal) => {
+ if (err) {
+ return res.json({
+ error: err.message || err,
+ data: []
+ });
+ }
+
+ res.json({
+ draw: req.body.draw,
+ recordsTotal: total,
+ recordsFiltered: filteredTotal,
+ data: data.map((row, i) => [
+ (Number(req.body.start) || 0) + 1 + i,
+ htmlescape(row.email || ''),
+ htmlescape(row.firstName || ''),
+ htmlescape(row.lastName || ''),
+ row.created && row.created.toISOString ? '' + row.created.toISOString() + '' : 'N/A',
+ row.count,
+ 'Edit'
+ ])
+ });
+ });
+ });
+});
+
router.post('/delete', passport.parseForm, passport.csrfProtection, (req, res) => {
campaigns.delete(req.body.id, (err, deleted) => {
if (err) {
diff --git a/services/sender.js b/services/sender.js
index 49c773c5..c934ce34 100644
--- a/services/sender.js
+++ b/services/sender.js
@@ -151,7 +151,7 @@ function formatMessage(message, callback) {
if (field.options) {
field.options.forEach(subField => {
if (subField.mergeTag) {
- message.subscription.mergeTags[subField.mergeTag] = subField.mergeValue || '';
+ message.subscription.mergeTags[subField.mergeTag] = subField.value && subField.mergeValue || '';
}
});
}
diff --git a/setup/sql/mailtrain.sql b/setup/sql/mailtrain.sql
index 39922c3d..fe1adaa0 100644
--- a/setup/sql/mailtrain.sql
+++ b/setup/sql/mailtrain.sql
@@ -23,7 +23,9 @@ CREATE TABLE `campaign_tracker` (
`ip` varchar(100) CHARACTER SET ascii DEFAULT NULL,
`country` varchar(2) CHARACTER SET ascii DEFAULT NULL,
`count` int(11) unsigned NOT NULL DEFAULT '1',
- PRIMARY KEY (`list`,`subscriber`,`link`)
+ `created` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ PRIMARY KEY (`list`,`subscriber`,`link`),
+ KEY `created_index` (`created`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `campaigns` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
@@ -181,7 +183,7 @@ CREATE TABLE `settings` (
`value` text NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `key` (`key`)
-) ENGINE=InnoDB AUTO_INCREMENT=25 DEFAULT CHARSET=utf8mb4;
+) ENGINE=InnoDB AUTO_INCREMENT=27 DEFAULT CHARSET=utf8mb4;
INSERT INTO `settings` (`id`, `key`, `value`) VALUES (1,'smtp_hostname','localhost');
INSERT INTO `settings` (`id`, `key`, `value`) VALUES (2,'smtp_port','465');
INSERT INTO `settings` (`id`, `key`, `value`) VALUES (3,'smtp_encryption','TLS');
@@ -198,7 +200,7 @@ INSERT INTO `settings` (`id`, `key`, `value`) VALUES (13,'default_from','My Awes
INSERT INTO `settings` (`id`, `key`, `value`) VALUES (14,'default_address','admin@example.com');
INSERT INTO `settings` (`id`, `key`, `value`) VALUES (15,'default_subject','Test message');
INSERT INTO `settings` (`id`, `key`, `value`) VALUES (16,'default_homepage','http://localhost:3000/');
-INSERT INTO `settings` (`id`, `key`, `value`) VALUES (17,'db_schema_version','8');
+INSERT INTO `settings` (`id`, `key`, `value`) VALUES (17,'db_schema_version','10');
CREATE TABLE `subscription` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`cid` varchar(255) CHARACTER SET ascii NOT NULL,
@@ -242,6 +244,7 @@ CREATE TABLE `users` (
`username` varchar(255) NOT NULL DEFAULT '',
`password` varchar(255) NOT NULL DEFAULT '',
`email` varchar(255) CHARACTER SET utf8 DEFAULT NULL,
+ `access_token` varchar(40) DEFAULT NULL,
`reset_token` varchar(255) CHARACTER SET ascii DEFAULT NULL,
`reset_expire` timestamp NULL DEFAULT NULL,
`created` timestamp NULL DEFAULT CURRENT_TIMESTAMP,
@@ -249,9 +252,10 @@ CREATE TABLE `users` (
UNIQUE KEY `email` (`email`),
KEY `username` (`username`(191)),
KEY `reset` (`reset_token`),
- KEY `check_reset` (`username`(191),`reset_token`,`reset_expire`)
+ KEY `check_reset` (`username`(191),`reset_token`,`reset_expire`),
+ KEY `token_index` (`access_token`)
) ENGINE=InnoDB AUTO_INCREMENT=2 DEFAULT CHARSET=utf8mb4;
-INSERT INTO `users` (`id`, `username`, `password`, `email`, `reset_token`, `reset_expire`, `created`) VALUES (1,'admin','$2a$10$mzKU71G62evnGB2PvQA4k..Wf9jASk.c7a8zRMHh6qQVjYJ2r/g/K','admin@example.com',NULL,NULL,NOW());
+INSERT INTO `users` (`id`, `username`, `password`, `email`, `access_token`, `reset_token`, `reset_expire`, `created`) VALUES (1,'admin','$2a$10$mzKU71G62evnGB2PvQA4k..Wf9jASk.c7a8zRMHh6qQVjYJ2r/g/K','admin@example.com',NULL,NULL,NULL,NOW());
SET UNIQUE_CHECKS=1;
SET FOREIGN_KEY_CHECKS=1;
diff --git a/setup/sql/upgrade-00010.sql b/setup/sql/upgrade-00010.sql
new file mode 100644
index 00000000..51f67d89
--- /dev/null
+++ b/setup/sql/upgrade-00010.sql
@@ -0,0 +1,17 @@
+# Header section
+# Define incrementing schema version number
+SET @schema_version = '10';
+
+-- {{#each tables.campaign_tracker}}
+
+ # Adds new column 'created' to campaign tracker table
+ # Indicates when a subscriber first clicked a link or opened the message
+ ALTER TABLE `{{this}}` ADD COLUMN `created` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP AFTER `count`;
+ CREATE INDEX created_index ON `{{this}}` (`created`);
+
+-- {{/each}}
+
+# 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
new file mode 100644
index 00000000..6a5c4590
--- /dev/null
+++ b/views/campaigns/clicked.hbs
@@ -0,0 +1,86 @@
+
+ - Home
+ - Campaigns
+ {{#if parent}}
+ - {{parent.name}}
+ {{/if}}
+ - {{name}}
+ - Link info
+
+
+
+
+
+
+{{#if description}}
+ {{{description}}}
+{{/if}}
+
+
+
+
+
+ URL
+ |
+
+ Clicks
+ |
+
+ % of clicks
+ |
+
+ % of messages
+ |
+
+
+
+
+ {{link.short}}
+ |
+
+ {{link.clicks}}
+ |
+
+ {{link.relPercentage}}
+ |
+
+ {{link.totalPercentage}}
+ |
+
+
+
+
+
+
+
Subscribers who clicked on this link:
+
+
+
+
+
+
+ #
+ |
+
+ Address
+ |
+
+ First Name
+ |
+
+ Last Name
+ |
+
+ First click
+ |
+
+ Click count
+ |
+ |
+
+
+
+
+
+
+
diff --git a/views/campaigns/edit-rss.hbs b/views/campaigns/edit-rss.hbs
index 4f57aac9..9a5d0ec5 100644
--- a/views/campaigns/edit-rss.hbs
+++ b/views/campaigns/edit-rss.hbs
@@ -71,6 +71,52 @@
+
+
diff --git a/views/campaigns/view.hbs b/views/campaigns/view.hbs
index d02c92b5..bec02b86 100644
--- a/views/campaigns/view.hbs
+++ b/views/campaigns/view.hbs
@@ -294,6 +294,9 @@
{{short}}
+
{{clicks}}
|
@@ -339,32 +342,34 @@
{{/if}}
- {{#if isRss}}
-
-
- If a new entry is found from campaign feed a new subcampaign is created of that entry and it will be listed here
-
-
-
-
- #
- |
-
- Name
- |
-
- Description
- |
-
- Status
- |
-
- Created
- |
-
-
- |
-
-
+
+
+{{#if isRss}}
+
+
+ If a new entry is found from campaign feed a new subcampaign is created of that entry and it will be listed here
- {{/if}}
+
+
+
+ #
+ |
+
+ Name
+ |
+
+ Description
+ |
+
+ Status
+ |
+
+ Created
+ |
+
+
+ |
+
+
+
+{{/if}}
|