aboutsummaryrefslogtreecommitdiffstatshomepage
path: root/app/Models/TagDAO.php
blob: 65e322d5aace0917c7a89f231d6cbe37119af7a7 (plain) (blame)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
<?php
declare(strict_types=1);

class FreshRSS_TagDAO extends Minz_ModelPdo {

	public function sqlIgnore(): string {
		return 'IGNORE';
	}

	/**
	 * @param array{'id'?:int,'name':string,'attributes'?:array<string,mixed>} $valuesTmp
	 */
	public function addTag(array $valuesTmp): int|false {
		// TRIM() gives a text type hint to PostgreSQL
		// No category of the same name
		$sql = <<<'SQL'
INSERT INTO `_tag`(name, attributes)
SELECT * FROM (SELECT TRIM(?) as name, TRIM(?) as attributes) t2
WHERE NOT EXISTS (SELECT 1 FROM `_category` WHERE name = TRIM(?))
SQL;
		$stm = $this->pdo->prepare($sql);

		$valuesTmp['name'] = mb_strcut(trim($valuesTmp['name']), 0, FreshRSS_DatabaseDAO::LENGTH_INDEX_UNICODE, 'UTF-8');
		if (!isset($valuesTmp['attributes'])) {
			$valuesTmp['attributes'] = [];
		}
		$values = [
			$valuesTmp['name'],
			is_string($valuesTmp['attributes']) ? $valuesTmp['attributes'] : json_encode($valuesTmp['attributes'], JSON_UNESCAPED_SLASHES | JSON_UNESCAPED_UNICODE),
			$valuesTmp['name'],
		];

		if ($stm !== false && $stm->execute($values) && $stm->rowCount() > 0) {
			$tagId = $this->pdo->lastInsertId('`_tag_id_seq`');
			return $tagId === false ? false : (int)$tagId;
		} else {
			$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
			Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
			return false;
		}
	}

	public function addTagObject(FreshRSS_Tag $tag): int|false {
		$tag0 = $this->searchByName($tag->name());
		if ($tag0 === null) {
			$values = [
				'name' => $tag->name(),
				'attributes' => $tag->attributes(),
			];
			return $this->addTag($values);
		}
		return $tag->id();
	}

	public function updateTagName(int $id, string $name): int|false {
		// No category of the same name
		$sql = <<<'SQL'
UPDATE `_tag` SET name = :name1 WHERE id = :id
AND NOT EXISTS (SELECT 1 FROM `_category` WHERE name = :name2)
SQL;

		$name = mb_strcut(trim($name), 0, FreshRSS_DatabaseDAO::LENGTH_INDEX_UNICODE, 'UTF-8');
		$stm = $this->pdo->prepare($sql);
		if ($stm !== false &&
			$stm->bindValue(':id', $id, PDO::PARAM_INT) &&
			$stm->bindValue(':name1', $name, PDO::PARAM_STR) &&
			$stm->bindValue(':name2', $name, PDO::PARAM_STR) &&
			$stm->execute()) {
			return $stm->rowCount();
		} else {
			$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
			Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
			return false;
		}
	}

	/**
	 * @param array<string,mixed> $attributes
	 */
	public function updateTagAttributes(int $id, array $attributes): int|false {
		$sql = 'UPDATE `_tag` SET attributes=:attributes WHERE id=:id';
		$stm = $this->pdo->prepare($sql);
		if ($stm !== false &&
			$stm->bindValue(':id', $id, PDO::PARAM_INT) &&
			$stm->bindValue(':attributes', json_encode($attributes, JSON_UNESCAPED_SLASHES | JSON_UNESCAPED_UNICODE), PDO::PARAM_STR) &&
			$stm->execute()) {
			return $stm->rowCount();
		}
		$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
		Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
		return false;
	}

	/**
	 * @param non-empty-string $key
	 */
	public function updateTagAttribute(FreshRSS_Tag $tag, string $key, mixed $value): int|false {
		$tag->_attribute($key, $value);
		return $this->updateTagAttributes($tag->id(), $tag->attributes());
	}

