Skip to content

Commit

Permalink
feat: stories view counts (#2336)
Browse files Browse the repository at this point in the history
* blog views on stories

* update specs

* rename variables

* wildcards for blog cleanup deletion

* prevent action duplication, to adhere to unique key constraint

* clean up old duplicate actions before old object deletion

* cascade delete for actions-object fk

* cascade delete on all fk constraints

* add renamed migration
  • Loading branch information
lbiedinger authored Jun 4, 2024
1 parent 33a55cf commit 9a4458d
Show file tree
Hide file tree
Showing 4 changed files with 80 additions and 3 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
SET search_path TO EVENTS;

-- remove existing fk constraints and re-create them with cascade deletion

-- Actions table
ALTER TABLE actions
DROP CONSTRAINT fk_object;
ALTER TABLE actions
DROP CONSTRAINT fk_action_type;
ALTER TABLE actions
DROP CONSTRAINT fk_session;

ALTER TABLE actions
ADD CONSTRAINT fk_object FOREIGN KEY (object_id) REFERENCES objects (id) ON DELETE CASCADE;
ALTER TABLE actions
ADD CONSTRAINT fk_action_type FOREIGN KEY (action_type_id) REFERENCES action_types (id) ON DELETE CASCADE;
ALTER TABLE actions
ADD CONSTRAINT fk_session FOREIGN KEY (session_id) REFERENCES sessions (id) ON DELETE CASCADE;

-- History table
ALTER TABLE history
DROP CONSTRAINT fk_object;
ALTER TABLE history
DROP CONSTRAINT fk_action_type;

ALTER TABLE history
ADD CONSTRAINT fk_object FOREIGN KEY (object_id) REFERENCES objects (id) ON DELETE CASCADE;
ALTER TABLE history
ADD CONSTRAINT fk_action_type FOREIGN KEY (action_type_id) REFERENCES action_types (id) ON DELETE CASCADE;
44 changes: 44 additions & 0 deletions docker/compose/postgres/model/08-clean-up-blog-objects.psql
Original file line number Diff line number Diff line change
@@ -0,0 +1,44 @@
SET search_path TO EVENTS;

-- ensure an object for the '/stories' uri exists for all /blog uris

INSERT INTO objects (uri)
(SELECT DISTINCT REPLACE(uri, '/blog/', '/stories/')
FROM objects) ON CONFLICT DO NOTHING;

-- on actions/history linked to /blog/ objects, update the link to be to the /stories/ object
-- do not update old actions where a user viewed old & new objects in the same session already.

UPDATE actions
SET object_id=new_object_id
FROM
(SELECT old_actions.id old_action_id,
new_objects.id new_object_id
FROM objects old_objects
INNER JOIN objects new_objects ON new_objects.uri=REPLACE(old_objects.uri, '/blog/', '/stories/')
INNER JOIN actions old_actions ON old_actions.object_id=old_objects.id
LEFT JOIN actions duplicate_actions ON (
duplicate_actions.object_id=new_objects.id
AND duplicate_actions.session_id=old_actions.session_id
AND duplicate_actions.action_type_id=old_actions.action_type_id)
WHERE old_objects.uri like '%/blog/%'
AND new_objects.uri like '%/stories/%'
AND duplicate_actions.id IS NULL) old_actions_new_objects
WHERE id=old_action_id;

UPDATE history
SET object_id=new_id
FROM
(SELECT old.id old_id,
new.id new_id
FROM objects old
INNER JOIN objects new ON new.uri=REPLACE(old.uri, '/blog/', '/stories/')
WHERE old.uri like '%/blog/%'
AND new.uri like '%/stories/%') old_new
WHERE object_id=old_id;

-- delete the /blog/ objects

DELETE
FROM objects
WHERE uri like '%/blog/%';
8 changes: 6 additions & 2 deletions packages/portal/src/server-middleware/api/events/views.js
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,10 @@ export default (config = {}) => {
// Ignore any search query or hash
const uri = `${url.origin}${url.pathname}`;

// TODO: update old objects, then stop using legacy uris
// @/docker/compose/postgres/model/07-clean-up-blog-objects.psql
const legacyUri = url.pathname.startsWith('/stories') ? `${url.origin}${url.pathname.replace('/stories', '/blog')}` : uri;

const result = await pg.query(`
SELECT SUM(views) AS views
FROM
Expand All @@ -33,9 +37,9 @@ export default (config = {}) => {
LEFT JOIN events.action_types AT ON a.action_type_id=at.id
GROUP BY at.name,
o.uri) actions_and_history
WHERE action_type_name='view' AND (uri=$1 OR uri LIKE $2)
WHERE action_type_name='view' AND (uri=$1 OR uri=$2)
`,
[uri, `${uri}?%`]
[uri, legacyUri]
);

const viewCount = Number(result.rows[0]?.views);
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -48,7 +48,7 @@ describe('@/server-middleware/api/events/views', () => {

expect(pgPoolQuery.calledWith(
sinon.match((sql) => sql.trim().startsWith('SELECT ')),
['https://example.com/example', 'https://example.com/example?%']
['https://example.com/example', 'https://example.com/example']
)).toBe(true);
});

Expand Down

0 comments on commit 9a4458d

Please sign in to comment.