Skip to content

Commit

Permalink
feat: Add CR Transactions to Transactions view
Browse files Browse the repository at this point in the history
* Pass description to store the nickname
* Update materialized view with new union on compliance reports
* Rename Id -> ID
  • Loading branch information
dhaselhan committed Jan 13, 2025
1 parent 5d00b88 commit f40b33e
Show file tree
Hide file tree
Showing 8 changed files with 274 additions and 7 deletions.
238 changes: 238 additions & 0 deletions backend/lcfs/db/migrations/versions/2025-01-13-22-13_f78e53370ed2.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,238 @@
"""Add CR to Transaction Aggregate
Revision ID: f78e53370ed2
Revises: d25e7c47659e
Create Date: 2025-01-13 22:13:48.610890
"""

import sqlalchemy as sa
from alembic import op

# revision identifiers, used by Alembic.
revision = "f78e53370ed2"
down_revision = "d25e7c47659e"
branch_labels = None
depends_on = None


def upgrade() -> None:
op.execute("DROP MATERIALIZED VIEW mv_transaction_aggregate;")
op.execute(
"""
CREATE MATERIALIZED VIEW mv_transaction_aggregate AS
SELECT
t.transfer_id AS transaction_id,
'Transfer' AS transaction_type,
NULL AS description,
org_from.organization_id AS from_organization_id,
org_from.name AS from_organization,
org_to.organization_id AS to_organization_id,
org_to.name AS to_organization,
t.quantity,
t.price_per_unit,
ts.status::text AS status,
NULL AS compliance_period,
t.from_org_comment AS COMMENT,
tc.category,
(
SELECT
th.create_date
FROM
transfer_history th
WHERE
th.transfer_id = t.transfer_id
AND th.transfer_status_id = 6) AS recorded_date, NULL AS approved_date, t.transaction_effective_date, t.update_date, t.create_date
FROM
transfer t
JOIN organization org_from ON t.from_organization_id = org_from.organization_id
JOIN organization org_to ON t.to_organization_id = org_to.organization_id
JOIN transfer_status ts ON t.current_status_id = ts.transfer_status_id
LEFT JOIN transfer_category tc ON t.transfer_category_id = tc.transfer_category_id
UNION ALL
SELECT
ia.initiative_agreement_id AS transaction_id,
'InitiativeAgreement' AS transaction_type,
NULL AS description,
NULL AS from_organization_id,
NULL AS from_organization,
org.organization_id AS to_organization_id,
org.name AS to_organization,
ia.compliance_units AS quantity,
NULL AS price_per_unit,
ias.status::text AS status,
NULL AS compliance_period,
ia.gov_comment AS COMMENT,
NULL AS category,
NULL AS recorded_date,
(
SELECT
iah.create_date
FROM
initiative_agreement_history iah
WHERE
iah.initiative_agreement_id = ia.initiative_agreement_id
AND iah.initiative_agreement_status_id = 3) AS approved_date, ia.transaction_effective_date, ia.update_date, ia.create_date
FROM
initiative_agreement ia
JOIN organization org ON ia.to_organization_id = org.organization_id
JOIN initiative_agreement_status ias ON ia.current_status_id = ias.initiative_agreement_status_id
UNION ALL
SELECT
aa.admin_adjustment_id AS transaction_id,
'AdminAdjustment' AS transaction_type,
NULL AS description,
NULL AS from_organization_id,
NULL AS from_organization,
org.organization_id AS to_organization_id,
org.name AS to_organization,
aa.compliance_units AS quantity,
NULL AS price_per_unit,
aas.status::text AS status,
NULL AS compliance_period,
aa.gov_comment AS COMMENT,
NULL AS category,
NULL AS recorded_date,
(
SELECT
aah.create_date
FROM
admin_adjustment_history aah
WHERE
aah.admin_adjustment_id = aa.admin_adjustment_id
AND aah.admin_adjustment_status_id = 3) AS approved_date, aa.transaction_effective_date, aa.update_date, aa.create_date
FROM
admin_adjustment aa
JOIN organization org ON aa.to_organization_id = org.organization_id
JOIN admin_adjustment_status aas ON aa.current_status_id = aas.admin_adjustment_status_id
UNION ALL
SELECT
cr.compliance_report_id AS transaction_id,
'ComplianceReport' AS transaction_type,
cr.nickname AS description,
NULL AS from_organization_id,
NULL AS from_organization,
org.organization_id AS to_organization_id,
org.name AS to_organization,
tr.compliance_units AS quantity,
NULL AS price_per_unit,
crs.status::text AS status,
cp.description AS compliance_period,
NULL AS COMMENT,
NULL AS category,
NULL AS recorded_date,
NULL AS approved_date,
NULL AS transaction_effective_date,
cr.update_date,
cr.create_date
FROM
compliance_report cr
JOIN organization org ON cr.organization_id = org.organization_id
JOIN compliance_report_status crs ON cr.current_status_id = crs.compliance_report_status_id
JOIN compliance_period cp ON cr.compliance_period_id = cp.compliance_period_id
JOIN TRANSACTION tr ON cr.transaction_id = tr.transaction_id
AND cr.transaction_id IS NOT NULL;
"""
)