	public function deleteTag(int $id): int|false {
		if ($id <= 0) {
			return false;
		}
		$sql = 'DELETE FROM `_tag` WHERE id=?';
		$stm = $this->pdo->prepare($sql);

		$values = [$id];

		if ($stm !== false && $stm->execute($values)) {
			return $stm->rowCount();
		} else {
			$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
			Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
			return false;
		}
	}

	/** @return Traversable<array{id:int,name:string,attributes?:array<string,mixed>}> */
	public function selectAll(): Traversable {
		$sql = 'SELECT id, name, attributes FROM `_tag`';
		$stm = $this->pdo->query($sql);
		if ($stm === false) {
			Minz_Log::error('SQL error ' . __METHOD__ . json_encode($this->pdo->errorInfo()));
			return;
		}
		while (is_array($row = $stm->fetch(PDO::FETCH_ASSOC))) {
			/** @var array{id:int,name:string,attributes?:array<string,mixed>} $row */
			yield $row;
		}
	}

	/** @return Traversable<array{id_tag:int,id_entry:int|numeric-string}> */
	public function selectEntryTag(): Traversable {
		$sql = 'SELECT id_tag, id_entry FROM `_entrytag`';
		$stm = $this->pdo->query($sql);
		if ($stm === false) {
			Minz_Log::error('SQL error ' . __METHOD__ . json_encode($this->pdo->errorInfo()));
			return;
		}
		while (is_array($row = $stm->fetch(PDO::FETCH_ASSOC))) {
			/** @var array{id_tag:int,id_entry:int|numeric-string}> $row */
			yield $row;	// @phpstan-ignore generator.valueType
		}
	}

	public function updateEntryTag(int $oldTagId, int $newTagId): int|false {
		$sql = <<<'SQL'
DELETE FROM `_entrytag` WHERE EXISTS (
	SELECT 1 FROM `_entrytag` AS e
	WHERE e.id_entry = `_entrytag`.id_entry AND e.id_tag = ? AND `_entrytag`.id_tag = ?)
SQL;
		$stm = $this->pdo->prepare($sql);

		if ($stm === false || !$stm->execute([$newTagId, $oldTagId])) {
			$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
			Minz_Log::error('SQL error ' . __METHOD__ . ' A ' . json_encode($info));
			return false;
		}

		$sql = 'UPDATE `_entrytag` SET id_tag = ? WHERE id_tag = ?';
		$stm = $this->pdo->prepare($sql);

		if ($stm !== false && $stm->execute([$newTagId, $oldTagId])) {
			return $stm->rowCount();
		}
		$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
		Minz_Log::error('SQL error ' . __METHOD__ . ' B ' . json_encode($info));
		return false;
	}

	public function searchById(int $id): ?FreshRSS_Tag {
		$res = $this->fetchAssoc('SELECT * FROM `_tag` WHERE id=:id', [':id' => $id]);
		/** @var list<array{id:int,name:string,attributes?:string}>|null $res */
		return $res === null ? null : (current(self::daoToTags($res)) ?: null);
	}

	public function searchByName(string $name): ?FreshRSS_Tag {
		$res = $this->fetchAssoc('SELECT * FROM `_tag` WHERE name=:name', [':name' => $name]);
		/** @var list<array{id:int,name:string,attributes?:string}>|null $res */
		return $res === null ? null : (current(self::daoToTags($res)) ?: null);
	}

	/** @return array<int,FreshRSS_Tag> where the key is the label ID */
	public function listTags(bool $precounts = false): array {
		if ($precounts) {
			$sql = <<<'SQL'
SELECT t.id, t.name, count(e.id) AS unreads
FROM `_tag` t
LEFT OUTER JOIN `_entrytag` et ON et.id_tag = t.id
LEFT OUTER JOIN `_entry` e ON et.id_entry = e.id AND e.is_read = 0
GROUP BY t.id
ORDER BY t.name
SQL;
		} else {
			$sql = 'SELECT * FROM `_tag` ORDER BY name';
		}

		$stm = $this->pdo->query($sql);
		if ($stm !== false && ($res = $stm->fetchAll(PDO::FETCH_ASSOC)) !== false) {
			return self::daoToTags($res);
		} else {
			$info = $this->pdo->errorInfo();
			Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
			return [];
		}
	}

