Some checks failed
Deploy to Test Environment / deploy-to-test (push) Failing after 1m10s
557 lines
15 KiB
TypeScript
557 lines
15 KiB
TypeScript
// src/services/db/upc.db.ts
|
|
import type { Pool, PoolClient } from 'pg';
|
|
import { getPool } from './connection.db';
|
|
import { NotFoundError, handleDbError } from './errors.db';
|
|
import type { Logger } from 'pino';
|
|
import type {
|
|
UpcScanSource,
|
|
UpcExternalSource,
|
|
UpcScanHistoryRecord,
|
|
UpcExternalLookupRecord,
|
|
UpcProductMatch,
|
|
UpcScanHistoryQueryOptions,
|
|
} from '../../types/upc';
|
|
|
|
/**
|
|
* Database row type for products table with UPC-relevant fields.
|
|
*/
|
|
interface ProductRow {
|
|
product_id: number;
|
|
name: string;
|
|
brand_id: number | null;
|
|
category_id: number | null;
|
|
description: string | null;
|
|
size: string | null;
|
|
upc_code: string | null;
|
|
master_item_id: number | null;
|
|
created_at: string;
|
|
updated_at: string;
|
|
}
|
|
|
|
/**
|
|
* Extended product row with joined brand and category names.
|
|
*/
|
|
interface ProductWithDetailsRow extends ProductRow {
|
|
brand_name: string | null;
|
|
category_name: string | null;
|
|
image_url: string | null;
|
|
}
|
|
|
|
/**
|
|
* Repository for UPC scanning related database operations.
|
|
* Handles scan history tracking, external lookup caching, and product UPC matching.
|
|
*/
|
|
export class UpcRepository {
|
|
private db: Pick<Pool | PoolClient, 'query'>;
|
|
|
|
constructor(db: Pick<Pool | PoolClient, 'query'> = getPool()) {
|
|
this.db = db;
|
|
}
|
|
|
|
// ============================================================================
|
|
// PRODUCT UPC LOOKUP
|
|
// ============================================================================
|
|
|
|
/**
|
|
* Finds a product by its UPC code.
|
|
* Returns null if no product is found with the given UPC.
|
|
*/
|
|
async findProductByUpc(upcCode: string, logger: Logger): Promise<UpcProductMatch | null> {
|
|
try {
|
|
const query = `
|
|
SELECT
|
|
p.product_id,
|
|
p.name,
|
|
p.description,
|
|
p.size,
|
|
p.upc_code,
|
|
p.master_item_id,
|
|
b.name AS brand_name,
|
|
c.name AS category_name,
|
|
NULL AS image_url
|
|
FROM public.products p
|
|
LEFT JOIN public.brands b ON p.brand_id = b.brand_id
|
|
LEFT JOIN public.master_grocery_items mgi ON p.master_item_id = mgi.master_grocery_item_id
|
|
LEFT JOIN public.categories c ON mgi.category_id = c.category_id
|
|
WHERE p.upc_code = $1
|
|
`;
|
|
const res = await this.db.query<ProductWithDetailsRow>(query, [upcCode]);
|
|
|
|
if (res.rowCount === 0) {
|
|
return null;
|
|
}
|
|
|
|
const row = res.rows[0];
|
|
return {
|
|
product_id: row.product_id,
|
|
name: row.name,
|
|
brand: row.brand_name,
|
|
category: row.category_name,
|
|
description: row.description,
|
|
size: row.size,
|
|
upc_code: row.upc_code ?? upcCode,
|
|
image_url: row.image_url,
|
|
master_item_id: row.master_item_id,
|
|
};
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in findProductByUpc',
|
|
{ upcCode },
|
|
{
|
|
defaultMessage: 'Failed to look up product by UPC code.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Links a UPC code to an existing product.
|
|
* Updates the product's upc_code field.
|
|
*/
|
|
async linkUpcToProduct(productId: number, upcCode: string, logger: Logger): Promise<ProductRow> {
|
|
try {
|
|
const res = await this.db.query<ProductRow>(
|
|
`UPDATE public.products SET upc_code = $1, updated_at = NOW() WHERE product_id = $2 RETURNING *`,
|
|
[upcCode, productId],
|
|
);
|
|
|
|
if (res.rowCount === 0) {
|
|
throw new NotFoundError('Product not found.');
|
|
}
|
|
|
|
return res.rows[0];
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in linkUpcToProduct',
|
|
{ productId, upcCode },
|
|
{
|
|
uniqueMessage: 'This UPC code is already linked to another product.',
|
|
fkMessage: 'The specified product does not exist.',
|
|
defaultMessage: 'Failed to link UPC code to product.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
// ============================================================================
|
|
// SCAN HISTORY
|
|
// ============================================================================
|
|
|
|
/**
|
|
* Records a UPC scan in the history table.
|
|
* Creates an audit trail of all scans performed by users.
|
|
*/
|
|
async recordScan(
|
|
userId: string,
|
|
upcCode: string,
|
|
scanSource: UpcScanSource,
|
|
logger: Logger,
|
|
options: {
|
|
productId?: number | null;
|
|
scanConfidence?: number | null;
|
|
rawImagePath?: string | null;
|
|
lookupSuccessful?: boolean;
|
|
} = {},
|
|
): Promise<UpcScanHistoryRecord> {
|
|
const {
|
|
productId = null,
|
|
scanConfidence = null,
|
|
rawImagePath = null,
|
|
lookupSuccessful = false,
|
|
} = options;
|
|
|
|
try {
|
|
const res = await this.db.query<UpcScanHistoryRecord>(
|
|
`INSERT INTO public.upc_scan_history
|
|
(user_id, upc_code, product_id, scan_source, scan_confidence, raw_image_path, lookup_successful)
|
|
VALUES ($1, $2, $3, $4, $5, $6, $7)
|
|
RETURNING *`,
|
|
[userId, upcCode, productId, scanSource, scanConfidence, rawImagePath, lookupSuccessful],
|
|
);
|
|
|
|
return res.rows[0];
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in recordScan',
|
|
{ userId, upcCode, scanSource, productId },
|
|
{
|
|
fkMessage: 'The specified user or product does not exist.',
|
|
checkMessage: 'Invalid UPC code format or scan source.',
|
|
defaultMessage: 'Failed to record UPC scan.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Retrieves the scan history for a user with optional filtering.
|
|
*/
|
|
async getScanHistory(
|
|
options: UpcScanHistoryQueryOptions,
|
|
logger: Logger,
|
|
): Promise<{ scans: UpcScanHistoryRecord[]; total: number }> {
|
|
const {
|
|
user_id,
|
|
limit = 50,
|
|
offset = 0,
|
|
lookup_successful,
|
|
scan_source,
|
|
from_date,
|
|
to_date,
|
|
} = options;
|
|
|
|
try {
|
|
// Build dynamic WHERE clause
|
|
const conditions: string[] = ['user_id = $1'];
|
|
const params: (string | number | boolean)[] = [user_id];
|
|
let paramIndex = 2;
|
|
|
|
if (lookup_successful !== undefined) {
|
|
conditions.push(`lookup_successful = $${paramIndex++}`);
|
|
params.push(lookup_successful);
|
|
}
|
|
|
|
if (scan_source) {
|
|
conditions.push(`scan_source = $${paramIndex++}`);
|
|
params.push(scan_source);
|
|
}
|
|
|
|
if (from_date) {
|
|
conditions.push(`created_at >= $${paramIndex++}`);
|
|
params.push(from_date);
|
|
}
|
|
|
|
if (to_date) {
|
|
conditions.push(`created_at <= $${paramIndex++}`);
|
|
params.push(to_date);
|
|
}
|
|
|
|
const whereClause = conditions.join(' AND ');
|
|
|
|
// Get total count
|
|
const countRes = await this.db.query<{ count: string }>(
|
|
`SELECT COUNT(*) FROM public.upc_scan_history WHERE ${whereClause}`,
|
|
params,
|
|
);
|
|
const total = parseInt(countRes.rows[0].count, 10);
|
|
|
|
// Get paginated results
|
|
const dataParams = [...params, limit, offset];
|
|
const dataRes = await this.db.query<UpcScanHistoryRecord>(
|
|
`SELECT * FROM public.upc_scan_history
|
|
WHERE ${whereClause}
|
|
ORDER BY created_at DESC
|
|
LIMIT $${paramIndex++} OFFSET $${paramIndex}`,
|
|
dataParams,
|
|
);
|
|
|
|
return { scans: dataRes.rows, total };
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in getScanHistory',
|
|
{ options },
|
|
{
|
|
defaultMessage: 'Failed to retrieve scan history.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Gets a single scan record by ID.
|
|
*/
|
|
async getScanById(scanId: number, userId: string, logger: Logger): Promise<UpcScanHistoryRecord> {
|
|
try {
|
|
const res = await this.db.query<UpcScanHistoryRecord>(
|
|
`SELECT * FROM public.upc_scan_history WHERE scan_id = $1 AND user_id = $2`,
|
|
[scanId, userId],
|
|
);
|
|
|
|
if (res.rowCount === 0) {
|
|
throw new NotFoundError('Scan record not found.');
|
|
}
|
|
|
|
return res.rows[0];
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in getScanById',
|
|
{ scanId, userId },
|
|
{
|
|
defaultMessage: 'Failed to retrieve scan record.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
// ============================================================================
|
|
// EXTERNAL LOOKUP CACHE
|
|
// ============================================================================
|
|
|
|
/**
|
|
* Finds a cached external lookup result for a UPC code.
|
|
* Returns null if not cached or cache is expired.
|
|
*/
|
|
async findExternalLookup(
|
|
upcCode: string,
|
|
maxAgeHours: number,
|
|
logger: Logger,
|
|
): Promise<UpcExternalLookupRecord | null> {
|
|
try {
|
|
const res = await this.db.query<UpcExternalLookupRecord>(
|
|
`SELECT * FROM public.upc_external_lookups
|
|
WHERE upc_code = $1
|
|
AND created_at > NOW() - ($2 * interval '1 hour')`,
|
|
[upcCode, maxAgeHours],
|
|
);
|
|
|
|
if (res.rowCount === 0) {
|
|
return null;
|
|
}
|
|
|
|
return res.rows[0];
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in findExternalLookup',
|
|
{ upcCode, maxAgeHours },
|
|
{
|
|
defaultMessage: 'Failed to find cached external lookup.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Creates or updates a cached external lookup result.
|
|
* Uses UPSERT to handle both new and existing records.
|
|
*/
|
|
async upsertExternalLookup(
|
|
upcCode: string,
|
|
externalSource: UpcExternalSource,
|
|
lookupSuccessful: boolean,
|
|
logger: Logger,
|
|
data: {
|
|
productName?: string | null;
|
|
brandName?: string | null;
|
|
category?: string | null;
|
|
description?: string | null;
|
|
imageUrl?: string | null;
|
|
lookupData?: Record<string, unknown> | null;
|
|
} = {},
|
|
): Promise<UpcExternalLookupRecord> {
|
|
const {
|
|
productName = null,
|
|
brandName = null,
|
|
category = null,
|
|
description = null,
|
|
imageUrl = null,
|
|
lookupData = null,
|
|
} = data;
|
|
|
|
try {
|
|
const res = await this.db.query<UpcExternalLookupRecord>(
|
|
`INSERT INTO public.upc_external_lookups
|
|
(upc_code, product_name, brand_name, category, description, image_url, external_source, lookup_data, lookup_successful)
|
|
VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9)
|
|
ON CONFLICT (upc_code) DO UPDATE SET
|
|
product_name = EXCLUDED.product_name,
|
|
brand_name = EXCLUDED.brand_name,
|
|
category = EXCLUDED.category,
|
|
description = EXCLUDED.description,
|
|
image_url = EXCLUDED.image_url,
|
|
external_source = EXCLUDED.external_source,
|
|
lookup_data = EXCLUDED.lookup_data,
|
|
lookup_successful = EXCLUDED.lookup_successful,
|
|
updated_at = NOW()
|
|
RETURNING *`,
|
|
[
|
|
upcCode,
|
|
productName,
|
|
brandName,
|
|
category,
|
|
description,
|
|
imageUrl,
|
|
externalSource,
|
|
lookupData ? JSON.stringify(lookupData) : null,
|
|
lookupSuccessful,
|
|
],
|
|
);
|
|
|
|
return res.rows[0];
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in upsertExternalLookup',
|
|
{ upcCode, externalSource, lookupSuccessful },
|
|
{
|
|
checkMessage: 'Invalid UPC code format or external source.',
|
|
defaultMessage: 'Failed to cache external lookup result.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Gets an external lookup record by UPC code (without cache expiry check).
|
|
*/
|
|
async getExternalLookupByUpc(
|
|
upcCode: string,
|
|
logger: Logger,
|
|
): Promise<UpcExternalLookupRecord | null> {
|
|
try {
|
|
const res = await this.db.query<UpcExternalLookupRecord>(
|
|
`SELECT * FROM public.upc_external_lookups WHERE upc_code = $1`,
|
|
[upcCode],
|
|
);
|
|
|
|
if (res.rowCount === 0) {
|
|
return null;
|
|
}
|
|
|
|
return res.rows[0];
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in getExternalLookupByUpc',
|
|
{ upcCode },
|
|
{
|
|
defaultMessage: 'Failed to get external lookup record.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Deletes old external lookup cache entries.
|
|
* Used for periodic cleanup.
|
|
*/
|
|
async deleteOldExternalLookups(daysOld: number, logger: Logger): Promise<number> {
|
|
try {
|
|
const res = await this.db.query(
|
|
`DELETE FROM public.upc_external_lookups WHERE updated_at < NOW() - ($1 * interval '1 day')`,
|
|
[daysOld],
|
|
);
|
|
return res.rowCount ?? 0;
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in deleteOldExternalLookups',
|
|
{ daysOld },
|
|
{
|
|
defaultMessage: 'Failed to delete old external lookups.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
// ============================================================================
|
|
// STATISTICS
|
|
// ============================================================================
|
|
|
|
/**
|
|
* Gets scan statistics for a user.
|
|
*/
|
|
async getUserScanStats(
|
|
userId: string,
|
|
logger: Logger,
|
|
): Promise<{
|
|
total_scans: number;
|
|
successful_lookups: number;
|
|
unique_products: number;
|
|
scans_today: number;
|
|
scans_this_week: number;
|
|
}> {
|
|
try {
|
|
const res = await this.db.query<{
|
|
total_scans: string;
|
|
successful_lookups: string;
|
|
unique_products: string;
|
|
scans_today: string;
|
|
scans_this_week: string;
|
|
}>(
|
|
`SELECT
|
|
COUNT(*) AS total_scans,
|
|
COUNT(*) FILTER (WHERE lookup_successful = true) AS successful_lookups,
|
|
COUNT(DISTINCT product_id) FILTER (WHERE product_id IS NOT NULL) AS unique_products,
|
|
COUNT(*) FILTER (WHERE created_at >= CURRENT_DATE) AS scans_today,
|
|
COUNT(*) FILTER (WHERE created_at >= CURRENT_DATE - interval '7 days') AS scans_this_week
|
|
FROM public.upc_scan_history
|
|
WHERE user_id = $1`,
|
|
[userId],
|
|
);
|
|
|
|
const row = res.rows[0];
|
|
return {
|
|
total_scans: parseInt(row.total_scans, 10),
|
|
successful_lookups: parseInt(row.successful_lookups, 10),
|
|
unique_products: parseInt(row.unique_products, 10),
|
|
scans_today: parseInt(row.scans_today, 10),
|
|
scans_this_week: parseInt(row.scans_this_week, 10),
|
|
};
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in getUserScanStats',
|
|
{ userId },
|
|
{
|
|
defaultMessage: 'Failed to get scan statistics.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Updates a scan record with the detected UPC code from image processing.
|
|
* Used by the barcode detection worker after processing an uploaded image.
|
|
*/
|
|
async updateScanWithDetectedCode(
|
|
scanId: number,
|
|
upcCode: string,
|
|
confidence: number | null,
|
|
logger: Logger,
|
|
): Promise<void> {
|
|
try {
|
|
const query = `
|
|
UPDATE public.upc_scan_history
|
|
SET
|
|
upc_code = $2,
|
|
scan_confidence = $3,
|
|
updated_at = NOW()
|
|
WHERE scan_id = $1
|
|
`;
|
|
const res = await this.db.query(query, [scanId, upcCode, confidence]);
|
|
|
|
if (res.rowCount === 0) {
|
|
throw new NotFoundError('Scan record not found.');
|
|
}
|
|
|
|
logger.info({ scanId, upcCode, confidence }, 'Updated scan with detected code');
|
|
} catch (error) {
|
|
handleDbError(
|
|
error,
|
|
logger,
|
|
'Database error in updateScanWithDetectedCode',
|
|
{ scanId, upcCode },
|
|
{
|
|
defaultMessage: 'Failed to update scan with detected code.',
|
|
},
|
|
);
|
|
}
|
|
}
|
|
}
|