From d6b4a75231926cd8b0fa4564de0c4c66e0562140 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Micha=C3=ABl=20De=20Boey?= Date: Sat, 20 Jan 2024 21:56:50 +0100 Subject: [PATCH] refactor: remove `Transaction` `category` DB generation --- .../features/src/providers/plaid/plaid.etl.ts | 69 ++++++++++++++++++- .../src/providers/teller/teller.etl.ts | 40 ++++++++++- .../migration.sql | 63 +++++++++++++++++ prisma/schema.prisma | 2 +- 4 files changed, 169 insertions(+), 5 deletions(-) create mode 100644 prisma/migrations/20240120213022_remove_transaction_category_generation/migration.sql diff --git a/libs/server/features/src/providers/plaid/plaid.etl.ts b/libs/server/features/src/providers/plaid/plaid.etl.ts index ad16b62e..1c8159d4 100644 --- a/libs/server/features/src/providers/plaid/plaid.etl.ts +++ b/libs/server/features/src/providers/plaid/plaid.etl.ts @@ -13,6 +13,7 @@ import type { Item as PlaidItem, LiabilitiesObject as PlaidLiabilities, PlaidApi, + PersonalFinanceCategory, } from 'plaid' import { Prisma } from '@prisma/client' import { DateTime } from 'luxon' @@ -366,7 +367,7 @@ export class PlaidETL implements IETL { const txnUpsertQueries = chunk(transactions, 1_000).map((chunk) => { return this.prisma.$executeRaw` - INSERT INTO transaction (account_id, plaid_transaction_id, date, name, amount, pending, currency_code, merchant_name, plaid_category, plaid_category_id, plaid_personal_finance_category) + INSERT INTO transaction (account_id, plaid_transaction_id, date, name, amount, pending, currency_code, merchant_name, plaid_category, plaid_category_id, plaid_personal_finance_category, category) VALUES ${Prisma.join( chunk.map((plaidTransaction) => { @@ -401,7 +402,8 @@ export class PlaidETL implements IETL { ${merchant_name}, ${category ?? []}, ${category_id}, - ${personal_finance_category} + ${personal_finance_category}, + ${this.getMaybeTransactionCategory(personal_finance_category)} )` }) )} @@ -414,6 +416,7 @@ export class PlaidETL implements IETL { plaid_category = EXCLUDED.plaid_category, plaid_category_id = EXCLUDED.plaid_category_id, plaid_personal_finance_category = EXCLUDED.plaid_personal_finance_category; + category = EXCLUDED.category; ` }) @@ -444,6 +447,68 @@ export class PlaidETL implements IETL { ] } + private getMaybeTransactionCategory = (category?: PersonalFinanceCategory | null) => { + if (!category) { + return 'Other' + } + + if (category.primary === 'INCOME') { + return 'Income' + } + + if ( + ['LOAN_PAYMENTS_MORTGAGE_PAYMENT', 'RENT_AND_UTILITIES_RENT'].includes( + category.detailed + ) + ) { + return 'Housing Payments' + } + + if (category.detailed === 'LOAN_PAYMENTS_CAR_PAYMENT') { + return 'Vehicle Payments' + } + + if (category.primary === 'LOAN_PAYMENTS') { + return 'Other Payments' + } + + if (category.primary === 'HOME_IMPROVEMENT') { + return 'Home Improvement' + } + + if (category.primary === 'GENERAL_MERCHANDISE') { + return 'Shopping' + } + + if ( + category.primary === 'RENT_AND_UTILITIES' && + category.detailed !== 'RENT_AND_UTILITIES_RENT' + ) { + return 'Utilities' + } + + if (category.primary === 'FOOD_AND_DRINK') { + return 'Food and Drink' + } + + if (category.primary === 'TRANSPORTATION') { + return 'Transportation' + } + + if (category.primary === 'TRAVEL') { + return 'Travel' + } + + if ( + ['PERSONAL_CARE', 'MEDICAL'].includes(category.primary) && + category.detailed !== 'MEDICAL_VETERINARY_SERVICES' + ) { + return 'Health' + } + + return 'Other' + } + private _extractInvestmentTransactions(accessToken: string, dateRange: SharedType.DateRange) { return SharedUtil.paginate({ pageSize: 500, // https://plaid.com/docs/api/products/investments/#investments-transactions-get-request-options-count diff --git a/libs/server/features/src/providers/teller/teller.etl.ts b/libs/server/features/src/providers/teller/teller.etl.ts index 6891de97..406f70c3 100644 --- a/libs/server/features/src/providers/teller/teller.etl.ts +++ b/libs/server/features/src/providers/teller/teller.etl.ts @@ -25,6 +25,40 @@ type Connection = Pick< 'id' | 'userId' | 'tellerInstitutionId' | 'tellerAccessToken' > +const maybeCategoryByTellerCategory: Record< + Required['category'], + string +> = { + accommodation: 'Travel', + advertising: 'Other', + bar: 'Food and Drink', + charity: 'Other', + clothing: 'Shopping', + dining: 'Food and Drink', + education: 'Other', + electronics: 'Shopping', + entertainment: 'Shopping', + fuel: 'Transportation', + general: 'Other', + groceries: 'Food and Drink', + health: 'Health', + home: 'Home Improvement', + income: 'Income', + insurance: 'Other', + investment: 'Other', + loan: 'Other', + office: 'Other', + phone: 'Utilities', + service: 'Other', + shopping: 'Shopping', + software: 'Shopping', + sport: 'Shopping', + tax: 'Other', + transport: 'Transportation', + transportation: 'Transportation', + utilities: 'Utilities', +} + export class TellerETL implements IETL { public constructor( private readonly logger: Logger, @@ -204,7 +238,7 @@ export class TellerETL implements IETL { const txnUpsertQueries = _.chunk(transactions, 1_000).map((chunk) => { return this.prisma.$executeRaw` - INSERT INTO transaction (account_id, teller_transaction_id, date, name, amount, pending, currency_code, merchant_name, teller_type, teller_category) + INSERT INTO transaction (account_id, teller_transaction_id, date, name, amount, pending, currency_code, merchant_name, teller_type, teller_category, category) VALUES ${Prisma.join( chunk.map((tellerTransaction) => { @@ -231,7 +265,8 @@ export class TellerETL implements IETL { ${'USD'}, ${details.counterparty?.name ?? ''}, ${type}, - ${details.category ?? ''} + ${details.category ?? ''}, + ${maybeCategoryByTellerCategory[details.category ?? ''] ?? 'Other'} )` }) )} @@ -243,6 +278,7 @@ export class TellerETL implements IETL { merchant_name = EXCLUDED.merchant_name, teller_type = EXCLUDED.teller_type, teller_category = EXCLUDED.teller_category; + category = EXCLUDED.category; ` }) diff --git a/prisma/migrations/20240120213022_remove_transaction_category_generation/migration.sql b/prisma/migrations/20240120213022_remove_transaction_category_generation/migration.sql new file mode 100644 index 00000000..1acfb3ad --- /dev/null +++ b/prisma/migrations/20240120213022_remove_transaction_category_generation/migration.sql @@ -0,0 +1,63 @@ +-- AlterTable +ALTER TABLE "transaction" + RENAME COLUMN "category" TO "category_old"; + +DROP VIEW IF EXISTS transactions_enriched; + +ALTER TABLE "transaction" + ADD COLUMN "category" TEXT NOT NULL DEFAULT 'Other'::text; + +CREATE OR REPLACE VIEW transactions_enriched AS ( + SELECT + t.id, + t.created_at as "createdAt", + t.updated_at as "updatedAt", + t.name, + t.account_id as "accountId", + t.date, + t.flow, + COALESCE( + t.type_user, + CASE + -- no matching transaction + WHEN t.match_id IS NULL THEN ( + CASE + t.flow + WHEN 'INFLOW' THEN ( + CASE + a.classification + WHEN 'asset' THEN 'INCOME' :: "TransactionType" + WHEN 'liability' THEN 'PAYMENT' :: "TransactionType" + END + ) + WHEN 'OUTFLOW' THEN 'EXPENSE' :: "TransactionType" + END + ) -- has matching transaction + ELSE ( + CASE + a.classification + WHEN 'asset' THEN 'TRANSFER' :: "TransactionType" + WHEN 'liability' THEN 'PAYMENT' :: "TransactionType" + END + ) + END + ) AS "type", + t.type_user as "typeUser", + t.amount, + t.currency_code as "currencyCode", + t.pending, + t.merchant_name as "merchantName", + t.category, + t.category_user as "categoryUser", + t.excluded, + t.match_id as "matchId", + COALESCE(ac.user_id, a.user_id) as "userId", + a.classification as "accountClassification", + a.type as "accountType" + FROM + transaction t + inner join account a on a.id = t.account_id + left join account_connection ac on a.account_connection_id = ac.id +); + +ALTER TABLE "transaction" DROP COLUMN "category_old"; diff --git a/prisma/schema.prisma b/prisma/schema.prisma index 4242132e..78f96a4c 100644 --- a/prisma/schema.prisma +++ b/prisma/schema.prisma @@ -312,7 +312,7 @@ model Transaction { currencyCode String @default("USD") @map("currency_code") pending Boolean @default(false) merchantName String? @map("merchant_name") - category String @default(dbgenerated("COALESCE(category_user,\nCASE\n WHEN ((plaid_personal_finance_category ->> 'primary'::text) = 'INCOME'::text) THEN 'Income'::text\n WHEN ((plaid_personal_finance_category ->> 'detailed'::text) = ANY (ARRAY['LOAN_PAYMENTS_MORTGAGE_PAYMENT'::text, 'RENT_AND_UTILITIES_RENT'::text])) THEN 'Housing Payments'::text\n WHEN ((plaid_personal_finance_category ->> 'detailed'::text) = 'LOAN_PAYMENTS_CAR_PAYMENT'::text) THEN 'Vehicle Payments'::text\n WHEN ((plaid_personal_finance_category ->> 'primary'::text) = 'LOAN_PAYMENTS'::text) THEN 'Other Payments'::text\n WHEN ((plaid_personal_finance_category ->> 'primary'::text) = 'HOME_IMPROVEMENT'::text) THEN 'Home Improvement'::text\n WHEN ((plaid_personal_finance_category ->> 'primary'::text) = 'GENERAL_MERCHANDISE'::text) THEN 'Shopping'::text\n WHEN (((plaid_personal_finance_category ->> 'primary'::text) = 'RENT_AND_UTILITIES'::text) AND ((plaid_personal_finance_category ->> 'detailed'::text) <> 'RENT_AND_UTILITIES_RENT'::text)) THEN 'Utilities'::text\n WHEN ((plaid_personal_finance_category ->> 'primary'::text) = 'FOOD_AND_DRINK'::text) THEN 'Food and Drink'::text\n WHEN ((plaid_personal_finance_category ->> 'primary'::text) = 'TRANSPORTATION'::text) THEN 'Transportation'::text\n WHEN ((plaid_personal_finance_category ->> 'primary'::text) = 'TRAVEL'::text) THEN 'Travel'::text\n WHEN (((plaid_personal_finance_category ->> 'primary'::text) = ANY (ARRAY['PERSONAL_CARE'::text, 'MEDICAL'::text])) AND ((plaid_personal_finance_category ->> 'detailed'::text) <> 'MEDICAL_VETERINARY_SERVICES'::text)) THEN 'Health'::text\n WHEN (teller_category = 'income'::text) THEN 'Income'::text\n WHEN (teller_category = 'home'::text) THEN 'Home Improvement'::text\n WHEN (teller_category = ANY (ARRAY['phone'::text, 'utilities'::text])) THEN 'Utilities'::text\n WHEN (teller_category = ANY (ARRAY['dining'::text, 'bar'::text, 'groceries'::text])) THEN 'Food and Drink'::text\n WHEN (teller_category = ANY (ARRAY['clothing'::text, 'entertainment'::text, 'shopping'::text, 'electronics'::text, 'software'::text, 'sport'::text])) THEN 'Shopping'::text\n WHEN (teller_category = ANY (ARRAY['transportation'::text, 'fuel'::text])) THEN 'Transportation'::text\n WHEN (teller_category = ANY (ARRAY['accommodation'::text, 'transport'::text])) THEN 'Travel'::text\n WHEN (teller_category = 'health'::text) THEN 'Health'::text\n WHEN (teller_category = ANY (ARRAY['loan'::text, 'tax'::text, 'insurance'::text, 'office'::text])) THEN 'Other Payments'::text\n ELSE 'Other'::text\nEND)")) + category String @default("Other") categoryUser String? @map("category_user") excluded Boolean @default(false)