# Create unique index on mv_transaction_aggregate
op.execute(
"""
CREATE UNIQUE INDEX mv_transaction_aggregate_unique_idx ON mv_transaction_aggregate (transaction_id, description, transaction_type);
"""
)


def downgrade() -> None:
op.execute("DROP MATERIALIZED VIEW mv_transaction_aggregate;")
op.execute(
"""
CREATE MATERIALIZED VIEW mv_transaction_aggregate AS
SELECT
t.transfer_id AS transaction_id,
'Transfer' AS transaction_type,
org_from.organization_id AS from_organization_id,
org_from.name AS from_organization,
org_to.organization_id AS to_organization_id,
org_to.name AS to_organization,
t.quantity,
t.price_per_unit,
ts.status::text AS status,
NULL AS compliance_period,
t.from_org_comment AS comment,
tc.category,
(
SELECT th.create_date
FROM transfer_history th
WHERE th.transfer_id = t.transfer_id AND th.transfer_status_id = 6
) AS recorded_date,
NULL AS approved_date,
t.transaction_effective_date,
t.update_date,
t.create_date
FROM transfer t
JOIN organization org_from ON t.from_organization_id = org_from.organization_id
JOIN organization org_to ON t.to_organization_id = org_to.organization_id
JOIN transfer_status ts ON t.current_status_id = ts.transfer_status_id
LEFT JOIN transfer_category tc ON t.transfer_category_id = tc.transfer_category_id
UNION ALL
SELECT
ia.initiative_agreement_id AS transaction_id,
'InitiativeAgreement' AS transaction_type,
NULL AS from_organization_id,
NULL AS from_organization,
org.organization_id AS to_organization_id,
org.name AS to_organization,
ia.compliance_units AS quantity,
NULL AS price_per_unit,
ias.status::text AS status,
NULL AS compliance_period,
ia.gov_comment AS comment,
NULL AS category,
NULL AS recorded_date,
(
SELECT iah.create_date
FROM initiative_agreement_history iah
WHERE iah.initiative_agreement_id = ia.initiative_agreement_id AND iah.initiative_agreement_status_id = 3
) AS approved_date,
ia.transaction_effective_date,
ia.update_date,
ia.create_date
FROM initiative_agreement ia
JOIN organization org ON ia.to_organization_id = org.organization_id
JOIN initiative_agreement_status ias ON ia.current_status_id = ias.initiative_agreement_status_id
UNION ALL
SELECT
aa.admin_adjustment_id AS transaction_id,
'AdminAdjustment' AS transaction_type,
NULL AS from_organization_id,
NULL AS from_organization,
org.organization_id AS to_organization_id,
org.name AS to_organization,
aa.compliance_units AS quantity,
NULL AS price_per_unit,
aas.status::text AS status,
NULL AS compliance_period,
aa.gov_comment AS comment,
NULL AS category,
NULL AS recorded_date,
(
SELECT aah.create_date
FROM admin_adjustment_history aah
WHERE aah.admin_adjustment_id = aa.admin_adjustment_id AND aah.admin_adjustment_status_id = 3
) AS approved_date,
aa.transaction_effective_date,
aa.update_date,
aa.create_date
FROM admin_adjustment aa
JOIN organization org ON aa.to_organization_id = org.organization_id
JOIN admin_adjustment_status aas ON aa.current_status_id = aas.admin_adjustment_status_id;
"""
)

