From 715b3f1866fcd705e694f4707aca6e1fdb094a64 Mon Sep 17 00:00:00 2001 From: Justin Gasper Date: Wed, 11 Feb 2026 09:53:34 +1100 Subject: [PATCH 1/2] Member tax 2025 reports --- README.md | 32 ++ package.json | 2 + scripts/export-member-tax-aggregated.js | 249 +++++++++++++ scripts/export-member-tax.js | 449 ++++++++++++++++++++++++ 4 files changed, 732 insertions(+) create mode 100644 scripts/export-member-tax-aggregated.js create mode 100644 scripts/export-member-tax.js diff --git a/README.md b/README.md index ddc2f8b..003fba8 100644 --- a/README.md +++ b/README.md @@ -54,6 +54,9 @@ Create a `.env` file in the root of the project. You can copy the example struct # This is used by Prisma to connect to your local PostgreSQL instance. DATABASE_URL="postgresql://user:password@localhost:5432/lookups?schema=public" +# Old tc-payments database URL (used by member-tax CSV export script) +OLD_PAYMENTS_DATABASE_URL="postgresql://user:password@localhost:5432/tc_payments?schema=public" + # --------------------------------------------------- # JWT Authentication Secrets # These are used by tc-core-library-js for validating JWTs. @@ -77,6 +80,35 @@ pnpm run dev The application will be available at http://localhost:3000. +## Member Tax CSV Export + +`member-tax` is generated as an offline CSV export (not an API endpoint). +The export enriches tax-form name/withholding values and payment-method names from the old payments database. + +```bash +pnpm run export:member-tax -- --output ./member-tax.csv +``` + +Optional date window: + +```bash +pnpm run export:member-tax -- --start-date 2025-01-01 --end-date 2026-01-01 --output ./member-tax-2025.csv +``` + +## Member Tax Aggregated CSV Export + +Aggregated member-payment export (main database only): + +```bash +pnpm run export:member-tax-aggregated -- --output ./member-tax-aggregated.csv +``` + +Optional date window: + +```bash +pnpm run export:member-tax-aggregated -- --start-date 2025-01-01 --end-date 2026-01-01 --output ./member-tax-aggregated-2025.csv +``` + ## Public Statistics Endpoints The following read-only endpoints are available without authentication to support the Community Statistics page. diff --git a/package.json b/package.json index 3e1ff27..f3ee922 100644 --- a/package.json +++ b/package.json @@ -7,6 +7,8 @@ "start": "node dist/main.js", "start:dev": "nest start --watch", "start:prod": "node dist/main.js", + "export:member-tax": "node scripts/export-member-tax.js", + "export:member-tax-aggregated": "node scripts/export-member-tax-aggregated.js", "prisma:generate": "prisma generate", "prisma:migrate": "prisma migrate dev", "lint": "eslint \"src/**/*.ts\" --fix", diff --git a/scripts/export-member-tax-aggregated.js b/scripts/export-member-tax-aggregated.js new file mode 100644 index 0000000..6752846 --- /dev/null +++ b/scripts/export-member-tax-aggregated.js @@ -0,0 +1,249 @@ +#!/usr/bin/env node + +const fs = require("fs"); +const path = require("path"); +const { Pool } = require("pg"); + +const CSV_COLUMNS = [ + "userID", + "handle", + "email", + "firstName", + "lastName", + "homeCountryCode", + "net_amount", + "gross_amount", + "trolley_id", + "tax_form_status", + "num_payments", + "last_payment_release_date", +]; + +const AGGREGATED_QUERY = ` +WITH latest_payment AS MATERIALIZED ( + SELECT + p.winnings_id, + MAX(p.version) AS max_version + FROM finance.payment AS p + GROUP BY p.winnings_id +), +payment_rows AS MATERIALIZED ( + SELECT + w.winner_id AS user_id, + p.payment_id::text AS payment_id, + COALESCE(p.net_amount, 0) AS net_amount, + COALESCE(p.gross_amount, 0) AS gross_amount, + p.release_date + FROM finance.payment AS p + JOIN latest_payment AS lp + ON lp.winnings_id = p.winnings_id + AND lp.max_version = p.version + JOIN finance.winnings AS w + ON w.winning_id = p.winnings_id + WHERE w.type = 'PAYMENT' + AND p.date_paid >= $1::date + AND p.date_paid < $2::date +), +payment_agg AS MATERIALIZED ( + SELECT + pr.user_id, + COUNT(DISTINCT pr.payment_id) AS num_payments, + SUM(pr.net_amount) AS net_amount, + SUM(pr.gross_amount) AS gross_amount, + MAX(pr.release_date) AS last_payment_release_date + FROM payment_rows AS pr + GROUP BY pr.user_id +), +latest_tax_form AS MATERIALIZED ( + SELECT DISTINCT ON (utf.user_id) + utf.user_id, + utf.tax_form_status + FROM finance.user_tax_form_associations AS utf + JOIN payment_agg AS pa + ON pa.user_id = utf.user_id + ORDER BY + utf.user_id, + CASE utf.tax_form_status + WHEN 'ACTIVE' THEN 0 + ELSE 1 + END, + utf.date_filed DESC NULLS LAST, + utf.id DESC +) +SELECT + mem."userId"::text AS "userID", + mem.handle AS "handle", + mem.email AS "email", + mem."firstName" AS "firstName", + mem."lastName" AS "lastName", + mem."homeCountryCode" AS "homeCountryCode", + pa.net_amount AS "net_amount", + pa.gross_amount AS "gross_amount", + tr.trolley_id AS "trolley_id", + ltf.tax_form_status AS "tax_form_status", + pa.num_payments AS "num_payments", + pa.last_payment_release_date AS "last_payment_release_date" +FROM payment_agg AS pa +JOIN members.member AS mem + ON mem."userId"::text = pa.user_id +LEFT JOIN finance.trolley_recipient AS tr + ON tr.user_id = pa.user_id +LEFT JOIN latest_tax_form AS ltf + ON ltf.user_id = pa.user_id +ORDER BY pa.gross_amount DESC, mem.handle; +`; + +const HELP = ` +Usage: + node scripts/export-member-tax-aggregated.js [--output ] [--start-date YYYY-MM-DD] [--end-date YYYY-MM-DD] + +Required environment variables: + DATABASE_URL + +Defaults: + start-date: January 1 of previous calendar year + end-date: January 1 of current calendar year + output: ./member-tax-aggregated--to-.csv +`; + +function parseArgs(argv) { + const options = { + output: null, + startDate: null, + endDate: null, + help: false, + }; + + for (let i = 0; i < argv.length; i += 1) { + const arg = argv[i]; + if (arg === "--help" || arg === "-h") { + options.help = true; + continue; + } + if (arg === "--output" || arg === "-o") { + const value = argv[i + 1]; + if (!value) { + throw new Error("--output requires a value"); + } + options.output = value; + i += 1; + continue; + } + if (arg === "--start-date") { + const value = argv[i + 1]; + if (!value) { + throw new Error("--start-date requires a value"); + } + options.startDate = value; + i += 1; + continue; + } + if (arg === "--end-date") { + const value = argv[i + 1]; + if (!value) { + throw new Error("--end-date requires a value"); + } + options.endDate = value; + i += 1; + continue; + } + throw new Error(`Unknown argument: ${arg}`); + } + + return options; +} + +function getDefaultWindow() { + const now = new Date(); + const currentYear = now.getUTCFullYear(); + return { + startDate: `${currentYear - 1}-01-01`, + endDate: `${currentYear}-01-01`, + }; +} + +function validateIsoDate(value, name) { + if (!/^\d{4}-\d{2}-\d{2}$/.test(value)) { + throw new Error(`${name} must be in YYYY-MM-DD format`); + } + const parsed = new Date(`${value}T00:00:00.000Z`); + if (Number.isNaN(parsed.getTime())) { + throw new Error(`${name} is not a valid date`); + } +} + +function csvEscape(value) { + if (value === null || value === undefined) { + return ""; + } + const stringValue = String(value); + if (!/[",\n\r]/.test(stringValue)) { + return stringValue; + } + return `"${stringValue.replace(/"/g, '""')}"`; +} + +function writeCsv(outputPath, rows) { + fs.mkdirSync(path.dirname(outputPath), { recursive: true }); + const lines = []; + lines.push(CSV_COLUMNS.map(csvEscape).join(",")); + + for (const row of rows) { + const line = CSV_COLUMNS.map((column) => { + const value = row[column]; + if (column === "last_payment_release_date" && value) { + return csvEscape(new Date(value).toISOString()); + } + return csvEscape(value); + }).join(","); + lines.push(line); + } + + fs.writeFileSync(outputPath, `${lines.join("\n")}\n`, "utf8"); +} + +async function run() { + const options = parseArgs(process.argv.slice(2)); + if (options.help) { + console.log(HELP.trim()); + return; + } + + const defaultWindow = getDefaultWindow(); + const startDate = options.startDate ?? defaultWindow.startDate; + const endDate = options.endDate ?? defaultWindow.endDate; + + validateIsoDate(startDate, "start-date"); + validateIsoDate(endDate, "end-date"); + if (startDate >= endDate) { + throw new Error("start-date must be earlier than end-date"); + } + + const databaseUrl = process.env.DATABASE_URL; + if (!databaseUrl) { + throw new Error("DATABASE_URL is required"); + } + + const outputFile = + options.output ?? `member-tax-aggregated-${startDate}-to-${endDate}.csv`; + const outputPath = path.resolve(process.cwd(), outputFile); + const pool = new Pool({ connectionString: databaseUrl }); + + try { + console.log( + `[member-tax-aggregated-export] Exporting data for ${startDate} to ${endDate}`, + ); + const result = await pool.query(AGGREGATED_QUERY, [startDate, endDate]); + writeCsv(outputPath, result.rows); + console.log( + `[member-tax-aggregated-export] Rows: ${result.rows.length}. Wrote CSV: ${outputPath}`, + ); + } finally { + await pool.end(); + } +} + +run().catch((error) => { + console.error(`[member-tax-aggregated-export] Failed: ${error.message}`); + process.exit(1); +}); diff --git a/scripts/export-member-tax.js b/scripts/export-member-tax.js new file mode 100644 index 0000000..7b715cf --- /dev/null +++ b/scripts/export-member-tax.js @@ -0,0 +1,449 @@ +#!/usr/bin/env node + +const fs = require("fs"); +const path = require("path"); +const { Pool } = require("pg"); + +const CSV_COLUMNS = [ + "payment.payment_id", + "payee.handle", + "payee.email", + "payee.first_name", + "payee.last_name", + "user_tax_form.tax_form_name", + "member_profile_advanced.full_address_1", + "payment.payment_type_id", + "payment.payment_type_desc", + "payment_paid_date.date_date", + "user_tax_form.tax_form_status", + "payee.payment_method_desc", + "member_profile_basic.home_country", + "member_profile_advanced.street_address_1", + "member_profile_advanced.street_address_2", + "member_profile_advanced.city", + "member_profile_advanced.state_code", + "member_profile_advanced.country", + "payee.zip", + "user_tax_form.withholding_amount", + "user_tax_form.withholding_percentage", + "user_payment.gross_amount", + "user_payment.net_amount", +]; + +const BASE_DATA_QUERY = ` +WITH latest_payment AS MATERIALIZED ( + SELECT + p.winnings_id, + MAX(p.version) AS max_version + FROM finance.payment AS p + GROUP BY p.winnings_id +), +payment_rows AS MATERIALIZED ( + SELECT + p.payment_id::text AS payment_id, + w.winner_id AS user_id, + COALESCE(w.category::text, w.type::text) AS payment_type_id, + INITCAP(REPLACE(COALESCE(w.category::text, w.type::text), '_', ' ')) + AS payment_type_desc, + DATE(p.date_paid) AS paid_date, + COALESCE(p.gross_amount, 0) AS gross_amount, + COALESCE(p.net_amount, 0) AS net_amount + FROM finance.payment AS p + JOIN latest_payment AS lp + ON lp.winnings_id = p.winnings_id + AND lp.max_version = p.version + JOIN finance.winnings AS w + ON w.winning_id = p.winnings_id + WHERE w.type = 'PAYMENT' + AND p.date_paid >= $1::date + AND p.date_paid < $2::date +), +paid_users AS MATERIALIZED ( + SELECT DISTINCT pr.user_id + FROM payment_rows AS pr +), +member_base AS MATERIALIZED ( + SELECT + mem."userId", + mem.handle, + mem.email, + mem."firstName", + mem."lastName", + mem.country, + mem."homeCountryCode", + COALESCE(home_code.name, home_id.name, mem."homeCountryCode") + AS home_country + FROM members.member AS mem + JOIN paid_users AS pu + ON pu.user_id = mem."userId"::text + LEFT JOIN lookups."Country" AS home_code + ON UPPER(home_code."countryCode") = UPPER(mem."homeCountryCode") + LEFT JOIN lookups."Country" AS home_id + ON UPPER(home_id.id) = UPPER(mem."homeCountryCode") + WHERE mem.email IS NULL + OR mem.email NOT ILIKE '%@wipro%' +), +latest_tax_form AS MATERIALIZED ( + SELECT DISTINCT ON (utf.user_id) + utf.user_id, + utf.tax_form_status + FROM finance.user_tax_form_associations AS utf + JOIN paid_users AS pu + ON pu.user_id = utf.user_id + ORDER BY + utf.user_id, + CASE utf.tax_form_status + WHEN 'ACTIVE' THEN 0 + ELSE 1 + END, + utf.date_filed DESC, + utf.id DESC +), +preferred_address AS MATERIALIZED ( + SELECT DISTINCT ON (ma."userId") + ma."userId", + ma."streetAddr1" AS street_address_1, + ma."streetAddr2" AS street_address_2, + ma.city, + ma."stateCode" AS state_code, + ma.zip + FROM members."memberAddress" AS ma + JOIN paid_users AS pu + ON pu.user_id = ma."userId"::text + ORDER BY + ma."userId", + CASE + WHEN UPPER(ma.type) = 'HOME' THEN 0 + WHEN UPPER(ma.type) = 'BILLING' THEN 1 + ELSE 2 + END, + ma."updatedAt" DESC NULLS LAST, + ma."createdAt" DESC NULLS LAST, + ma.id DESC +), +preferred_payment_method AS MATERIALIZED ( + SELECT DISTINCT ON (upm.user_id) + upm.user_id, + pm.name AS payment_method_desc + FROM finance.user_payment_methods AS upm + JOIN paid_users AS pu + ON pu.user_id = upm.user_id + JOIN finance.payment_method AS pm + ON pm.payment_method_id = upm.payment_method_id + ORDER BY + upm.user_id, + CASE upm.status + WHEN 'CONNECTED' THEN 0 + WHEN 'OTP_VERIFIED' THEN 1 + WHEN 'OTP_PENDING' THEN 2 + ELSE 3 + END, + upm.payment_method_id +) +SELECT + mb."userId"::text AS "__user_id", + pr.payment_id AS "__payment_id", + pr.payment_id AS "payment.payment_id", + mb.handle AS "payee.handle", + mb.email AS "payee.email", + mb."firstName" AS "payee.first_name", + mb."lastName" AS "payee.last_name", + NULL::text AS "user_tax_form.tax_form_name", + CONCAT_WS( + ' ', + NULLIF(addr.street_address_1, ''), + NULLIF(addr.street_address_2, ''), + NULLIF(addr.city, ''), + NULLIF(addr.state_code, ''), + NULLIF(COALESCE(NULLIF(mb.country, ''), mb.home_country), '') + ) AS "member_profile_advanced.full_address_1", + pr.payment_type_id AS "payment.payment_type_id", + pr.payment_type_desc AS "payment.payment_type_desc", + pr.paid_date AS "payment_paid_date.date_date", + utf.tax_form_status AS "user_tax_form.tax_form_status", + ppm.payment_method_desc AS "payee.payment_method_desc", + mb.home_country AS "member_profile_basic.home_country", + addr.street_address_1 AS "member_profile_advanced.street_address_1", + addr.street_address_2 AS "member_profile_advanced.street_address_2", + addr.city AS "member_profile_advanced.city", + addr.state_code AS "member_profile_advanced.state_code", + COALESCE(NULLIF(mb.country, ''), mb.home_country) + AS "member_profile_advanced.country", + addr.zip AS "payee.zip", + NULL::numeric AS "user_tax_form.withholding_amount", + NULL::numeric AS "user_tax_form.withholding_percentage", + pr.gross_amount AS "user_payment.gross_amount", + pr.net_amount AS "user_payment.net_amount" +FROM payment_rows AS pr +JOIN member_base AS mb + ON mb."userId"::text = pr.user_id +LEFT JOIN latest_tax_form AS utf + ON utf.user_id = pr.user_id +LEFT JOIN preferred_address AS addr + ON addr."userId" = mb."userId" +LEFT JOIN preferred_payment_method AS ppm + ON ppm.user_id = pr.user_id +ORDER BY pr.paid_date DESC, mb.handle, pr.payment_id; +`; + +const OLD_TAX_FORM_QUERY = ` +WITH input_users AS ( + SELECT DISTINCT UNNEST($1::text[]) AS user_id +) +SELECT DISTINCT ON (utfa.user_id) + utfa.user_id, + tf.name AS tax_form_name, + utfa.withholding_amount, + utfa.withholding_percentage +FROM public.user_tax_form_associations AS utfa +JOIN input_users AS iu + ON iu.user_id = utfa.user_id +LEFT JOIN public.tax_forms AS tf + ON tf.tax_form_id = utfa.tax_form_id +ORDER BY + utfa.user_id, + CASE utfa.status_id + WHEN 'ACTIVE' THEN 0 + WHEN 'OTP_VERIFIED' THEN 1 + WHEN 'OTP_PENDING' THEN 2 + ELSE 3 + END, + utfa.date_filed DESC NULLS LAST, + utfa.id DESC; +`; + +const OLD_PAYMENT_METHOD_QUERY = ` +WITH input_payments AS ( + SELECT DISTINCT UNNEST($1::text[]) AS payment_id +) +SELECT DISTINCT ON (pra.payment_id::text) + pra.payment_id::text AS payment_id, + pm.name AS payment_method_desc +FROM input_payments AS ip +JOIN public.payment_release_associations AS pra + ON pra.payment_id::text = ip.payment_id +JOIN public.payment_releases AS pr + ON pr.payment_release_id = pra.payment_release_id +JOIN public.payment_method AS pm + ON pm.payment_method_id = pr.payment_method_id +ORDER BY + pra.payment_id::text, + pr.created_at DESC NULLS LAST, + pr.payment_release_id DESC; +`; + +const HELP = ` +Usage: + node scripts/export-member-tax.js [--output ] [--start-date YYYY-MM-DD] [--end-date YYYY-MM-DD] + +Required environment variables: + DATABASE_URL + OLD_PAYMENTS_DATABASE_URL + +Defaults: + start-date: January 1 of previous calendar year + end-date: January 1 of current calendar year + output: ./member-tax--to-.csv +`; + +function parseArgs(argv) { + const options = { + output: null, + startDate: null, + endDate: null, + help: false, + }; + + for (let i = 0; i < argv.length; i += 1) { + const arg = argv[i]; + if (arg === "--help" || arg === "-h") { + options.help = true; + continue; + } + if (arg === "--output" || arg === "-o") { + const value = argv[i + 1]; + if (!value) { + throw new Error("--output requires a value"); + } + options.output = value; + i += 1; + continue; + } + if (arg === "--start-date") { + const value = argv[i + 1]; + if (!value) { + throw new Error("--start-date requires a value"); + } + options.startDate = value; + i += 1; + continue; + } + if (arg === "--end-date") { + const value = argv[i + 1]; + if (!value) { + throw new Error("--end-date requires a value"); + } + options.endDate = value; + i += 1; + continue; + } + throw new Error(`Unknown argument: ${arg}`); + } + + return options; +} + +function getDefaultWindow() { + const now = new Date(); + const currentYear = now.getUTCFullYear(); + return { + startDate: `${currentYear - 1}-01-01`, + endDate: `${currentYear}-01-01`, + }; +} + +function validateIsoDate(value, name) { + if (!/^\d{4}-\d{2}-\d{2}$/.test(value)) { + throw new Error(`${name} must be in YYYY-MM-DD format`); + } + const parsed = new Date(`${value}T00:00:00.000Z`); + if (Number.isNaN(parsed.getTime())) { + throw new Error(`${name} is not a valid date`); + } +} + +function csvEscape(value) { + if (value === null || value === undefined) { + return ""; + } + const stringValue = String(value); + if (!/[",\n\r]/.test(stringValue)) { + return stringValue; + } + return `"${stringValue.replace(/"/g, '""')}"`; +} + +function writeCsv(outputPath, rows) { + fs.mkdirSync(path.dirname(outputPath), { recursive: true }); + const lines = []; + lines.push(CSV_COLUMNS.map(csvEscape).join(",")); + + for (const row of rows) { + const line = CSV_COLUMNS.map((column) => csvEscape(row[column])).join(","); + lines.push(line); + } + + fs.writeFileSync(outputPath, `${lines.join("\n")}\n`, "utf8"); +} + +async function run() { + const options = parseArgs(process.argv.slice(2)); + if (options.help) { + console.log(HELP.trim()); + return; + } + + const defaultWindow = getDefaultWindow(); + const startDate = options.startDate ?? defaultWindow.startDate; + const endDate = options.endDate ?? defaultWindow.endDate; + + validateIsoDate(startDate, "start-date"); + validateIsoDate(endDate, "end-date"); + if (startDate >= endDate) { + throw new Error("start-date must be earlier than end-date"); + } + + const mainDatabaseUrl = process.env.DATABASE_URL; + const oldPaymentsDatabaseUrl = process.env.OLD_PAYMENTS_DATABASE_URL; + + if (!mainDatabaseUrl) { + throw new Error("DATABASE_URL is required"); + } + if (!oldPaymentsDatabaseUrl) { + throw new Error("OLD_PAYMENTS_DATABASE_URL is required"); + } + + const outputFile = + options.output ?? `member-tax-${startDate}-to-${endDate}.csv`; + const outputPath = path.resolve(process.cwd(), outputFile); + + const mainPool = new Pool({ connectionString: mainDatabaseUrl }); + const oldPaymentsPool = new Pool({ connectionString: oldPaymentsDatabaseUrl }); + + try { + console.log( + `[member-tax-export] Exporting data for ${startDate} to ${endDate}`, + ); + + const baseResult = await mainPool.query(BASE_DATA_QUERY, [startDate, endDate]); + const baseRows = baseResult.rows; + const userIds = Array.from( + new Set(baseRows.map((row) => row.__user_id).filter(Boolean)), + ); + const paymentIds = Array.from( + new Set(baseRows.map((row) => row.__payment_id).filter(Boolean)), + ); + + console.log(`[member-tax-export] Main rows: ${baseRows.length}`); + console.log(`[member-tax-export] Distinct users: ${userIds.length}`); + console.log(`[member-tax-export] Distinct payments: ${paymentIds.length}`); + + let taxRows = []; + if (userIds.length > 0) { + const oldResult = await oldPaymentsPool.query(OLD_TAX_FORM_QUERY, [userIds]); + taxRows = oldResult.rows; + } + + let paymentMethodRows = []; + if (paymentIds.length > 0) { + const oldPaymentMethodResult = await oldPaymentsPool.query( + OLD_PAYMENT_METHOD_QUERY, + [paymentIds], + ); + paymentMethodRows = oldPaymentMethodResult.rows; + } + + const taxFormsByUserId = new Map( + taxRows.map((row) => [ + String(row.user_id), + { + taxFormName: row.tax_form_name ?? null, + withholdingAmount: row.withholding_amount ?? null, + withholdingPercentage: row.withholding_percentage ?? null, + }, + ]), + ); + const paymentMethodByPaymentId = new Map( + paymentMethodRows.map((row) => [ + String(row.payment_id), + row.payment_method_desc ?? null, + ]), + ); + + const mergedRows = baseRows.map((row) => { + const userId = String(row.__user_id); + const paymentId = String(row.__payment_id); + const oldTaxData = taxFormsByUserId.get(userId); + const oldPaymentMethod = paymentMethodByPaymentId.get(paymentId); + return { + ...row, + "user_tax_form.tax_form_name": oldTaxData?.taxFormName ?? null, + "user_tax_form.withholding_amount": oldTaxData?.withholdingAmount ?? null, + "user_tax_form.withholding_percentage": + oldTaxData?.withholdingPercentage ?? null, + "payee.payment_method_desc": + oldPaymentMethod ?? row["payee.payment_method_desc"] ?? null, + }; + }); + + writeCsv(outputPath, mergedRows); + console.log(`[member-tax-export] Wrote CSV: ${outputPath}`); + } finally { + await Promise.allSettled([mainPool.end(), oldPaymentsPool.end()]); + } +} + +run().catch((error) => { + console.error(`[member-tax-export] Failed: ${error.message}`); + process.exit(1); +}); From 83d675d4f64c89fb60df94642d7f2d78f455df0c Mon Sep 17 00:00:00 2001 From: Vasilica Olariu Date: Thu, 19 Feb 2026 11:36:39 +0200 Subject: [PATCH 2/2] PS-529 - for TG make sure to return only payments, without not rewards --- sql/reports/topgear/payments.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/sql/reports/topgear/payments.sql b/sql/reports/topgear/payments.sql index c53b450..a14adfa 100644 --- a/sql/reports/topgear/payments.sql +++ b/sql/reports/topgear/payments.sql @@ -13,4 +13,5 @@ INNER JOIN finance.winnings w on p.winnings_id = w.winning_id WHERE p.created_at >= $1::timestamptz AND p.created_at <= $2::timestamptz AND p.billing_account = '80000062' + AND w.type = 'PAYMENT' ORDER BY p.created_at DESC;