	/** @return array<string,string> */
	public function listTagsNewestItemUsec(?int $id_tag = null): array {
		$sql = <<<'SQL'
SELECT t.id AS id_tag, MAX(e.id) AS newest_item_us
FROM `_tag` t
LEFT OUTER JOIN `_entrytag` et ON et.id_tag = t.id
LEFT OUTER JOIN `_entry` e ON et.id_entry = e.id
SQL;
		if ($id_tag === null) {
			$sql .= ' GROUP BY t.id';
		} else {
			$sql .= ' WHERE t.id=' . $id_tag;
		}
		$res = $this->fetchAssoc($sql);
		if ($res == null) {
			return [];
		}
		$newestItemUsec = [];
		foreach ($res as $line) {
			$newestItemUsec['t_' . $line['id_tag']] = (string)($line['newest_item_us']);
		}
		return $newestItemUsec;
	}

	public function count(): int {
		$sql = 'SELECT COUNT(*) AS count FROM `_tag`';
		$stm = $this->pdo->query($sql);
		if ($stm !== false) {
			$res = $stm->fetchAll(PDO::FETCH_ASSOC);
			return (int)$res[0]['count'];
		}
		$info = $this->pdo->errorInfo();
		Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
		return -1;
	}

	public function countEntries(int $id): int {
		$sql = 'SELECT COUNT(*) AS count FROM `_entrytag` WHERE id_tag=:id_tag';
		$res = $this->fetchAssoc($sql, [':id_tag' => $id]);
		if ($res == null || !isset($res[0]['count'])) {
			return -1;
		}
		return (int)$res[0]['count'];
	}

	public function countNotRead(?int $id = null): int {
		$sql = <<<'SQL'
SELECT COUNT(*) AS count FROM `_entrytag` et
INNER JOIN `_entry` e ON et.id_entry=e.id
WHERE e.is_read=0
SQL;
		$values = [];
		if (null !== $id) {
			$sql .= ' AND et.id_tag=:id_tag';
			$values[':id_tag'] = $id;
		}

		$res = $this->fetchAssoc($sql, $values);
		if ($res == null || !isset($res[0]['count'])) {
			return -1;
		}
		return (int)$res[0]['count'];
	}

	public function tagEntry(int $id_tag, string $id_entry, bool $checked = true): bool {
		if ($checked) {
			$sql = 'INSERT ' . $this->sqlIgnore() . ' INTO `_entrytag`(id_tag, id_entry) VALUES(?, ?)';
		} else {
			$sql = 'DELETE FROM `_entrytag` WHERE id_tag=? AND id_entry=?';
		}
		$stm = $this->pdo->prepare($sql);
		$values = [$id_tag, $id_entry];

		if ($stm !== false && $stm->execute($values)) {
			return true;
		}
		$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
		Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
		return false;
	}

	/**
	 * @param iterable<array{id_tag:int,id_entry:numeric-string|int}> $addLabels Labels to insert as batch
	 * @return int|false Number of new entries or false in case of error
	 */
	public function tagEntries(iterable $addLabels): int|false {
		$hasValues = false;
		$sql = 'INSERT ' . $this->sqlIgnore() . ' INTO `_entrytag`(id_tag, id_entry) VALUES ';
		foreach ($addLabels as $addLabel) {
			$id_tag = (int)($addLabel['id_tag'] ?? 0);
			$id_entry = $addLabel['id_entry'] ?? '';
			if ($id_tag > 0 && (is_int($id_entry) || ctype_digit($id_entry))) {
				$sql .= "({$id_tag},{$id_entry}),";
				$hasValues = true;
			}
		}
		$sql = rtrim($sql, ',');
		if (!$hasValues) {
			return false;
		}

		$affected = $this->pdo->exec($sql);
		if ($affected !== false) {
			return $affected;
		}
		$info = $this->pdo->errorInfo();
		Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
		return false;
	}

