Skip to content

Commit

Permalink
merge the read and fav tables into a single table
Browse files Browse the repository at this point in the history
  • Loading branch information
urandom committed Sep 11, 2015
1 parent ae089b2 commit 22bbc56
Show file tree
Hide file tree
Showing 17 changed files with 322 additions and 249 deletions.
1 change: 0 additions & 1 deletion TODO
Original file line number Diff line number Diff line change
@@ -1,4 +1,3 @@
* Merge users_articles_read and users_articles_fav into a single table
* Create indexes for foreign key columns that are used in queries
* Non-fatal API errors
* TinyRSS API emulation
86 changes: 23 additions & 63 deletions content/sql/article.go
Original file line number Diff line number Diff line change
Expand Up @@ -174,6 +174,14 @@ func updateArticle(a content.Article, tx *sqlx.Tx, db *db.DB, logger webfw.Logge
}

func (ua *UserArticle) Read(read bool) {
ua.updateState(read, ua.Data().Favorite)
}

func (ua *UserArticle) Favorite(favorite bool) {
ua.updateState(ua.Data().Read, favorite)
}

func (ua *UserArticle) updateState(read, favorite bool) {
if ua.HasErr() {
return
}
Expand All @@ -185,7 +193,7 @@ func (ua *UserArticle) Read(read bool) {
}

login := ua.User().Data().Login
ua.logger.Infof("Marking user '%s' article '%d' as read: %v\n", login, d.Id, read)
ua.logger.Infof("Updating user '%s' article '%d' state: read = %v, fav = %v\n", login, d.Id, read, favorite)

tx, err := ua.db.Beginx()
if err != nil {
Expand All @@ -194,88 +202,40 @@ func (ua *UserArticle) Read(read bool) {
}
defer tx.Rollback()

stmt, err := tx.Preparex(ua.db.SQL("delete_user_article_read"))
stmt, err := tx.Preparex(ua.db.SQL("update_user_article_state"))

if err != nil {
ua.Err(err)
ua.Err(fmt.Errorf("Error updating article %s state: %v", ua, err))
return
}
defer stmt.Close()

_, err = stmt.Exec(login, d.Id)
res, err := stmt.Exec(read, favorite, login, d.Id)
if err != nil {
ua.Err(err)
return
}

d.Read = read

if read {
stmt, err = tx.Preparex(ua.db.SQL("create_user_article_read"))
if num, err := res.RowsAffected(); err != nil || num == 0 {
stmt, err := tx.Preparex(ua.db.SQL("create_user_article_state"))
if err != nil {
ua.Err(err)
ua.Err(fmt.Errorf("Error creating article %s state: %v", ua, err))
return
}
defer stmt.Close()

_, err = stmt.Exec(login, d.Id)
ua.Err(err)
}

tx.Commit()

ua.Data(d)
}

func (ua *UserArticle) Favorite(favorite bool) {
if ua.HasErr() {
return
}

d := ua.Data()
if d.Id == 0 {
ua.Err(content.NewValidationError(errors.New("Invalid article id")))
return
}

login := ua.User().Data().Login
ua.logger.Infof("Marking user '%s' article '%d' as favorite: %v\n", login, d.Id, favorite)

tx, err := ua.db.Beginx()
if err != nil {
ua.Err(err)
return
}
defer tx.Rollback()

stmt, err := tx.Preparex(ua.db.SQL("delete_user_article_favorite"))

if err != nil {
ua.Err(err)
return
}
defer stmt.Close()

_, err = stmt.Exec(login, d.Id)
if err != nil {
ua.Err(err)
return
}

d.Favorite = favorite

if favorite {
stmt, err = tx.Preparex(ua.db.SQL("create_user_article_favorite"))
_, err = stmt.Exec(login, d.Id, read, favorite)
if err != nil {
ua.Err(err)
return
}
defer stmt.Close()
_, err = stmt.Exec(login, d.Id)
ua.Err(err)
}

tx.Commit()

ua.Data(d)
if err := tx.Commit(); err == nil {
d.Read = read
d.Favorite = favorite
ua.Data(d)
} else {
ua.Err(err)
}
}
31 changes: 12 additions & 19 deletions content/sql/db/base/article.go
Original file line number Diff line number Diff line change
Expand Up @@ -3,10 +3,8 @@ package base
func init() {
sql["create_feed_article"] = createFeedArticle
sql["update_feed_article"] = updateFeedArticle
sql["create_user_article_read"] = createUserArticleRead
sql["delete_user_article_read"] = deleteUserArticleRead
sql["create_user_article_favorite"] = createUserArticleFavorite
sql["delete_user_article_favorite"] = deleteUserArticleFavorite
sql["create_user_article_state"] = createUserArticleState
sql["update_user_article_state"] = updateUserArticleState
sql["get_article_scores"] = getArticleScores
sql["create_article_scores"] = createArticleScores
sql["update_article_scores"] = updateArticleScores
Expand All @@ -31,23 +29,18 @@ UPDATE articles SET title = $1, description = $2, date = $3, guid = $4, link = $
WHERE feed_id = $6 AND (guid = $4 OR link = $5)
`

createUserArticleRead = `
INSERT INTO users_articles_read(user_login, article_id)
SELECT $1, $2 EXCEPT
SELECT user_login, article_id
FROM users_articles_read WHERE user_login = $1 AND article_id = $2
createUserArticleState = `
INSERT INTO users_articles_states(user_login, article_id, read, favorite)
SELECT $1, $2, $3, $4 EXCEPT
SELECT user_login, article_id, CAST($3 AS BOOLEAN), CAST($4 AS BOOLEAN)
FROM users_articles_states WHERE user_login = $1 AND article_id = $2
`
deleteUserArticleRead = `
DELETE FROM users_articles_read WHERE user_login = $1 AND article_id = $2`
createUserArticleFavorite = `
INSERT INTO users_articles_fav(user_login, article_id)
SELECT $1, $2 EXCEPT
SELECT user_login, article_id
FROM users_articles_fav WHERE user_login = $1 AND article_id = $2
`
deleteUserArticleFavorite = `
DELETE FROM users_articles_fav WHERE user_login = $1 AND article_id = $2

updateUserArticleState = `
UPDATE users_articles_states SET read = $1, favorite = $2
WHERE user_login = $3 AND article_id = $4
`

getArticleScores = `
SELECT asco.score, asco.score1, asco.score2, asco.score3, asco.score4, asco.score5
FROM articles_scores asco
Expand Down
39 changes: 23 additions & 16 deletions content/sql/db/base/feed.go
Original file line number Diff line number Diff line change
Expand Up @@ -9,8 +9,8 @@ func init() {
sql["get_hubbub_subscription"] = getHubbubSubscription
sql["get_feed_users"] = getFeedUsers
sql["delete_user_feed"] = deleteUserFeed
sql["create_all_users_articles_read_by_feed_date"] = createAllUsersArticlesReadByFeedDate
sql["delete_all_users_articles_read_by_feed_date"] = deleteAllUsersArticlesReadByFeedDate
sql["create_missing_user_article_state_by_feed_date"] = createMissingUserArticleStateByFeedDate
sql["update_all_user_article_state_by_feed_date"] = updateAllUserArticleReadStateByFeedDate
sql["create_user_feed_tag"] = createUserFeedTag
sql["delete_user_feed_tags"] = deleteUserFeedTags
sql["get_user_feed_tags"] = getUserFeedTags
Expand Down Expand Up @@ -43,20 +43,27 @@ SELECT u.login, u.first_name, u.last_name, u.email, u.admin, u.active,
FROM users u, users_feeds uf
WHERE u.login = uf.user_login AND uf.feed_id = $1
`
deleteUserFeed = `DELETE FROM users_feeds WHERE user_login = $1 AND feed_id = $2`
createAllUsersArticlesReadByFeedDate = `
INSERT INTO users_articles_read
SELECT uf.user_login, a.id
FROM users_feeds uf INNER JOIN articles a
ON uf.feed_id = a.feed_id AND uf.user_login = $1 AND uf.feed_id = $2
AND a.id IN (SELECT id FROM articles WHERE date IS NULL OR date < $3)
`
deleteUserFeed = `DELETE FROM users_feeds WHERE user_login = $1 AND feed_id = $2`

deleteAllUsersArticlesReadByFeedDate = `
DELETE FROM users_articles_read WHERE user_login = $1 AND article_id IN (
SELECT id FROM articles WHERE feed_id = $2 AND (date IS NULL OR date < $3)
createMissingUserArticleStateByFeedDate = `
INSERT INTO users_articles_states (user_login, article_id)
SELECT uf.user_login, a.id
FROM users_feeds uf INNER JOIN articles a
ON uf.feed_id = a.feed_id AND uf.user_login = $1 AND uf.feed_id = $2
AND a.id IN (
SELECT id FROM articles where date IS NULL OR date < $3
)
EXCEPT SELECT uas.user_login, uas.article_id
FROM articles a INNER JOIN users_articles_states uas
ON a.id = uas.article_id
WHERE uas.user_login = $1 AND a.feed_id = $2
`
updateAllUserArticleReadStateByFeedDate = `
UPDATE users_articles_states SET read = $1 WHERE user_login = $2 AND article_id IN (
SELECT id FROM articles WHERE feed_id = $3 AND (date IS NULL OR date < $4)
)
`

getUserFeedTags = `SELECT tag FROM users_feeds_tags WHERE user_login = $1 AND feed_id = $2`
createUserFeedTag = `
INSERT INTO users_feeds_tags(user_login, feed_id, tag)
Expand All @@ -73,8 +80,8 @@ FROM users_feeds uf INNER JOIN articles a
ON uf.feed_id = a.feed_id
AND uf.user_login = $1
AND uf.feed_id = $2
LEFT OUTER JOIN users_articles_read ar
ON a.id = ar.article_id AND uf.user_login = ar.user_login
WHERE ar.article_id IS NULL
LEFT OUTER JOIN users_articles_states uas
ON a.id = uas.article_id AND uf.user_login = uas.user_login
WHERE uas.article_id IS NULL OR NOT uas.read
`
)
51 changes: 29 additions & 22 deletions content/sql/db/base/tag.go
Original file line number Diff line number Diff line change
Expand Up @@ -2,8 +2,8 @@ package base

func init() {
sql["get_user_tag_feeds"] = getUserTagFeeds
sql["create_all_user_tag_articles_read_by_date"] = createAllUserTagArticlesByDate
sql["delete_all_user_tag_articles_read_by_date"] = deleteAllUserTagArticlesByDate
sql["create_missing_user_article_state_by_tag_date"] = createMissingUserArticleStateByTagDate
sql["update_all_user_article_state_by_tag_date"] = updateAllUserArticleReadStateByTagDate
sql["get_tag_unread_count"] = getTagUnreadCount
}

Expand All @@ -15,24 +15,31 @@ WHERE f.id = uft.feed_id
AND uft.user_login = $1 AND uft.tag = $2
ORDER BY LOWER(f.title)
`
createAllUserTagArticlesByDate = `
INSERT INTO users_articles_read
SELECT uf.user_login, a.id
FROM users_feeds uf INNER JOIN users_feeds_tags uft
ON uft.feed_id = uf.feed_id AND uft.user_login = uf.user_login
AND uft.user_login = $1 AND uft.tag = $2
INNER JOIN articles a
ON uf.feed_id = a.feed_id
AND a.id IN (SELECT id FROM articles WHERE date IS NULL OR date < $3)
`

deleteAllUserTagArticlesByDate = `
DELETE FROM users_articles_read WHERE user_login = $1
AND article_id IN (
SELECT feed_id FROM users_feeds_tags WHERE user_login = $1 AND tag = $2
) AND article_id IN (
SELECT id FROM articles WHERE date IS NULL OR date < $3
createMissingUserArticleStateByTagDate = `
INSERT INTO users_articles_states (user_login, article_id)
SELECT uf.user_login, a.id
FROM users_feeds uf INNER JOIN users_feeds_tags uft
ON uft.feed_id = uf.feed_id AND uft.user_login = uf.user_login
AND uft.user_login = $1 AND uft.tag = $2
INNER JOIN articles a
ON uf.feed_id = a.feed_id
AND a.id IN (
SELECT id FROM articles where date IS NULL OR date < $3
)
EXCEPT SELECT uas.user_login, uas.article_id
FROM articles a INNER JOIN users_feeds_tags uft
ON a.feed_id = uft.feed_id
INNER JOIN users_articles_states uas
ON a.id = uas.article_id
WHERE uas.user_login = $1 AND uft.tag = $2
`
updateAllUserArticleReadStateByTagDate = `
UPDATE users_articles_states SET read = $1 WHERE user_login = $2 AND article_id IN (
SELECT a.id
FROM articles a INNER JOIN users_feeds_tags uft
ON a.feed_id = uft.feed_id
WHERE uft.tag = $3 AND (date IS NULL OR date < $4)
)
`
getTagUnreadCount = `
SELECT count(a.id)
Expand All @@ -43,8 +50,8 @@ INNER JOIN users_feeds_tags uft
ON uft.feed_id = uf.feed_id
AND uft.user_login = uf.user_login
AND uft.tag = $2
LEFT OUTER JOIN users_articles_read ar
ON a.id = ar.article_id AND uf.user_login = ar.user_login
WHERE ar.article_id IS NULL
LEFT OUTER JOIN users_articles_states uas
ON a.id = uas.article_id AND uf.user_login = uas.user_login
WHERE uas.article_id IS NULL OR NOT uas.read
`
)
Loading

0 comments on commit 22bbc56

Please sign in to comment.