Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

PFS-198 paid invoice report #193

Open
wants to merge 9 commits into
base: main
Choose a base branch
from
129 changes: 129 additions & 0 deletions finance-api/internal/db/paid_invoices.go
Original file line number Diff line number Diff line change
@@ -0,0 +1,129 @@
package db

import (
"github.com/ministryofjustice/opg-sirius-supervision-finance-hub/shared"
"os"
"time"
)

type PaidInvoices struct {
FromDate *shared.Date
ToDate *shared.Date
}

const PaidInvoicesQuery = `WITH paid_invoices AS (SELECT i.id
FROM supervision_finance.ledger_allocation la
JOIN supervision_finance.ledger l ON l.id = la.ledger_id
JOIN supervision_finance.invoice i ON i.id = la.invoice_id
LEFT JOIN supervision_finance.invoice_adjustment ia ON i.id = ia.invoice_id
WHERE la.status IN ('ALLOCATED', 'REAPPLIED')
AND l.type NOT IN ('CREDIT WRITE OFF', 'WRITE OFF REVERSAL')
AND l.datetime BETWEEN $1 AND $2
GROUP BY i.id, i.amount
HAVING i.amount <= COALESCE(SUM(la.amount), 0))
SELECT CONCAT(p.firstname, ' ', p.surname) AS "Customer Name",
p.caserecnumber AS "Customer number",
fc.sop_number AS "SOP number",
'="0470"' AS "Entity",
COALESCE(cc.code::VARCHAR, 'Refer to SOP') AS "Revenue cost centre",
COALESCE(cc.cost_centre_description::VARCHAR, 'Refer to SOP') AS "Revenue cost centre description",
COALESCE(a.code::VARCHAR, 'Refer to SOP') AS "Revenue account code",
COALESCE(a.account_code_description::VARCHAR, 'Refer to SOP') AS "Revenue account code description",
i.feetype AS "Invoice type",
i.reference AS "Invoice number",
CASE
WHEN tt.fee_type IS NULL THEN 'Refer to SOP'
ELSE CONCAT(tt.fee_type, i.reference) END AS "Txn number",
COALESCE(tt.description, l.type) AS "Txn description",
((i.amount / 100.0)::NUMERIC(10, 2))::VARCHAR(255) AS "Original amount",
l.confirmeddate AS "Received date",
l.datetime AS "Sirius upload date",
CASE
WHEN l.type IN (
'BACS TRANSFER', 'CARD PAYMENT', 'UNKNOWN DEBIT',
'DIRECT DEBIT PAYMENT', 'ONLINE CARD PAYMENT', 'MOTO CARD PAYMENT',
'SUPERVISION BACS PAYMENT', 'OPG BACS PAYMENT', 'CHEQUE PAYMENT'
)
THEN ((la.amount / 100.0)::NUMERIC(10, 2))::VARCHAR(255)
ELSE '0' END AS "Cash amount",
CASE
WHEN l.type IN (
'UNKNOWN CREDIT',
'CREDIT MEMO', 'CREDIT EXEMPTION', 'CREDIT HARDSHIP', 'CREDIT REMISSION', 'CREDIT REAPPLY'
)
THEN ((la.amount / 100.0)::NUMERIC(10, 2)::VARCHAR(255))
ELSE '0' END AS "Credit amount",
CASE
WHEN l.type IN ('DEBIT MEMO', 'UNKNOWN DEBIT') THEN ((la.amount / 100.0)::NUMERIC(10, 2))::VARCHAR(255)
ELSE '0' END AS "Adjustment amount",
COALESCE(ia.notes, fr.notes) AS "Memo line description"
FROM paid_invoices pa
JOIN supervision_finance.invoice i ON pa.id = i.id
JOIN supervision_finance.ledger_allocation la ON pa.id = la.invoice_id
JOIN supervision_finance.ledger l ON la.ledger_id = l.id
JOIN supervision_finance.finance_client fc ON fc.id = l.finance_client_id
JOIN public.persons p ON fc.client_id = p.id
LEFT JOIN supervision_finance.invoice_adjustment ia ON i.id = ia.invoice_id
LEFT JOIN supervision_finance.fee_reduction fr ON fr.id = l.fee_reduction_id
LEFT JOIN LATERAL (
SELECT CASE WHEN i.feetype = 'AD' THEN 'AD' ELSE COALESCE(ifr.supervisionlevel, '') END AS supervision_level
FROM supervision_finance.invoice_fee_range ifr
WHERE ifr.invoice_id = i.id
ORDER BY id
LIMIT 1
) sl ON TRUE
LEFT JOIN supervision_finance.transaction_type tt ON
CASE
WHEN l.type = 'BACS TRANSFER' THEN
CASE WHEN l.bankaccount = 'BACS' THEN 'SUPERVISION BACS PAYMENT' ELSE 'OPG BACS PAYMENT' END
ELSE l.type
END = tt.ledger_type
AND CASE WHEN i.feetype = 'AD' THEN 'AD' ELSE sl.supervision_level END = tt.supervision_level
LEFT JOIN supervision_finance.account a ON tt.account_code = a.code
LEFT JOIN supervision_finance.cost_centre cc ON cc.code = a.cost_centre
WHERE la.status IN ('ALLOCATED', 'REAPPLIED')
AND l.type NOT IN ('CREDIT WRITE OFF', 'WRITE OFF REVERSAL');`