	/**
	 * @return list<array{id:int,name:string,checked:bool}>
	 */
	public function getTagsForEntry(string $id_entry): array {
		$sql = <<<'SQL'
SELECT t.id, t.name, et.id_entry IS NOT NULL as checked
FROM `_tag` t
LEFT OUTER JOIN `_entrytag` et ON et.id_tag = t.id AND et.id_entry=?
ORDER BY t.name
SQL;

		$stm = $this->pdo->prepare($sql);
		$values = [$id_entry];

		if ($stm !== false && $stm->execute($values) && ($lines = $stm->fetchAll(PDO::FETCH_ASSOC)) !== false) {
			$result = [];
			foreach ($lines as $line) {
				$result[] = [
					'id' => (int)($line['id']),
					'name' => $line['name'],
					'checked' => !empty($line['checked']),
				];
			}
			return $result;
		}
		$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
		Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
		return [];
	}

	/**
	 * @param list<FreshRSS_Entry|numeric-string> $entries
	 * @return list<array{id_entry:int|numeric-string,id_tag:int,name:string}>|null
	 */
	public function getTagsForEntries(array $entries): array|null {
		$sql = <<<'SQL'
SELECT et.id_entry, et.id_tag, t.name
FROM `_tag` t
INNER JOIN `_entrytag` et ON et.id_tag = t.id
SQL;

		$values = [];
		if (count($entries) > 0) {
			if (count($entries) > FreshRSS_DatabaseDAO::MAX_VARIABLE_NUMBER) {
				// Split a query with too many variables parameters
				$idsChunks = array_chunk($entries, FreshRSS_DatabaseDAO::MAX_VARIABLE_NUMBER);
				foreach ($idsChunks as $idsChunk) {
					$valuesChunk = $this->getTagsForEntries($idsChunk);
					if (!is_array($valuesChunk)) {
						return null;
					}
					$values = array_merge($values, $valuesChunk);
				}
				return $values;
			}
			$sql .= ' AND et.id_entry IN (' . str_repeat('?,', count($entries) - 1) . '?)';
			foreach ($entries as $entry) {
				$values[] = is_object($entry) ? $entry->id() : $entry;
			}
		}
		$stm = $this->pdo->prepare($sql);

		if ($stm !== false && $stm->execute($values)) {
			$result = $stm->fetchAll(PDO::FETCH_ASSOC);
			/** @var list<array{id_entry:int|numeric-string,id_tag:int,name:string}> $result; */
			return $result;
		}
		$info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo();
		Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info));
		return null;
	}

	/**
	 * Produces an array: for each entry ID (prefixed by `e_`), associate a list of labels.
	 * Used by API and by JSON export, to speed up queries (would be very expensive to perform a label look-up on each entry individually).
	 * @param list<FreshRSS_Entry|numeric-string> $entries the list of entries for which to retrieve the labels.
	 * @return array<string,array<string>> An array of the shape `[e_id_entry => ["label 1", "label 2"]]`
	 */
	public function getEntryIdsTagNames(array $entries): array {
		$result = [];
		foreach ($this->getTagsForEntries($entries) ?? [] as $line) {
			$entryId = 'e_' . $line['id_entry'];
			$tagName = $line['name'];
			if (empty($result[$entryId])) {
				$result[$entryId] = [];
			}
			$result[$entryId][] = $tagName;
		}
		return $result;
	}

	/**
	 * @param iterable<array{id:int,name:string,attributes?:string,unreads?:int}> $listDAO
	 * @return array<int,FreshRSS_Tag> where the key is the label ID
	 */
	private static function daoToTags(iterable $listDAO): array {
		$list = [];
		foreach ($listDAO as $dao) {
			if (empty($dao['id']) || empty($dao['name'])) {
				continue;
			}
			$tag = new FreshRSS_Tag($dao['name']);
			$tag->_id($dao['id']);
			if (!empty($dao['attributes'])) {
				$tag->_attributes($dao['attributes']);
			}
			if (isset($dao['unreads'])) {
				$tag->_nbUnread($dao['unreads']);
			}
			$list[$tag->id()] = $tag;
		}
		return $list;
	}
}