1
|
|
|
<?php declare(strict_types=1); |
2
|
|
|
|
3
|
|
|
/** |
4
|
|
|
* ownCloud - Music app |
5
|
|
|
* |
6
|
|
|
* This file is licensed under the Affero General Public License version 3 or |
7
|
|
|
* later. See the COPYING file. |
8
|
|
|
* |
9
|
|
|
* @author Morris Jobke <[email protected]> |
10
|
|
|
* @author Pauli Järvinen <[email protected]> |
11
|
|
|
* @copyright Morris Jobke 2013, 2014 |
12
|
|
|
* @copyright Pauli Järvinen 2016 - 2025 |
13
|
|
|
*/ |
14
|
|
|
|
15
|
|
|
namespace OCA\Music\Db; |
16
|
|
|
|
17
|
|
|
use OCA\Music\Utility\ArrayUtil; |
18
|
|
|
use OCA\Music\Utility\StringUtil; |
19
|
|
|
|
20
|
|
|
use OCP\IConfig; |
21
|
|
|
use OCP\IDBConnection; |
22
|
|
|
|
23
|
|
|
/** |
24
|
|
|
* Type hint a base class method to help Scrutinizer |
25
|
|
|
* @method Album updateOrInsert(Album $album) |
26
|
|
|
* @phpstan-extends BaseMapper<Album> |
27
|
|
|
*/ |
28
|
|
|
class AlbumMapper extends BaseMapper { |
29
|
|
|
public function __construct(IDBConnection $db, IConfig $config) { |
30
|
|
|
parent::__construct($db, $config, 'music_albums', Album::class, 'name', ['user_id', 'hash'], 'album_artist_id'); |
31
|
|
|
} |
32
|
|
|
|
33
|
|
|
/** |
34
|
|
|
* Override the base implementation to include data from multiple tables |
35
|
|
|
* |
36
|
|
|
* {@inheritdoc} |
37
|
|
|
* @see BaseMapper::selectEntities() |
38
|
|
|
*/ |
39
|
|
|
protected function selectEntities(string $condition, ?string $extension=null) : string { |
40
|
|
|
return "SELECT `*PREFIX*music_albums`.*, `artist`.`name` AS `album_artist_name` |
41
|
|
|
FROM `*PREFIX*music_albums` |
42
|
|
|
INNER JOIN `*PREFIX*music_artists` `artist` |
43
|
|
|
ON `*PREFIX*music_albums`.`album_artist_id` = `artist`.`id` |
44
|
|
|
WHERE $condition $extension"; |
45
|
|
|
} |
46
|
|
|
|
47
|
|
|
/** |
48
|
|
|
* Overridden from \OCA\Music\Db\BaseMapper to add support for sorting by artist. |
49
|
|
|
* |
50
|
|
|
* {@inheritdoc} |
51
|
|
|
* @see BaseMapper::formatSortingClause() |
52
|
|
|
*/ |
53
|
|
|
protected function formatSortingClause(int $sortBy, bool $invertSort = false) : ?string { |
54
|
|
|
if ($sortBy === SortBy::Parent) { |
55
|
|
|
// Note: the alternative form "LOWER(`album_artist_name`) wouldn't work on PostgreSQL, see https://github.com/owncloud/music/issues/1046 |
56
|
|
|
$dir = $invertSort ? 'DESC' : 'ASC'; |
57
|
|
|
return "ORDER BY LOWER(`artist`.`name`) $dir, LOWER(`*PREFIX*music_albums`.`name`) $dir"; |
58
|
|
|
} else { |
59
|
|
|
return parent::formatSortingClause($sortBy, $invertSort); |
60
|
|
|
} |
61
|
|
|
} |
62
|
|
|
|
63
|
|
|
/** |
64
|
|
|
* returns artist IDs mapped to album IDs |
65
|
|
|
* does not include album_artist_id |
66
|
|
|
* |
67
|
|
|
* @param integer[]|null $albumIds IDs of the albums; get all albums of the user if null given |
68
|
|
|
* @param string $userId the user ID |
69
|
|
|
* @return array int => int[], keys are albums IDs and values are arrays of artist IDs |
70
|
|
|
*/ |
71
|
|
|
public function getPerformingArtistsByAlbumId(?array $albumIds, string $userId) : array { |
72
|
|
|
$sql = 'SELECT DISTINCT `track`.`album_id`, `track`.`artist_id` |
73
|
|
|
FROM `*PREFIX*music_tracks` `track` |
74
|
|
|
WHERE `track`.`user_id` = ? '; |
75
|
|
|
$params = [$userId]; |
76
|
|
|
|
77
|
|
|
if ($albumIds !== null) { |
|
|
|
|
78
|
|
|
$sql .= 'AND `track`.`album_id` IN ' . $this->questionMarks(\count($albumIds)); |
79
|
|
|
$params = \array_merge($params, $albumIds); |
80
|
|
|
} |
81
|
|
|
|
82
|
|
|
$result = $this->execute($sql, $params); |
83
|
|
|
$artistIds = []; |
84
|
|
|
while ($row = $result->fetch()) { |
85
|
|
|
$artistIds[$row['album_id']][] = (int)$row['artist_id']; |
86
|
|
|
} |
87
|
|
|
return $artistIds; |
88
|
|
|
} |
89
|
|
|
|
90
|
|
|
/** |
91
|
|
|
* returns release years mapped to album IDs |
92
|
|
|
* |
93
|
|
|
* @param integer[]|null $albumIds IDs of the albums; get all albums of the user if null given |
94
|
|
|
* @param string $userId the user ID |
95
|
|
|
* @return array int => int[], keys are albums IDs and values are arrays of years |
96
|
|
|
*/ |
97
|
|
|
public function getYearsByAlbumId(?array $albumIds, string $userId) : array { |
98
|
|
|
$sql = 'SELECT DISTINCT `track`.`album_id`, `track`.`year` |
99
|
|
|
FROM `*PREFIX*music_tracks` `track` |
100
|
|
|
WHERE `track`.`user_id` = ? |
101
|
|
|
AND `track`.`year` IS NOT NULL '; |
102
|
|
|
$params = [$userId]; |
103
|
|
|
|
104
|
|
|
if ($albumIds !== null) { |
|
|
|
|
105
|
|
|
$sql .= 'AND `track`.`album_id` IN ' . $this->questionMarks(\count($albumIds)); |
106
|
|
|
$params = \array_merge($params, $albumIds); |
107
|
|
|
} |
108
|
|
|
|
109
|
|
|
$result = $this->execute($sql, $params); |
110
|
|
|
$years = []; |
111
|
|
|
while ($row = $result->fetch()) { |
112
|
|
|
$years[$row['album_id']][] = (int)$row['year']; |
113
|
|
|
} |
114
|
|
|
return $years; |
115
|
|
|
} |
116
|
|
|
|
117
|
|
|
/** |
118
|
|
|
* returns genres mapped to album IDs |
119
|
|
|
* |
120
|
|
|
* @param integer[]|null $albumIds IDs of the albums; get all albums of the user if null given |
121
|
|
|
* @param string $userId the user ID |
122
|
|
|
* @return array int => Genre[], keys are albums IDs and values are arrays of *partial* Genre objects (only id and name properties set) |
123
|
|
|
*/ |
124
|
|
|
public function getGenresByAlbumId(?array $albumIds, string $userId) : array { |
125
|
|
|
$sql = 'SELECT DISTINCT `album_id`, `genre_id`, `*PREFIX*music_genres`.`name` AS `genre_name` |
126
|
|
|
FROM `*PREFIX*music_tracks` |
127
|
|
|
LEFT JOIN `*PREFIX*music_genres` |
128
|
|
|
ON `genre_id` = `*PREFIX*music_genres`.`id` |
129
|
|
|
WHERE `*PREFIX*music_tracks`.`user_id` = ? |
130
|
|
|
AND `genre_id` IS NOT NULL '; |
131
|
|
|
$params = [$userId]; |
132
|
|
|
|
133
|
|
|
if ($albumIds !== null) { |
|
|
|
|
134
|
|
|
$sql .= 'AND `album_id` IN ' . $this->questionMarks(\count($albumIds)); |
135
|
|
|
$params = \array_merge($params, $albumIds); |
136
|
|
|
} |
137
|
|
|
|
138
|
|
|
$result = $this->execute($sql, $params); |
139
|
|
|
$genres = []; |
140
|
|
|
while ($row = $result->fetch()) { |
141
|
|
|
$genre = new Genre(); |
142
|
|
|
$genre->setUserId($userId); |
143
|
|
|
$genre->setId((int)$row['genre_id']); |
144
|
|
|
$genre->setName($row['genre_name']); |
145
|
|
|
$genres[$row['album_id']][] = $genre; |
146
|
|
|
} |
147
|
|
|
return $genres; |
148
|
|
|
} |
149
|
|
|
|
150
|
|
|
/** |
151
|
|
|
* returns number of disks per album ID |
152
|
|
|
* |
153
|
|
|
* @param integer[]|null $albumIds IDs of the albums; get all albums of the user if null given |
154
|
|
|
* @param string $userId the user ID |
155
|
|
|
* @return array int => int, keys are albums IDs and values are disk counts |
156
|
|
|
*/ |
157
|
|
|
public function getDiscCountByAlbumId(?array $albumIds, string $userId) : array { |
158
|
|
|
$sql = 'SELECT `album_id`, MAX(`disk`) AS `disc_count` |
159
|
|
|
FROM `*PREFIX*music_tracks` |
160
|
|
|
WHERE `user_id` = ? |
161
|
|
|
GROUP BY `album_id` '; |
162
|
|
|
$params = [$userId]; |
163
|
|
|
|
164
|
|
|
if ($albumIds !== null) { |
|
|
|
|
165
|
|
|
$sql .= 'HAVING `album_id` IN ' . $this->questionMarks(\count($albumIds)); |
166
|
|
|
$params = \array_merge($params, $albumIds); |
167
|
|
|
} |
168
|
|
|
|
169
|
|
|
$result = $this->execute($sql, $params); |
170
|
|
|
$diskCountByAlbum = []; |
171
|
|
|
while ($row = $result->fetch()) { |
172
|
|
|
$diskCountByAlbum[$row['album_id']] = (int)$row['disc_count']; |
173
|
|
|
} |
174
|
|
|
return $diskCountByAlbum; |
175
|
|
|
} |
176
|
|
|
|
177
|
|
|
/** |
178
|
|
|
* returns summed track play counts of each album of the user, omitting albums which have never been played |
179
|
|
|
* |
180
|
|
|
* @return array [int => int], keys are album IDs and values are play count sums; ordered largest counts first |
181
|
|
|
*/ |
182
|
|
|
public function getAlbumTracksPlayCount(string $userId, ?int $limit=null, ?int $offset=null) : array { |
183
|
|
|
$sql = 'SELECT `album_id`, SUM(`play_count`) AS `sum_count` |
184
|
|
|
FROM `*PREFIX*music_tracks` |
185
|
|
|
WHERE `user_id` = ? AND `play_count` > 0 |
186
|
|
|
GROUP BY `album_id` |
187
|
|
|
ORDER BY `sum_count` DESC, `album_id`'; // the second criterion is just to make the order predictable on even counts |
188
|
|
|
|
189
|
|
|
$result = $this->execute($sql, [$userId], $limit, $offset); |
190
|
|
|
$playCountByAlbum = []; |
191
|
|
|
while ($row = $result->fetch()) { |
192
|
|
|
$playCountByAlbum[$row['album_id']] = (int)$row['sum_count']; |
193
|
|
|
} |
194
|
|
|
return $playCountByAlbum; |
195
|
|
|
} |
196
|
|
|
|
197
|
|
|
/** |
198
|
|
|
* returns the latest play time of each album of the user, omitting albums which have never been played |
199
|
|
|
* |
200
|
|
|
* @return array [int => string], keys are album IDs and values are date-times; ordered latest times first |
201
|
|
|
*/ |
202
|
|
|
public function getLatestAlbumPlayTimes(string $userId, ?int $limit=null, ?int $offset=null) : array { |
203
|
|
|
$sql = 'SELECT `album_id`, MAX(`last_played`) AS `latest_time` |
204
|
|
|
FROM `*PREFIX*music_tracks` |
205
|
|
|
WHERE `user_id` = ? AND `last_played` IS NOT NULL |
206
|
|
|
GROUP BY `album_id` |
207
|
|
|
ORDER BY `latest_time` DESC'; |
208
|
|
|
|
209
|
|
|
$result = $this->execute($sql, [$userId], $limit, $offset); |
210
|
|
|
$latestTimeByAlbum = []; |
211
|
|
|
while ($row = $result->fetch()) { |
212
|
|
|
$latestTimeByAlbum[$row['album_id']] = $row['latest_time']; |
213
|
|
|
} |
214
|
|
|
return $latestTimeByAlbum; |
215
|
|
|
} |
216
|
|
|
|
217
|
|
|
/** |
218
|
|
|
* returns the latest play time of each album of the user, including albums which have never been played |
219
|
|
|
* |
220
|
|
|
* @return array [int => ?string], keys are album IDs and values are date-times (or null for never played); |
221
|
|
|
* ordered furthest times first |
222
|
|
|
*/ |
223
|
|
|
public function getFurthestAlbumPlayTimes(string $userId, ?int $limit=null, ?int $offset=null) : array { |
224
|
|
|
$sql = 'SELECT `album_id`, MAX(`last_played`) AS `latest_time` |
225
|
|
|
FROM `*PREFIX*music_tracks` |
226
|
|
|
WHERE `user_id` = ? |
227
|
|
|
GROUP BY `album_id` |
228
|
|
|
ORDER BY `latest_time` ASC'; |
229
|
|
|
|
230
|
|
|
$result = $this->execute($sql, [$userId], $limit, $offset); |
231
|
|
|
$latestTimeByAlbum = []; |
232
|
|
|
while ($row = $result->fetch()) { |
233
|
|
|
$latestTimeByAlbum[$row['album_id']] = $row['latest_time']; |
234
|
|
|
} |
235
|
|
|
return $latestTimeByAlbum; |
236
|
|
|
} |
237
|
|
|
|
238
|
|
|
/** |
239
|
|
|
* @return Album[] |
240
|
|
|
*/ |
241
|
|
|
public function findAllByNameRecursive(string $name, string $userId, ?int $limit=null, ?int $offset=null) : array { |
242
|
|
|
$condition = '( LOWER(`artist`.`name`) LIKE LOWER(?) OR |
243
|
|
|
LOWER(`*PREFIX*music_albums`.`name`) LIKE LOWER(?) )'; |
244
|
|
|
$sql = $this->selectUserEntities($condition, 'ORDER BY LOWER(`*PREFIX*music_albums`.`name`)'); |
245
|
|
|
$name = BaseMapper::prepareSubstringSearchPattern($name); |
246
|
|
|
$params = [$userId, $name, $name]; |
247
|
|
|
return $this->findEntities($sql, $params, $limit, $offset); |
248
|
|
|
} |
249
|
|
|
|
250
|
|
|
/** |
251
|
|
|
* returns albums of a specified artist |
252
|
|
|
* The artist may be an album_artist or the artist of a track |
253
|
|
|
* |
254
|
|
|
* @param integer $artistId |
255
|
|
|
* @return Album[] |
256
|
|
|
*/ |
257
|
|
|
public function findAllByArtist(int $artistId, string $userId, ?int $limit=null, ?int $offset=null) : array { |
258
|
|
|
$sql = $this->selectEntities( |
259
|
|
|
'`*PREFIX*music_albums`.`id` IN ( |
260
|
|
|
SELECT DISTINCT `album`.`id` |
261
|
|
|
FROM `*PREFIX*music_albums` `album` |
262
|
|
|
WHERE `album`.`album_artist_id` = ? |
263
|
|
|
UNION |
264
|
|
|
SELECT DISTINCT `track`.`album_id` |
265
|
|
|
FROM `*PREFIX*music_tracks` `track` |
266
|
|
|
WHERE `track`.`artist_id` = ? |
267
|
|
|
) AND `*PREFIX*music_albums`.`user_id` = ?', |
268
|
|
|
'ORDER BY LOWER(`*PREFIX*music_albums`.`name`)'); |
269
|
|
|
$params = [$artistId, $artistId, $userId]; |
270
|
|
|
return $this->findEntities($sql, $params, $limit, $offset); |
271
|
|
|
} |
272
|
|
|
|
273
|
|
|
/** |
274
|
|
|
* returns albums of a specified artists |
275
|
|
|
* The artist must be album_artist on the album, artists of individual tracks are not considered |
276
|
|
|
* |
277
|
|
|
* @param int[] $artistIds |
278
|
|
|
* @return Album[] |
279
|
|
|
*/ |
280
|
|
|
public function findAllByAlbumArtist(array $artistIds, string $userId, ?int $limit=null, ?int $offset=null) : array { |
281
|
|
|
$sql = $this->selectUserEntities('`album_artist_id` IN ' . $this->questionMarks(\count($artistIds))); |
282
|
|
|
$params = \array_merge([$userId], $artistIds); |
283
|
|
|
return $this->findEntities($sql, $params, $limit, $offset); |
284
|
|
|
} |
285
|
|
|
|
286
|
|
|
/** |
287
|
|
|
* @return Album[] |
288
|
|
|
*/ |
289
|
|
|
public function findAllByGenre(int $genreId, string $userId, ?int $limit=null, ?int $offset=null) : array { |
290
|
|
|
$sql = $this->selectUserEntities('EXISTS '. |
291
|
|
|
'(SELECT 1 FROM `*PREFIX*music_tracks` `track` |
292
|
|
|
WHERE `*PREFIX*music_albums`.`id` = `track`.`album_id` |
293
|
|
|
AND `track`.`genre_id` = ?)'); |
294
|
|
|
|
295
|
|
|
$params = [$userId, $genreId]; |
296
|
|
|
return $this->findEntities($sql, $params, $limit, $offset); |
297
|
|
|
} |
298
|
|
|
|
299
|
|
|
/** |
300
|
|
|
* @return boolean True if one or more albums were influenced |
301
|
|
|
*/ |
302
|
|
|
public function updateFolderCover(int $coverFileId, int $folderId) : bool { |
303
|
|
|
$sql = 'SELECT DISTINCT `tracks`.`album_id` |
304
|
|
|
FROM `*PREFIX*music_tracks` `tracks` |
305
|
|
|
JOIN `*PREFIX*filecache` `files` ON `tracks`.`file_id` = `files`.`fileid` |
306
|
|
|
WHERE `files`.`parent` = ?'; |
307
|
|
|
$params = [$folderId]; |
308
|
|
|
$result = $this->execute($sql, $params); |
309
|
|
|
$albumIds = $result->fetchAll(\PDO::FETCH_COLUMN); |
310
|
|
|
|
311
|
|
|
$updated = false; |
312
|
|
|
if (\count($albumIds) > 0) { |
313
|
|
|
$sql = 'UPDATE `*PREFIX*music_albums` |
314
|
|
|
SET `cover_file_id` = ? |
315
|
|
|
WHERE `cover_file_id` IS NULL AND `id` IN '. $this->questionMarks(\count($albumIds)); |
316
|
|
|
$params = \array_merge([$coverFileId], $albumIds); |
317
|
|
|
$result = $this->execute($sql, $params); |
318
|
|
|
$updated = $result->rowCount() > 0; |
319
|
|
|
} |
320
|
|
|
|
321
|
|
|
return $updated; |
322
|
|
|
} |
323
|
|
|
|
324
|
|
|
/** |
325
|
|
|
* Set file ID to be used as cover for an album |
326
|
|
|
*/ |
327
|
|
|
public function setCover(?int $coverFileId, int $albumId) : void { |
328
|
|
|
$sql = 'UPDATE `*PREFIX*music_albums` |
329
|
|
|
SET `cover_file_id` = ? |
330
|
|
|
WHERE `id` = ?'; |
331
|
|
|
$params = [$coverFileId, $albumId]; |
332
|
|
|
$this->execute($sql, $params); |
333
|
|
|
} |
334
|
|
|
|
335
|
|
|
/** |
336
|
|
|
* @param integer[] $coverFileIds |
337
|
|
|
* @param string[]|null $userIds the users whose music library is targeted; all users are targeted if omitted |
338
|
|
|
* @return Album[] albums which got modified (with incomplete data, only id and user are valid), |
339
|
|
|
* empty array if none |
340
|
|
|
*/ |
341
|
|
|
public function removeCovers(array $coverFileIds, ?array $userIds=null) : array { |
342
|
|
|
// find albums using the given file as cover |
343
|
|
|
$sql = 'SELECT `id`, `user_id` FROM `*PREFIX*music_albums` WHERE `cover_file_id` IN ' . |
344
|
|
|
$this->questionMarks(\count($coverFileIds)); |
345
|
|
|
$params = $coverFileIds; |
346
|
|
|
if ($userIds !== null) { |
347
|
|
|
$sql .= ' AND `user_id` IN ' . $this->questionMarks(\count($userIds)); |
348
|
|
|
$params = \array_merge($params, $userIds); |
349
|
|
|
} |
350
|
|
|
$albums = $this->findEntities($sql, $params); |
351
|
|
|
|
352
|
|
|
// if any albums found, remove the cover from those |
353
|
|
|
$count = \count($albums); |
354
|
|
|
if ($count) { |
355
|
|
|
$sql = 'UPDATE `*PREFIX*music_albums` |
356
|
|
|
SET `cover_file_id` = NULL |
357
|
|
|
WHERE `id` IN ' . $this->questionMarks($count); |
358
|
|
|
$params = ArrayUtil::extractIds($albums); |
359
|
|
|
$this->execute($sql, $params); |
360
|
|
|
} |
361
|
|
|
|
362
|
|
|
return $albums; |
363
|
|
|
} |
364
|
|
|
|
365
|
|
|
/** |
366
|
|
|
* @param string|null $userId target user; omit to target all users |
367
|
|
|
* @return array of dictionaries with keys [albumId, userId, parentFolderId] |
368
|
|
|
*/ |
369
|
|
|
public function getAlbumsWithoutCover(?string $userId = null) : array { |
370
|
|
|
$sql = 'SELECT DISTINCT `albums`.`id`, `albums`.`user_id`, `files`.`parent` |
371
|
|
|
FROM `*PREFIX*music_albums` `albums` |
372
|
|
|
JOIN `*PREFIX*music_tracks` `tracks` ON `albums`.`id` = `tracks`.`album_id` |
373
|
|
|
JOIN `*PREFIX*filecache` `files` ON `tracks`.`file_id` = `files`.`fileid` |
374
|
|
|
WHERE `albums`.`cover_file_id` IS NULL'; |
375
|
|
|
$params = []; |
376
|
|
|
if ($userId !== null) { |
377
|
|
|
$sql .= ' AND `albums`.`user_id` = ?'; |
378
|
|
|
$params[] = $userId; |
379
|
|
|
} |
380
|
|
|
$result = $this->execute($sql, $params); |
381
|
|
|
$return = []; |
382
|
|
|
while ($row = $result->fetch()) { |
383
|
|
|
$return[] = [ |
384
|
|
|
'albumId' => (int)$row['id'], |
385
|
|
|
'userId' => $row['user_id'], |
386
|
|
|
'parentFolderId' => (int)$row['parent'] |
387
|
|
|
]; |
388
|
|
|
} |
389
|
|
|
return $return; |
390
|
|
|
} |
391
|
|
|
|
392
|
|
|
/** |
393
|
|
|
* @return boolean True if a cover image was found and added for the album |
394
|
|
|
*/ |
395
|
|
|
public function findAlbumCover(int $albumId, int $parentFolderId) : bool { |
396
|
|
|
$return = false; |
397
|
|
|
$imagesSql = 'SELECT `fileid`, `name` |
398
|
|
|
FROM `*PREFIX*filecache` |
399
|
|
|
JOIN `*PREFIX*mimetypes` ON `*PREFIX*mimetypes`.`id` = `*PREFIX*filecache`.`mimetype` |
400
|
|
|
WHERE `parent` = ? AND `*PREFIX*mimetypes`.`mimetype` LIKE \'image%\''; |
401
|
|
|
$params = [$parentFolderId]; |
402
|
|
|
$result = $this->execute($imagesSql, $params); |
403
|
|
|
$images = $result->fetchAll(); |
404
|
|
|
if (\count($images) > 0) { |
405
|
|
|
$getImageRank = function($imageName) { |
406
|
|
|
$coverNames = ['cover', 'albumart', 'album', 'front', 'folder']; |
407
|
|
|
foreach ($coverNames as $i => $coverName) { |
408
|
|
|
if (StringUtil::startsWith($imageName, $coverName, /*$ignoreCase=*/true)) { |
409
|
|
|
return $i; |
410
|
|
|
} |
411
|
|
|
} |
412
|
|
|
return \count($coverNames); |
413
|
|
|
}; |
414
|
|
|
|
415
|
|
|
\usort($images, fn($imageA, $imageB) => |
416
|
|
|
$getImageRank($imageA['name']) <=> $getImageRank($imageB['name']) |
417
|
|
|
); |
418
|
|
|
$imageId = (int)$images[0]['fileid']; |
419
|
|
|
$this->setCover($imageId, $albumId); |
420
|
|
|
$return = true; |
421
|
|
|
} |
422
|
|
|
return $return; |
423
|
|
|
} |
424
|
|
|
|
425
|
|
|
/** |
426
|
|
|
* Given an array of track IDs, find corresponding unique album IDs, including only |
427
|
|
|
* those album which have a cover art set. |
428
|
|
|
* @param int[] $trackIds |
429
|
|
|
* @return Album[] |
430
|
|
|
*/ |
431
|
|
|
public function findAlbumsWithCoversForTracks(array $trackIds, string $userId, int $limit) : array { |
432
|
|
|
$sql = 'SELECT DISTINCT `albums`.* |
433
|
|
|
FROM `*PREFIX*music_albums` `albums` |
434
|
|
|
JOIN `*PREFIX*music_tracks` `tracks` ON `albums`.`id` = `tracks`.`album_id` |
435
|
|
|
WHERE `albums`.`cover_file_id` IS NOT NULL |
436
|
|
|
AND `albums`.`user_id` = ? |
437
|
|
|
AND `tracks`.`id` IN ' . $this->questionMarks(\count($trackIds)); |
438
|
|
|
$params = \array_merge([$userId], $trackIds); |
439
|
|
|
|
440
|
|
|
return $this->findEntities($sql, $params, $limit); |
441
|
|
|
} |
442
|
|
|
|
443
|
|
|
/** |
444
|
|
|
* Returns the count of albums where the given Artist is featured in |
445
|
|
|
* @param integer $artistId |
446
|
|
|
* @return integer |
447
|
|
|
*/ |
448
|
|
|
public function countByArtist(int $artistId) : int { |
449
|
|
|
$sql = 'SELECT COUNT(*) AS count FROM ( |
450
|
|
|
SELECT DISTINCT `track`.`album_id` |
451
|
|
|
FROM `*PREFIX*music_tracks` `track` |
452
|
|
|
WHERE `track`.`artist_id` = ? |
453
|
|
|
UNION |
454
|
|
|
SELECT `album`.`id` |
455
|
|
|
FROM `*PREFIX*music_albums` `album` |
456
|
|
|
WHERE `album`.`album_artist_id` = ? |
457
|
|
|
) tmp'; |
458
|
|
|
$params = [$artistId, $artistId]; |
459
|
|
|
$result = $this->execute($sql, $params); |
460
|
|
|
$row = $result->fetch(); |
461
|
|
|
return (int)$row['count']; |
462
|
|
|
} |
463
|
|
|
|
464
|
|
|
/** |
465
|
|
|
* Returns the count of albums where the given artist is the album artist |
466
|
|
|
* @param integer $artistId |
467
|
|
|
* @return integer |
468
|
|
|
*/ |
469
|
|
|
public function countByAlbumArtist(int $artistId) : int { |
470
|
|
|
$sql = 'SELECT COUNT(*) AS count |
471
|
|
|
FROM `*PREFIX*music_albums` `album` |
472
|
|
|
WHERE `album`.`album_artist_id` = ?'; |
473
|
|
|
$params = [$artistId]; |
474
|
|
|
$result = $this->execute($sql, $params); |
475
|
|
|
$row = $result->fetch(); |
476
|
|
|
return (int)$row['count']; |
477
|
|
|
} |
478
|
|
|
|
479
|
|
|
/** |
480
|
|
|
* Overridden from the base implementation to provide support for table-specific rules |
481
|
|
|
* |
482
|
|
|
* {@inheritdoc} |
483
|
|
|
* @see BaseMapper::advFormatSqlCondition() |
484
|
|
|
*/ |
485
|
|
|
protected function advFormatSqlCondition(string $rule, string $sqlOp, string $conv) : string { |
486
|
|
|
// The extra subquery "mysqlhack" seen around some nested queries is needed in order for these to not be insanely slow on MySQL. |
487
|
|
|
// In case of 'recent_played', the MySQL 5.5.62 errored with "1235 This version of MySQL doesn't yet support 'LIMIT & IN/ALL/ANY/SOME subquery'" without the extra subquery. |
488
|
|
|
$condForRule = [ |
489
|
|
|
'album_artist' => "$conv(`artist`.`name`) $sqlOp $conv(?)", |
490
|
|
|
'song_artist' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` JOIN `*PREFIX*music_artists` `ar` ON `t`.`artist_id` = `ar`.`id` WHERE $conv(`ar`.`name`) $sqlOp $conv(?))", |
491
|
|
|
'song' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` WHERE $conv(`t`.`title`) $sqlOp $conv(?))", |
492
|
|
|
'original_year' => "`*PREFIX*music_albums`.`id` IN (SELECT * FROM (SELECT `album_id` FROM `*PREFIX*music_tracks` GROUP BY `album_id` HAVING MIN(`year`) $sqlOp ?) mysqlhack)", |
493
|
|
|
'songrating' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` WHERE `t`.`rating` $sqlOp ?)", |
494
|
|
|
'artistrating' => "`artist`.rating $sqlOp ?", |
495
|
|
|
'played_times' => "`*PREFIX*music_albums`.`id` IN (SELECT * FROM (SELECT `album_id` from `*PREFIX*music_tracks` GROUP BY `album_id` HAVING SUM(`play_count`) $sqlOp ?) mysqlhack)", |
496
|
|
|
'last_play' => "`*PREFIX*music_albums`.`id` IN (SELECT * FROM (SELECT `album_id` from `*PREFIX*music_tracks` GROUP BY `album_id` HAVING MAX(`last_played`) $sqlOp ?) mysqlhack)", |
497
|
|
|
'myplayed' => "`*PREFIX*music_albums`.`id` IN (SELECT * FROM (SELECT `album_id` from `*PREFIX*music_tracks` GROUP BY `album_id` HAVING MAX(`last_played`) $sqlOp) mysqlhack)", // operator "IS NULL" or "IS NOT NULL" |
498
|
|
|
'myplayedartist'=> "`album_artist_id` IN (SELECT * FROM (SELECT `artist_id` from `*PREFIX*music_tracks` GROUP BY `artist_id` HAVING MAX(`last_played`) $sqlOp) mysqlhack)", // operator "IS NULL" or "IS NOT NULL" |
499
|
|
|
'song_count' => "`*PREFIX*music_albums`.`id` IN (SELECT * FROM (SELECT `album_id` FROM `*PREFIX*music_tracks` GROUP BY `album_id` HAVING COUNT(`id`) $sqlOp ?) mysqlhack)", |
500
|
|
|
'disk_count' => "`*PREFIX*music_albums`.`id` IN (SELECT * FROM (SELECT `album_id` FROM `*PREFIX*music_tracks` GROUP BY `album_id` HAVING MAX(`disk`) $sqlOp ?) mysqlhack)", |
501
|
|
|
'time' => "`*PREFIX*music_albums`.`id` IN (SELECT * FROM (SELECT `album_id` FROM `*PREFIX*music_tracks` GROUP BY `album_id` HAVING SUM(`length`) $sqlOp ?) mysqlhack)", |
502
|
|
|
'album_genre' => "`*PREFIX*music_albums`.`id` IN (SELECT * FROM (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` JOIN `*PREFIX*music_genres` `g` ON `t`.`genre_id` = `g`.`id` GROUP BY `album_id` HAVING $conv(" . $this->sqlGroupConcat('`g`.`name`') . ") $sqlOp $conv(?)) mysqlhack)", |
503
|
|
|
'song_genre' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` JOIN `*PREFIX*music_genres` `g` ON `t`.`genre_id` = `g`.`id` WHERE $conv(`g`.`name`) $sqlOp $conv(?))", |
504
|
|
|
'no_genre' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` JOIN `*PREFIX*music_genres` `g` ON `t`.`genre_id` = `g`.`id` WHERE `g`.`name` " . (($sqlOp == 'IS NOT NULL') ? '=' : '!=') . ' "")', |
505
|
|
|
'playlist' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` WHERE $sqlOp EXISTS (SELECT 1 from `*PREFIX*music_playlists` `p` WHERE `p`.`id` = ? AND `p`.`track_ids` LIKE " . $this->sqlConcat("'%|'", "`t`.`id`", "'|%'") . '))', |
506
|
|
|
'playlist_name' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` WHERE EXISTS (SELECT 1 from `*PREFIX*music_playlists` `p` WHERE $conv(`p`.`name`) $sqlOp $conv(?) AND `p`.`track_ids` LIKE " . $this->sqlConcat("'%|'", "`t`.`id`", "'|%'") . '))', |
507
|
|
|
'file' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` JOIN `*PREFIX*filecache` `f` ON `t`.`file_id` = `f`.`fileid` WHERE $conv(`f`.`name`) $sqlOp $conv(?))", |
508
|
|
|
'recent_played' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM (SELECT `album_id`, MAX(`last_played`) FROM `*PREFIX*music_tracks` WHERE `user_id` = ? GROUP BY `album_id` ORDER BY MAX(`last_played`) DESC LIMIT $sqlOp) mysqlhack)", |
509
|
|
|
'mbid_song' => "`*PREFIX*music_albums`.`id` IN (SELECT `album_id` FROM `*PREFIX*music_tracks` `t` WHERE `t`.`mbid` $sqlOp ?)", |
510
|
|
|
'mbid_artist' => "`artist`.`mbid` $sqlOp ?", |
511
|
|
|
'has_image' => "`*PREFIX*music_albums`.`cover_file_id` $sqlOp" // operator "IS NULL" or "IS NOT NULL" |
512
|
|
|
]; |
513
|
|
|
|
514
|
|
|
// Add alias rules |
515
|
|
|
$condForRule['year'] = $condForRule['original_year']; // we only have one kind of year |
516
|
|
|
$condForRule['played'] = $condForRule['myplayed']; // we give no access to other people's data; not part of the API spec but Ample uses this |
517
|
|
|
$condForRule['artist'] = $condForRule['album_artist']; |
518
|
|
|
$condForRule['genre'] = $condForRule['album_genre']; |
519
|
|
|
$condForRule['album'] = parent::advFormatSqlCondition('title', $sqlOp, $conv); |
520
|
|
|
$condForRule['mbid_album'] = parent::advFormatSqlCondition('mbid', $sqlOp, $conv); |
521
|
|
|
|
522
|
|
|
return $condForRule[$rule] ?? parent::advFormatSqlCondition($rule, $sqlOp, $conv); |
523
|
|
|
} |
524
|
|
|
} |
525
|
|
|
|