func (p *PaidInvoices) GetHeaders() []string {
return []string{
"Customer name",
"Customer number",
"SOP number",
"Entity",
"Cost centre",
"Cost centre description",
"Account code",
"Account code description",
"Invoice type",
"Invoice number",
"Txn number",
"Txn description",
"Original amount",
"Received date",
"Sirius upload date",
"Cash amount",
"Credit amount",
"Adjustment amount",
"Memo line description",
}
}

func (p *PaidInvoices) GetQuery() string {
return PaidInvoicesQuery
}

func (p *PaidInvoices) GetParams() []any {
if p.FromDate == nil {
from := shared.NewDate(os.Getenv("FINANCE_HUB_LIVE_DATE"))
p.FromDate = &from
}

if p.ToDate == nil {
to := shared.Date{Time: time.Now()}
p.ToDate = &to
}

p.ToDate.Time = p.ToDate.Time.Truncate(24 * time.Hour).Add(24 * time.Hour)

return []any{p.FromDate.Time.Format("2006-01-02 15:04:05"), p.ToDate.Time.Format("2006-01-02 15:04:05")}
}
99 changes: 99 additions & 0 deletions finance-api/internal/db/paid_invoices_test.go
Original file line number Diff line number Diff line change
@@ -0,0 +1,99 @@
package db

import (
"github.com/ministryofjustice/opg-sirius-supervision-finance-hub/shared"
"github.com/stretchr/testify/assert"
"time"
)

