Some checks failed
Deploy to Test Environment / deploy-to-test (push) Failing after 41s
79 lines
3.0 KiB
TypeScript
79 lines
3.0 KiB
TypeScript
// src/services/db/deals.db.ts
|
|
import { getPool } from './connection.db';
|
|
import { WatchedItemDeal } from '../../types';
|
|
import type { Pool, PoolClient } from 'pg';
|
|
import type { Logger } from 'pino';
|
|
import { logger as globalLogger } from '../logger.server';
|
|
|
|
export class DealsRepository {
|
|
// The repository only needs an object with a `query` method, matching the Pool/PoolClient interface.
|
|
// Using `Pick` makes this dependency explicit and simplifies testing by reducing the mock surface.
|
|
private db: Pick<Pool | PoolClient, 'query'>;
|
|
|
|
constructor(db: Pick<Pool | PoolClient, 'query'> = getPool()) {
|
|
this.db = db;
|
|
}
|
|
|
|
/**
|
|
* Finds the best current sale price for each of a user's watched items.
|
|
* It considers only currently active flyers and handles ties by preferring the deal
|
|
* that is valid for the longest time.
|
|
*
|
|
* @param userId - The ID of the user whose watched items are being checked.
|
|
* @param logger - The logger instance for context-specific logging.
|
|
* @returns A promise that resolves to an array of WatchedItemDeal objects.
|
|
*/
|
|
async findBestPricesForWatchedItems(
|
|
userId: string,
|
|
logger: Logger = globalLogger,
|
|
): Promise<WatchedItemDeal[]> {
|
|
logger.debug({ userId }, 'Finding best prices for watched items.');
|
|
const query = `
|
|
WITH UserWatchedItems AS (
|
|
-- Select all items the user is watching
|
|
SELECT master_item_id FROM watched_items WHERE user_id = $1
|
|
),
|
|
RankedPrices AS (
|
|
-- Find all current sale prices for those items and rank them
|
|
SELECT
|
|
fi.master_item_id,
|
|
mgi.name AS item_name,
|
|
fi.price_in_cents,
|
|
s.name AS store_name,
|
|
f.flyer_id,
|
|
f.valid_to,
|
|
-- Rank prices for each item, lowest first. In case of a tie, the deal that ends later is preferred.
|
|
ROW_NUMBER() OVER(PARTITION BY fi.master_item_id ORDER BY fi.price_in_cents ASC, f.valid_to DESC) as rn
|
|
FROM flyer_items fi
|
|
JOIN flyers f ON fi.flyer_id = f.flyer_id
|
|
JOIN stores s ON f.store_id = s.store_id
|
|
JOIN master_grocery_items mgi ON fi.master_item_id = mgi.master_grocery_item_id
|
|
WHERE
|
|
fi.master_item_id IN (SELECT master_item_id FROM UserWatchedItems)
|
|
AND f.valid_to >= CURRENT_DATE -- Only consider active flyers
|
|
AND fi.price_in_cents IS NOT NULL
|
|
)
|
|
-- Select only the #1 ranked (lowest) price for each item
|
|
SELECT
|
|
master_item_id,
|
|
item_name,
|
|
price_in_cents AS best_price_in_cents,
|
|
store_name,
|
|
flyer_id,
|
|
valid_to
|
|
FROM RankedPrices
|
|
WHERE rn = 1
|
|
ORDER BY item_name;
|
|
`;
|
|
try {
|
|
const { rows } = await this.db.query<WatchedItemDeal>(query, [userId]);
|
|
return rows;
|
|
} catch (error) {
|
|
logger.error({ err: error }, 'Database error in findBestPricesForWatchedItems');
|
|
throw error; // Re-throw the original error to be handled by the global error handler
|
|
}
|
|
}
|
|
}
|
|
|
|
export const dealsRepo = new DealsRepository();
|