# Create unique index on mv_transaction_aggregate
op.execute(
"""
CREATE UNIQUE INDEX mv_transaction_aggregate_unique_idx ON mv_transaction_aggregate (transaction_id, transaction_type);
"""
)
1 change: 1 addition & 0 deletions backend/lcfs/db/models/transaction/TransactionView.py
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,7 @@ class TransactionView(BaseModel):
# id and type columns are defined as a composite primary key.
transaction_id = Column(Integer, primary_key=True)
transaction_type = Column(String, primary_key=True)
description = Column(String)
from_organization_id = Column(Integer)
from_organization = Column(String)
to_organization_id = Column(Integer)
Expand Down
2 changes: 2 additions & 0 deletions backend/lcfs/web/api/transaction/schema.py
Original file line number Diff line number Diff line change
Expand Up @@ -69,10 +69,12 @@ class TransactionBaseSchema(BaseSchema):
class TransactionViewSchema(BaseSchema):
transaction_id: int
transaction_type: str
description: Optional[str] = None
from_organization: Optional[str] = None
to_organization: str
quantity: int
price_per_unit: Optional[float] = None
compliance_period: Optional[str] = None
status: str
create_date: datetime
update_date: datetime
Expand Down
2 changes: 1 addition & 1 deletion frontend/src/assets/locales/en/fuelCode.json
Original file line number Diff line number Diff line change
Expand Up @@ -23,7 +23,7 @@
"addRow": "Add row",
"rows": "rows",
"fuelCodeColLabels": {
"fuelCodeId": "Fuel Code Id",
"fuelCodeId": "Fuel Code ID",
"status": "Status",
"prefix": "Prefix",
"fuelSuffix": "Iteration",
Expand Down
2 changes: 1 addition & 1 deletion frontend/src/assets/locales/en/transaction.json
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
{
"title": "Transactions",
"txnColLabels": {
"txnId": "Id",
"txnId": "ID",
"compliancePeriod": "Compliance period",
"type": "Type",
"organizationFrom": "From",
Expand Down
2 changes: 2 additions & 0 deletions frontend/src/utils/grid/cellRenderers.jsx
Original file line number Diff line number Diff line change
Expand Up @@ -181,6 +181,7 @@ export const TransactionStatusRenderer = (props) => {
'Sent',
'Submitted',
'Approved',
'Assessed',
'Recorded',
'Refused',
'Deleted',
Expand All @@ -194,6 +195,7 @@ export const TransactionStatusRenderer = (props) => {
'info',
'success',
'success',
'success',
'error',
'error',
'error',
Expand Down
15 changes: 13 additions & 2 deletions frontend/src/views/Transactions/Transactions.jsx
Original file line number Diff line number Diff line change
Expand Up @@ -66,8 +66,13 @@ export const Transactions = () => {
url: (
data // Based on the user Type (BCeID or IDIR) navigate to specific view
) => {
const { transactionId, transactionType, fromOrganization, status } =
data.data
const {
transactionId,
transactionType,
fromOrganization,
status,
compliancePeriod
} = data.data
const userOrgName = currentUser?.organization?.name

// Define routes mapping for transaction types
Expand All @@ -87,6 +92,10 @@ export const Transactions = () => {
? ROUTES.INITIATIVE_AGREEMENT_VIEW
: ROUTES.ORG_INITIATIVE_AGREEMENT_VIEW,
edit: ROUTES.INITIATIVE_AGREEMENT_EDIT
},
ComplianceReport: {
view: ROUTES.REPORTS_VIEW,
edit: ROUTES.INITIATIVE_AGREEMENT_EDIT
}
}

Expand All @@ -105,6 +114,8 @@ export const Transactions = () => {
return routeTemplate
.replace(':transactionId', transactionId)
.replace(':transferId', transactionId)
.replace(':compliancePeriod', compliancePeriod)
.replace(':complianceReportId', transactionId)
} else {
console.error(
'No route defined for this transaction type and scenario'
Expand Down
19 changes: 16 additions & 3 deletions frontend/src/views/Transactions/_schema.js
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,8 @@ import { useTransactionStatuses } from '@/hooks/useTransactions'
const prefixMap = {
Transfer: 'CT',
AdminAdjustment: 'AA',
InitiativeAgreement: 'IA'
InitiativeAgreement: 'IA',
ComplianceReport: 'CR'
}

export const transactionsColDefs = (t) => [
Expand All @@ -36,7 +37,16 @@ export const transactionsColDefs = (t) => [
colId: 'transactionType',
field: 'transactionType',
headerName: t('txn:txnColLabels.type'),
valueFormatter: spacesFormatter,
valueGetter: (params) => {
const value = spacesFormatter({ value: params.data.transactionType })
const suffix = params.data.description

if (suffix) {
debugger
return `${value} - ${suffix}`
}
return value
},
filter: true, // Enable filtering
filterParams: {
textFormatter: (value) => value.replace(/\s+/g, '').toLowerCase(),
Expand All @@ -56,6 +66,9 @@ export const transactionsColDefs = (t) => [
headerName: t('txn:txnColLabels.organizationFrom'),
minWidth: 300,
flex: 2,
valueGetter: (params) => {
return params.fromOrganization || 'N/A'
},
filterParams: {
buttons: ['clear']
}
Expand Down Expand Up @@ -91,7 +104,7 @@ export const transactionsColDefs = (t) => [
width: 190,
valueGetter: (params) => {
const value = params.data?.pricePerUnit
return value !== null && value !== undefined ? value : null
return value !== null && value !== undefined ? value : 'N/A'
},
filter: 'agNumberColumnFilter',
filterParams: {
Expand Down

0 comments on commit f40b33e

Please sign in to comment.