Skip to main content

Monthly Profit and Loss by Account (Fixed Monthly Columns)

This query creates a monthly profit and loss layout where each month is its own column, making it easy for users to compare month-over-month performance and build Excel dashboards.

Updated over a week ago

Purpose of this query

This SuiteQL statement returns a full year of financial activity for every P&L account, broken out into fixed monthly columns plus a total column. It includes account attributes such as account number, account name, parent account, account type, and financial statement section. Because each month is represented as a separate column, users can run side-by-side comparisons, build trend reports, or prepare formatted financial summaries. The year is currently hard-coded to 2025 and should be updated before use.

SuiteQL

/*
* INCOME STATEMENT (PROFIT & LOSS) - MONTHLY BY ACCOUNT (PIVOTED)
*
* This query generates a monthly income statement with one row per account
* and separate columns for each month (January through December) plus Total.
* Output format is ideal for traditional financial statement presentation.
*
* Shows: Revenue, Cost of Goods Sold, Operating Expenses, Other Income, Other Expense
* Amounts are consolidated to the target subsidiary's currency.
* Only accounts with non-zero balances are included.
*
* Compatible with both OneWorld (multi-subsidiary) and standard NetSuite accounts.
*/

SELECT
a.acctnumber AS account_number,
a.accountsearchdisplaynamecopy AS account_name,
-- Alternative: For full hierarchy path (e.g., "Parent : Child : Account"), use:
-- a.fullname AS account_name,
pa.acctnumber AS parent_account_number,
a.accttype AS account_type,

/*
* FINANCIAL STATEMENT SECTIONS
* Maps NetSuite account types to standard income statement sections.
* The numbered prefixes ensure proper sort order.
*/
CASE
WHEN a.accttype = 'Income' THEN '1. Revenue'
WHEN a.accttype IN ('COGS','Cost of Goods Sold') THEN '2. Cost of Goods Sold'
WHEN a.accttype = 'Expense' THEN '3. Operating Expenses'
WHEN a.accttype = 'OthIncome' THEN '4. Other Income'
WHEN a.accttype = 'OthExpense' THEN '5. Other Expense'
END AS section,

/*
* MONTHLY COLUMNS (PIVOTED)
* Each column sums amounts for a specific month.
* Change the year (2025) in each YYYY-MM value to your desired fiscal year.
*/
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-01' THEN cons_amt ELSE 0 END) AS January,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-02' THEN cons_amt ELSE 0 END) AS February,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-03' THEN cons_amt ELSE 0 END) AS March,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-04' THEN cons_amt ELSE 0 END) AS April,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-05' THEN cons_amt ELSE 0 END) AS May,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-06' THEN cons_amt ELSE 0 END) AS June,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-07' THEN cons_amt ELSE 0 END) AS July,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-08' THEN cons_amt ELSE 0 END) AS August,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-09' THEN cons_amt ELSE 0 END) AS September,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-10' THEN cons_amt ELSE 0 END) AS October,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-11' THEN cons_amt ELSE 0 END) AS November,
SUM(CASE WHEN TO_CHAR(ap.startdate,'YYYY-MM')='2025-12' THEN cons_amt ELSE 0 END) AS December,
SUM(cons_amt) AS Total

