Labels: Improve photo count accuracy for MariaDB / MySQL users #584
This commit is contained in:
parent
98320235cb
commit
ac70e0f324
3 changed files with 28 additions and 42 deletions
|
@ -369,7 +369,7 @@ func (c *Config) UserConfig() ClientConfig {
|
|||
|
||||
c.Db().
|
||||
Table("labels").
|
||||
Select("MAX(photo_count) as label_max_photos, COUNT(*) AS labels").
|
||||
Select("MAX(photo_count) AS label_max_photos, COUNT(*) AS labels").
|
||||
Where("photo_count > 0").
|
||||
Where("deleted_at IS NULL").
|
||||
Where("(label_priority >= 0 OR label_favorite = 1)").
|
||||
|
|
|
@ -82,16 +82,17 @@ func UpdateSubjectCounts() (err error) {
|
|||
switch DbDialect() {
|
||||
case MySQL:
|
||||
res = Db().Exec(`UPDATE ? LEFT JOIN (
|
||||
SELECT m.subj_uid, COUNT(*) AS subj_files, COUNT(DISTINCT f.photo_id) AS subj_photos FROM ? f
|
||||
JOIN ? m ON f.file_uid = m.file_uid AND m.subj_uid IS NOT NULL AND m.subj_uid <> ''
|
||||
SELECT m.subj_uid, COUNT(DISTINCT f.id) AS subj_files, COUNT(DISTINCT f.photo_id) AS subj_photos FROM ? f
|
||||
JOIN ? m ON f.file_uid = m.file_uid AND m.subj_uid IS NOT NULL AND m.subj_uid <> '' AND m.subj_uid IS NOT NULL
|
||||
WHERE m.marker_invalid = 0 AND f.deleted_at IS NULL GROUP BY m.subj_uid
|
||||
) b ON b.subj_uid = subjects.subj_uid
|
||||
SET subjects.file_count = b.subj_files, subjects.photo_count = b.subj_photos
|
||||
SET subjects.file_count = CASE WHEN b.subj_files IS NULL THEN 0 ELSE b.subj_files END,
|
||||
subjects.photo_count = CASE WHEN b.subj_photos IS NULL THEN 0 ELSE b.subj_photos END
|
||||
WHERE ?`, gorm.Expr(subjTable), gorm.Expr(filesTable), gorm.Expr(markerTable), condition)
|
||||
case SQLite:
|
||||
// Update files count.
|
||||
res = Db().Table(subjTable).
|
||||
UpdateColumn("file_count", gorm.Expr("(SELECT COUNT(*) FROM files f "+
|
||||
UpdateColumn("file_count", gorm.Expr("(SELECT COUNT(DISTINCT f.id) FROM files f "+
|
||||
fmt.Sprintf("JOIN %s m ON f.file_uid = m.file_uid AND m.subj_uid = %s.subj_uid ",
|
||||
markerTable, subjTable)+" WHERE m.marker_invalid = 0 AND f.deleted_at IS NULL) WHERE ?", condition))
|
||||
|
||||
|
@ -100,7 +101,7 @@ func UpdateSubjectCounts() (err error) {
|
|||
return res.Error
|
||||
} else {
|
||||
photosRes := Db().Table(subjTable).
|
||||
UpdateColumn("photo_count", gorm.Expr("(SELECT COUNT(DISTINCT photo_id) FROM files f "+
|
||||
UpdateColumn("photo_count", gorm.Expr("(SELECT COUNT(DISTINCT f.photo_id) FROM files f "+
|
||||
fmt.Sprintf("JOIN %s m ON f.file_uid = m.file_uid AND m.subj_uid = %s.subj_uid ",
|
||||
markerTable, subjTable)+" WHERE m.marker_invalid = 0 AND f.deleted_at IS NULL) WHERE ?", condition))
|
||||
res.RowsAffected += photosRes.RowsAffected
|
||||
|
@ -123,28 +124,19 @@ func UpdateLabelPhotoCounts() (err error) {
|
|||
start := time.Now()
|
||||
var res *gorm.DB
|
||||
if IsDialect(MySQL) {
|
||||
res = Db().
|
||||
Table("labels").
|
||||
UpdateColumn("photo_count",
|
||||
gorm.Expr(`(SELECT photo_count FROM (
|
||||
SELECT label_id, SUM(photo_count) AS photo_count FROM (
|
||||
(SELECT l.id AS label_id, COUNT(*) AS photo_count FROM labels l
|
||||
JOIN photos_labels pl ON pl.label_id = l.id
|
||||
JOIN photos ph ON pl.photo_id = ph.id
|
||||
WHERE pl.uncertainty < 100
|
||||
AND ph.photo_quality >= 0
|
||||
AND ph.photo_private = 0
|
||||
AND ph.deleted_at IS NULL GROUP BY l.id)
|
||||
UNION ALL
|
||||
(SELECT l.id AS label_id, COUNT(*) AS photo_count FROM labels l
|
||||
JOIN categories c ON c.category_id = l.id
|
||||
JOIN photos_labels pl ON pl.label_id = c.label_id
|
||||
JOIN photos ph ON pl.photo_id = ph.id
|
||||
WHERE pl.uncertainty < 100
|
||||
AND ph.photo_quality >= 0
|
||||
AND ph.photo_private = 0
|
||||
AND ph.deleted_at IS NULL GROUP BY l.id)) counts GROUP BY label_id
|
||||
) label_counts WHERE label_id = labels.id)`))
|
||||
res = Db().Exec(`UPDATE labels LEFT JOIN (
|
||||
SELECT p2.label_id, COUNT(DISTINCT photo_id) AS label_photos FROM (
|
||||
SELECT pl.label_id as label_id, p.id AS photo_id FROM photos p
|
||||
JOIN photos_labels pl ON pl.photo_id = p.id AND pl.uncertainty < 100
|
||||
WHERE p.photo_quality > -1 AND p.photo_private = 0 AND p.deleted_at IS NULL
|
||||
UNION
|
||||
SELECT c.category_id as label_id, p.id AS photo_id FROM photos p
|
||||
JOIN photos_labels pl ON pl.photo_id = p.id AND pl.uncertainty < 100
|
||||
JOIN categories c ON c.label_id = pl.label_id
|
||||
WHERE p.photo_quality > -1 AND p.photo_private = 0 AND p.deleted_at IS NULL
|
||||
) p2 GROUP BY p2.label_id
|
||||
) b ON b.label_id = labels.id
|
||||
SET photo_count = CASE WHEN b.label_photos IS NULL THEN 0 ELSE b.label_photos END`)
|
||||
} else if IsDialect(SQLite) {
|
||||
res = Db().
|
||||
Table("labels").
|
||||
|
|
|
@ -17,16 +17,14 @@ func UpdateAlbumDefaultCovers() (err error) {
|
|||
|
||||
var res *gorm.DB
|
||||
|
||||
condition := gorm.Expr(
|
||||
"album_type = ? AND (thumb_src = ? OR thumb IS NULL OR thumb = '')",
|
||||
entity.AlbumDefault, entity.SrcDefault)
|
||||
condition := gorm.Expr("album_type = ? AND thumb_src = ?", entity.AlbumDefault, entity.SrcAuto)
|
||||
|
||||
switch DbDialect() {
|
||||
case MySQL:
|
||||
res = Db().Exec(`UPDATE albums LEFT JOIN (
|
||||
SELECT p2.album_uid, f.file_hash FROM files f, (
|
||||
SELECT pa.album_uid, max(p.id) AS photo_id FROM photos p
|
||||
JOIN photos_albums pa ON pa.photo_uid = p.photo_uid AND pa.hidden = 0
|
||||
JOIN photos_albums pa ON pa.photo_uid = p.photo_uid AND pa.hidden = 0 AND pa.missing = 0
|
||||
WHERE p.photo_quality > 0 AND p.photo_private = 0 AND p.deleted_at IS NULL
|
||||
GROUP BY pa.album_uid) p2 WHERE p2.photo_id = f.photo_id AND f.file_primary = 1 AND f.file_type = 'jpg'
|
||||
) b ON b.album_uid = albums.album_uid
|
||||
|
@ -35,7 +33,7 @@ func UpdateAlbumDefaultCovers() (err error) {
|
|||
res = Db().Table(entity.Album{}.TableName()).
|
||||
UpdateColumn("thumb", gorm.Expr(`(
|
||||
SELECT f.file_hash FROM files f
|
||||
JOIN photos_albums pa ON pa.album_uid = albums.album_uid AND pa.photo_uid = f.photo_uid AND pa.hidden = 0
|
||||
JOIN photos_albums pa ON pa.album_uid = albums.album_uid AND pa.photo_uid = f.photo_uid AND pa.hidden = 0 AND pa.missing = 0
|
||||
JOIN photos p ON p.id = f.photo_id AND p.photo_private = 0 AND p.deleted_at IS NULL AND p.photo_quality > 0
|
||||
WHERE f.deleted_at IS NULL AND f.file_missing = 0 AND f.file_hash <> '' AND f.file_primary = 1 AND f.file_type = 'jpg'
|
||||
ORDER BY p.taken_at DESC LIMIT 1
|
||||
|
@ -64,9 +62,7 @@ func UpdateAlbumFolderCovers() (err error) {
|
|||
|
||||
var res *gorm.DB
|
||||
|
||||
condition := gorm.Expr(
|
||||
"album_type = ? AND (thumb_src = ? OR thumb IS NULL OR thumb = '')",
|
||||
entity.AlbumFolder, entity.SrcAuto)
|
||||
condition := gorm.Expr("album_type = ? AND thumb_src = ?", entity.AlbumFolder, entity.SrcAuto)
|
||||
|
||||
switch DbDialect() {
|
||||
case MySQL:
|
||||
|
@ -111,9 +107,7 @@ func UpdateAlbumMonthCovers() (err error) {
|
|||
|
||||
var res *gorm.DB
|
||||
|
||||
condition := gorm.Expr(
|
||||
"album_type = ? AND (thumb_src = ? OR thumb IS NULL OR thumb = '')",
|
||||
entity.AlbumMonth, entity.SrcAuto)
|
||||
condition := gorm.Expr("album_type = ? AND thumb_src = ?", entity.AlbumMonth, entity.SrcAuto)
|
||||
|
||||
switch DbDialect() {
|
||||
case MySQL:
|
||||
|
@ -178,7 +172,7 @@ func UpdateLabelCovers() (err error) {
|
|||
|
||||
var res *gorm.DB
|
||||
|
||||
condition := gorm.Expr("(thumb_src = ? OR thumb IS NULL OR thumb = '')", entity.SrcAuto)
|
||||
condition := gorm.Expr("thumb_src = ?", entity.SrcAuto)
|
||||
|
||||
switch DbDialect() {
|
||||
case MySQL:
|
||||
|
@ -194,7 +188,7 @@ func UpdateLabelCovers() (err error) {
|
|||
JOIN categories c ON c.label_id = pl.label_id
|
||||
WHERE p.photo_quality > 0 AND p.photo_private = 0 AND p.deleted_at IS NULL
|
||||
GROUP BY c.category_id
|
||||
) p2 WHERE p2.photo_id = f.photo_id AND f.file_primary = 1 AND f.file_type = 'jpg'
|
||||
) p2 WHERE p2.photo_id = f.photo_id AND f.file_primary = 1 AND f.file_type = 'jpg' AND f.file_missing = 0
|
||||
) b ON b.label_id = labels.id
|
||||
SET thumb = b.file_hash WHERE ?`, condition)
|
||||
case SQLite:
|
||||
|
@ -246,7 +240,7 @@ func UpdateSubjectCovers() (err error) {
|
|||
markerTable := entity.Marker{}.TableName()
|
||||
|
||||
condition := gorm.Expr(
|
||||
fmt.Sprintf("%s.subj_type = ? AND (thumb_src = ? OR thumb IS NULL OR thumb = '')", subjTable),
|
||||
fmt.Sprintf("%s.subj_type = ? AND thumb_src = ?", subjTable),
|
||||
entity.SubjPerson, entity.SrcAuto)
|
||||
|
||||
// TODO: Avoid using private photos as subject covers.
|
||||
|
|
Loading…
Reference in a new issue