Optimize gallery sort by likes or comments

This commit is contained in:
Noah Petherbridge 2024-09-21 16:59:37 -07:00
parent 944b2e28e9
commit 0cd72a96ed
3 changed files with 49 additions and 42 deletions

View File

@ -13,8 +13,8 @@ import (
// Comment table - in forum threads, on profiles or photos, etc.
type Comment struct {
ID uint64 `gorm:"primaryKey"`
TableName string `gorm:"index"`
TableID uint64 `gorm:"index"`
TableName string `gorm:"index:idx_comment_composite"`
TableID uint64 `gorm:"index:idx_comment_composite"`
UserID uint64 `gorm:"index"`
User User `json:"-"`
Message string

View File

@ -11,8 +11,8 @@ import (
type Like struct {
ID uint64 `gorm:"primaryKey"`
UserID uint64 `gorm:"index"` // who it belongs to
TableName string `gorm:"index"`
TableID uint64 `gorm:"index"`
TableName string `gorm:"index:idx_likes_composite"`
TableID uint64 `gorm:"index:idx_likes_composite"`
CreatedAt time.Time `gorm:"index"`
UpdatedAt time.Time
}

View File

@ -570,9 +570,9 @@ func PaginateGalleryPhotos(user *User, conf Gallery, pager *Pagination) ([]*Phot
// Shy users can only see their Friends photos (public or friends visibility)
// and any Private photos to whom they were granted access.
visOrs = append(visOrs,
fmt.Sprintf("(user_id IN %s AND visibility IN ?)", friendsQuery),
"(user_id IN ? AND visibility IN ?)",
"user_id = ?",
fmt.Sprintf("(photos.user_id IN %s AND photos.visibility IN ?)", friendsQuery),
"(photos.user_id IN ? AND photos.visibility IN ?)",
"photos.user_id = ?",
)
visPlaceholders = append(visPlaceholders,
photosFriends,
@ -582,23 +582,23 @@ func PaginateGalleryPhotos(user *User, conf Gallery, pager *Pagination) ([]*Phot
} else if friendsOnly {
// User wants to see only self and friends photos.
visOrs = append(visOrs,
fmt.Sprintf("(user_id IN %s AND visibility IN ?)", friendsQuery),
"user_id = ?",
fmt.Sprintf("(photos.user_id IN %s AND photos.visibility IN ?)", friendsQuery),
"photos.user_id = ?",
)
visPlaceholders = append(visPlaceholders, photosFriends, userID)
// If their friends granted private photos, include those too.
if len(privateUserIDsAreFriends) > 0 {
visOrs = append(visOrs, "(user_id IN ? AND visibility IN ?)")
visOrs = append(visOrs, "(photos.user_id IN ? AND photos.visibility IN ?)")
visPlaceholders = append(visPlaceholders, privateUserIDsAreFriends, photosPrivate)
}
} else {
// You can see friends' Friend photos but only public for non-friends.
visOrs = append(visOrs,
fmt.Sprintf("(user_id IN %s AND visibility IN ?)", friendsQuery),
"(user_id IN ? AND visibility IN ?)",
fmt.Sprintf("(user_id NOT IN %s AND visibility IN ?)", friendsQuery),
"user_id = ?",
fmt.Sprintf("(photos.user_id IN %s AND photos.visibility IN ?)", friendsQuery),
"(photos.user_id IN ? AND photos.visibility IN ?)",
fmt.Sprintf("(photos.user_id NOT IN %s AND photos.visibility IN ?)", friendsQuery),
"photos.user_id = ?",
)
visPlaceholders = append(placeholders,
photosFriends,
@ -613,7 +613,7 @@ func PaginateGalleryPhotos(user *User, conf Gallery, pager *Pagination) ([]*Phot
placeholders = append(placeholders, visPlaceholders...)
// Gallery photos only.
wheres = append(wheres, "gallery = ?")
wheres = append(wheres, "photos.gallery = ?")
placeholders = append(placeholders, true)
// Filter by photos the user has liked.
@ -622,9 +622,9 @@ func PaginateGalleryPhotos(user *User, conf Gallery, pager *Pagination) ([]*Phot
EXISTS (
SELECT 1
FROM likes
WHERE user_id = ?
AND table_name = 'photos'
AND table_id = photos.id
WHERE likes.user_id = ?
AND likes.table_name = 'photos'
AND likes.table_id = photos.id
)
`)
placeholders = append(placeholders, user.ID)
@ -632,39 +632,39 @@ func PaginateGalleryPhotos(user *User, conf Gallery, pager *Pagination) ([]*Phot
// Filter blocked users.
if len(blocklist) > 0 {
wheres = append(wheres, "user_id NOT IN ?")
wheres = append(wheres, "photos.user_id NOT IN ?")
placeholders = append(placeholders, blocklist)
}
// Non-explicit pics unless the user opted in. Allow explicit filter setting to override.
if filterExplicit != "" {
wheres = append(wheres, "explicit = ?")
wheres = append(wheres, "photos.explicit = ?")
placeholders = append(placeholders, filterExplicit == "true")
} else if !explicitOK {
wheres = append(wheres, "explicit = ?")
wheres = append(wheres, "photos.explicit = ?")
placeholders = append(placeholders, false)
}
// Is the user furthermore clamping the visibility filter?
if filterVisibility != "" {
wheres = append(wheres, "visibility = ?")
wheres = append(wheres, "photos.visibility = ?")
placeholders = append(placeholders, filterVisibility)
}
// Only certified (and not banned) user photos.
if conf.Uncertified {
wheres = append(wheres,
"EXISTS (SELECT 1 FROM users WHERE id = photos.user_id AND certified IS NOT true AND status='active')",
"EXISTS (SELECT 1 FROM users WHERE id = photos.user_id AND users.certified IS NOT true AND users.status='active')",
)
} else {
wheres = append(wheres,
"EXISTS (SELECT 1 FROM users WHERE id = photos.user_id AND certified = true AND status='active')",
"EXISTS (SELECT 1 FROM users WHERE id = photos.user_id AND users.certified = true AND users.status='active')",
)
}
// Exclude private users' photos.
wheres = append(wheres,
"NOT EXISTS (SELECT 1 FROM users WHERE id = photos.user_id AND visibility = 'private')",
"NOT EXISTS (SELECT 1 FROM users WHERE id = photos.user_id AND photos.visibility = 'private')",
)
// Admin view: get ALL PHOTOS on the site, period.
@ -673,14 +673,14 @@ func PaginateGalleryPhotos(user *User, conf Gallery, pager *Pagination) ([]*Phot
// Admin may filter too.
if filterVisibility != "" {
query = query.Where("visibility = ?", filterVisibility)
query = query.Where("photos.visibility = ?", filterVisibility)
}
if filterExplicit != "" {
query = query.Where("explicit = ?", filterExplicit == "true")
query = query.Where("photos.explicit = ?", filterExplicit == "true")
}
if conf.Uncertified {
query = query.Where(
"EXISTS (SELECT 1 FROM users WHERE id = photos.user_id AND certified IS NOT true AND status='active')",
"EXISTS (SELECT 1 FROM users WHERE id = photos.user_id AND users.certified IS NOT true AND users.status='active')",
)
}
} else {
@ -690,27 +690,34 @@ func PaginateGalleryPhotos(user *User, conf Gallery, pager *Pagination) ([]*Phot
)
}
// Get count pre-sorting.
query.Model(&Photo{}).Count(&pager.Total)
// Custom SORT parameters.
switch pager.Sort {
case "by_likes":
pager.Sort = `(
SELECT count(likes.id)
FROM likes
WHERE likes.table_name = 'photos'
AND likes.table_id = photos.id
) DESC`
query = query.Select(`
photos.*,
COUNT(likes.id) AS like_count
`).Joins(
"LEFT OUTER JOIN likes ON (likes.table_name='photos' AND likes.table_id=photos.id)",
).Where(
"likes.table_name = 'photos' AND likes.table_id = photos.id",
).Group("photos.id")
pager.Sort = `like_count DESC`
case "by_comments":
pager.Sort = `(
SELECT count(comments.id)
FROM comments
WHERE comments.table_name = 'photos'
AND comments.table_id = photos.id
) DESC NULLS LAST`
query = query.Select(`
photos.*,
COUNT(comments.id) AS comment_count
`).Joins(
"LEFT OUTER JOIN comments ON (comments.table_name='photos' AND comments.table_id=photos.id)",
).Where(
"comments.table_name = 'photos' AND comments.table_id = photos.id",
).Group("photos.id")
pager.Sort = `comment_count DESC`
}
query = query.Order(pager.Sort)
query.Model(&Photo{}).Count(&pager.Total)
result := query.Offset(pager.GetOffset()).Limit(pager.PerPage).Find(&p)
return p, result.Error
}