FROM (
/*
* SUBQUERY: Calculate consolidated amounts per transaction line
* This inner query handles currency consolidation and sign conventions
* before aggregation in the outer query.
*/
SELECT
tal.account,
t.postingperiod,
TO_NUMBER(
BUILTIN.CONSOLIDATE(
tal.amount,
'LEDGER', -- Consolidation type: Uses ledger amounts
'DEFAULT', -- Accounting book: 'DEFAULT' uses primary book
'DEFAULT', -- Currency: 'DEFAULT' uses subsidiary's base currency
1, -- Subsidiary ID: Change to run for a specific subsidiary.
-- Default is 1, which is typically the parent/consolidated subsidiary.
-- For non-OneWorld accounts, this value is ignored.
-- To find your subsidiary IDs, run:
-- SELECT id, name FROM subsidiary WHERE isinactive = 'F'
t.postingperiod,
'DEFAULT' -- Exchange rate type: 'DEFAULT' uses standard rates
)
)
/*
* SIGN CONVENTION
* NetSuite stores Income/OthIncome as credits (negative).
* Multiplying by -1 converts to positive for financial reporting.
* Expense accounts are already stored as debits (positive).
*/
* CASE WHEN a.accttype IN ('Income','OthIncome') THEN -1 ELSE 1 END AS cons_amt

FROM transactionaccountingline tal
-- Link to transaction header for posting status and period
JOIN transaction t ON t.id = tal.transaction
-- Link to account for account details and type
JOIN account a ON a.id = tal.account
-- Link to accounting period for date filtering
JOIN accountingperiod apf ON apf.id = t.postingperiod

WHERE
-- Posted transactions only (excludes pending, voided, etc.)
t.posting = 'T'

/*
* ACCOUNTING BOOK FILTER
* Default: Dynamically selects the primary accounting book.
*
* To use a specific book, replace the subquery with the book ID:
* AND tal.accountingbook = 3
*
* To find your accounting book IDs, run:
* SELECT id, name, isprimary FROM accountingbook
*/
AND tal.accountingbook = (SELECT id FROM accountingbook WHERE isprimary = 'T')

-- Exclude summary periods (year totals, quarter totals)
AND apf.isyear = 'F'
AND apf.isquarter = 'F'

/*
* FISCAL YEAR FILTER
* Change '2025' to your desired year.
* Note: Must match the year used in the monthly column CASE statements above.
*/
AND TO_CHAR(apf.startdate,'YYYY') = '2025'

/*
* ELIMINATION ACCOUNT FILTER
* Excludes intercompany elimination accounts.
* These accounts are used for consolidated reporting adjustments
* and should not appear on subsidiary-level statements.
*/
AND COALESCE(a.eliminate,'F') = 'F'

/*
* ACCOUNT TYPE FILTER
* Includes only income statement (P&L) account types.
* Balance sheet accounts (Assets, Liabilities, Equity) are excluded.
*/
AND a.accttype IN (
'Income', -- Sales, service revenue
'COGS', -- Cost of Goods Sold
'Cost of Goods Sold',-- Alternative COGS designation (some accounts)
'Expense', -- Operating expenses
'OthIncome', -- Interest income, gains, etc.
'OthExpense' -- Interest expense, losses, etc.
)
) x
-- Rejoin to accounting period for month extraction in outer query
JOIN accountingperiod ap ON ap.id = x.postingperiod
-- Rejoin to account for account details in output
JOIN account a ON a.id = x.account
-- Parent account for hierarchy reporting (LEFT JOIN since top-level accounts have no parent)
LEFT JOIN account pa ON pa.id = a.parent

GROUP BY
a.acctnumber,
a.accountsearchdisplaynamecopy,
pa.acctnumber,
a.accttype

/*
* ZERO BALANCE FILTER
* Excludes accounts with no activity for the entire year.
* Remove this line to show all accounts regardless of balance.
*/
HAVING SUM(cons_amt) <> 0

ORDER BY section, a.acctnumber;

Sample Output

How the query works

Here is a simple explanation of how this version operates.

  1. Retrieving posting activity for the selected year

    The query collects posting transaction accounting lines for all P&L accounts and filters out annual and quarterly summary periods. The year is hard-coded to 2025.

  2. Always applying NetSuite’s consolidation engine

    Every transaction amount is run through BUILTIN.CONSOLIDATE, even if your account has only one subsidiary. This ensures results always match the consolidated view NetSuite would produce.

  3. Standardizing signs for income and revenue accounts

    Income and Other Income amounts are multiplied by negative one so that revenue appears as positive values.

  4. Categorizing accounts into financial statement sections

    The CASE expression assigns each account to Revenue, COGS, Operating Expenses, Other Income, or Other Expense.

  5. Summarizing each month using CASE expressions

    Each month column calculates its value by checking whether the posting period’s start date belongs to that month.

  6. Adding a total column

    The Total field sums the consolidated monthly values for each account.

  7. Filtering out rows with no activity

    The HAVING clause removes any accounts that have no activity across the year.

Did this answer your question?