func (suite *IntegrationSuite) Test_paid_invoices() {
ctx := suite.ctx

today := suite.seeder.Today()
twoMonthsAgo := suite.seeder.Today().Sub(0, 2, 0)
twoYearsAgo := suite.seeder.Today().Sub(2, 0, 0)
fourYearsAgo := suite.seeder.Today().Sub(4, 0, 0)
general := "320.00"

// one client with one invoice and an exemption
client1ID := suite.seeder.CreateClient(ctx, "Ian", "Test", "12345678", "1234")
suite.seeder.CreateOrder(ctx, client1ID, "ACTIVE")
_, c1i1Ref := suite.seeder.CreateInvoice(ctx, client1ID, shared.InvoiceTypeAD, nil, twoMonthsAgo.StringPtr(), nil, nil, nil)
suite.seeder.CreateFeeReduction(ctx, client1ID, shared.FeeReductionTypeExemption, "2024", 1, "Test exemption")

// one client with:
// one invoice with no outstanding balance due to an exemption
// one invoice with outstanding balance
client2ID := suite.seeder.CreateClient(ctx, "John", "Suite", "87654321", "4321")
suite.seeder.CreateOrder(ctx, client2ID, "ACTIVE")
_, c2i1Ref := suite.seeder.CreateInvoice(ctx, client2ID, shared.InvoiceTypeAD, nil, fourYearsAgo.StringPtr(), nil, nil, nil)
_, _ = suite.seeder.CreateInvoice(ctx, client2ID, shared.InvoiceTypeS2, &general, twoYearsAgo.StringPtr(), twoYearsAgo.StringPtr(), nil, nil)
suite.seeder.CreateFeeReduction(ctx, client2ID, shared.FeeReductionTypeExemption, "2020", 1, "Test exemption")
// Update exemption years

// one client with one invoice partially paid due to a remission
client3ID := suite.seeder.CreateClient(ctx, "John", "Suite", "87654321", "4321")
suite.seeder.CreateOrder(ctx, client3ID, "ACTIVE")
_, _ = suite.seeder.CreateInvoice(ctx, client3ID, shared.InvoiceTypeAD, nil, fourYearsAgo.StringPtr(), nil, nil, nil)
suite.seeder.CreateFeeReduction(ctx, client3ID, shared.FeeReductionTypeRemission, "2018", 4, "Test remission")

c := Client{suite.seeder.Conn}

from := shared.NewDate(fourYearsAgo.String())
to := shared.NewDate(today.String())

rows, err := c.Run(ctx, &PaidInvoices{
FromDate: &from,
ToDate: &to,
})

runTime := time.Now()

assert.NoError(suite.T(), err)
assert.Equal(suite.T(), 3, len(rows))

results := mapByHeader(rows)
assert.NotEmpty(suite.T(), results)

// client 2 invoice 1
assert.Equal(suite.T(), "John Suite", results[0]["Customer name"], "Customer Name - client 2 invoice 1")
assert.Equal(suite.T(), "87654321", results[0]["Customer number"], "Customer number - client 2 invoice 1")
assert.Equal(suite.T(), "4321", results[0]["SOP number"], "SOP number - client 2 invoice 1")
assert.Equal(suite.T(), "=\"0470\"", results[0]["Entity"], "Entity - client 2 invoice 1")
assert.Equal(suite.T(), "10482009", results[0]["Cost centre"], "Cost centre - client 2 invoice 1")
assert.Equal(suite.T(), "Supervision Investigations", results[0]["Cost centre description"], "Cost centre description - client 2 invoice 1")
assert.Equal(suite.T(), "4481102114", results[0]["Account code"], "Account code - client 2 invoice 1")
assert.Equal(suite.T(), "INC - RECEIPT OF FEES AND CHARGES - Rem Appoint Deputy", results[0]["Account code description"], "Account code description - client 2 invoice 1")
assert.Equal(suite.T(), "AD", results[0]["Invoice type"], "Invoice type - client 2 invoice 1")
assert.Equal(suite.T(), c2i1Ref, results[0]["Invoice number"], "Invoice number - client 2 invoice 1")
assert.Equal(suite.T(), "ZE"+c2i1Ref, results[0]["Txn number"], "Txn number - client 2 invoice 1")
assert.Equal(suite.T(), "Exemption Credit", results[0]["Txn description"], "Txn description - client 2 invoice 1")
assert.Equal(suite.T(), "100.00", results[0]["Original amount"], "Original amount - client 2 invoice 1")
assert.Equal(suite.T(), "<nil>", results[0]["Received date"], "Received date - client 2 invoice 1")
assert.Contains(suite.T(), results[0]["Sirius upload date"], runTime.Format("2006-01-02 15:04"), "Sirius upload date - client 2 invoice 1")
assert.Equal(suite.T(), "0", results[0]["Cash amount"], "Cash amount - client 2 invoice 1")
assert.Equal(suite.T(), "100.00", results[0]["Credit amount"], "Credit amount - client 2 invoice 1")
assert.Equal(suite.T(), "0", results[0]["Adjustment amount"], "Adjustment amount - client 2 invoice 1")
assert.Equal(suite.T(), "Test exemption", results[0]["Memo line description"], "Memo line description - client 2 invoice 1")

// client 1
assert.Equal(suite.T(), "Ian Test", results[1]["Customer name"], "Customer Name - client 1")
assert.Equal(suite.T(), "12345678", results[1]["Customer number"], "Customer number - client 1")
assert.Equal(suite.T(), "1234", results[1]["SOP number"], "SOP number - client 1")
assert.Equal(suite.T(), "=\"0470\"", results[1]["Entity"], "Entity - client 1")
assert.Equal(suite.T(), "10482009", results[1]["Cost centre"], "Cost centre - client 1")
assert.Equal(suite.T(), "Supervision Investigations", results[1]["Cost centre description"], "Cost centre description - client 1")
assert.Equal(suite.T(), "4481102114", results[1]["Account code"], "Account code - client 1")
assert.Equal(suite.T(), "INC - RECEIPT OF FEES AND CHARGES - Rem Appoint Deputy", results[1]["Account code description"], "Account code description - client 1")
assert.Equal(suite.T(), "AD", results[1]["Invoice type"], "Invoice type - client 1")
assert.Equal(suite.T(), c1i1Ref, results[1]["Invoice number"], "Invoice number - client 1")
assert.Equal(suite.T(), "ZE"+c1i1Ref, results[1]["Txn number"], "Txn number - client 1")
assert.Equal(suite.T(), "Exemption Credit", results[1]["Txn description"], "Txn description - client 1")
assert.Equal(suite.T(), "100.00", results[1]["Original amount"], "Original amount - client 1")
assert.Equal(suite.T(), "<nil>", results[1]["Received date"], "Received date - client 1")
assert.Contains(suite.T(), results[1]["Sirius upload date"], runTime.Format("2006-01-02 15:04"), "Sirius upload date - client 1")
assert.Equal(suite.T(), "0", results[1]["Cash amount"], "Cash amount - client 1")
assert.Equal(suite.T(), "100.00", results[1]["Credit amount"], "Credit amount - client 1")
assert.Equal(suite.T(), "0", results[1]["Adjustment amount"], "Adjustment amount - client 1")
assert.Equal(suite.T(), "Test exemption", results[1]["Memo line description"], "Memo line description - client 1")
}
2 changes: 2 additions & 0 deletions finance-api/internal/reports/generate_report.go
Original file line number Diff line number Diff line change
Expand Up @@ -29,6 +29,8 @@ func (c *Client) GenerateAndUploadReport(ctx context.Context, reportRequest shar
}
case shared.ReportAccountTypeAgedDebtByCustomer:
query = &db.AgedDebtByCustomer{}
case shared.ReportAccountTypeARPaidInvoiceReport:
query = &db.PaidInvoices{}
default:
return fmt.Errorf("unknown query")
}
Expand Down
Loading