The PIVOTBY function allows you to create a summary of your data via a formula. It supports grouping along two axis and aggregating the associated values. For instance, if you had a table of sales data, you might generate a summary of sales by state and year.

Note: Though it can produce similar outputs, PIVOTBY is not directly related to Excel's PivotTable feature. 

Syntax

The PIVOTBY function allows you to group, aggregate, sort, and filter data based on the row and column fields that you specify.

The syntax of the PIVOTBY function is:

PIVOTBY(row_fields,col_fields,values,function,[field_headers],[row_total_depth],[row_sort_order],[col_total_depth],[col_sort_order],[filter_array],[relative_to])

​​​​​​​

Argument

Description

row_fields

(required)

A column-oriented array or range that contains the values which are used to group rows and generate row headers. 

The array or range may contain multiple columns. If so, the output will have multiple row group levels.

col_fields

(required)

A column-oriented array or range that contains the values which are used to group columns and generate column headers. 

The array or range may contain multiple columns. If so, the output will have multiple column group levels. 

values

(required)

A column-oriented array or range of the data to aggregate.

The array or range may contain multiple columns. If so, the output will have multiple aggregations.

function

(required)

A lambda function or eta reduced lambda (SUM, AVERAGE, COUNT, etc) that defines how to aggregate the values.

A vector of lambdas can be provided. If so, the output will have multiple aggregations. The orientation of the vector will determine whether they are laid out row- or column-wise.

field_headers

A number that specifies whether the row_fieldscol_fields and values have headers and whether field headers should be returned in the results. The possible values are:

Missing: Automatic. 0: No 1: Yes and don't show 2: No but generate3: Yes and show

Note: Automatic assumes the data contains headers based on the values argument. If the 1st value is text and the 2nd value is a number, then the data is assumed to have headers. Fields headers are shown if there are multiple row or column group levels.

row_total_depth

Determines whether the row headers should contain totals. The possible values are:

Missing: Automatic: Grand totals and, where possible, subtotals.0: No Totals1: Grand Totals2: Grand and Subtotals-1: Grand Totals at Top-2: Grand and Subtotals at Top 

Note: For subtotals, row_fields must have at least 2 columns. Numbers greater than 2 are supported provided row_field has sufficient columns.

row_sort_order

A number indicating how columns should be sorted. Numbers correspond with columns in row_fields followed by the columns in values. If the number is negative, the rows are sorted in descending/reverse order.

A vector of numbers can be provided when sorting based on only row_fields

col_total_depth

Determines whether the column headers should contain totals. The possible values are:

Missing: Automatic: Grand totals and, where possible, subtotals.0: No Totals1: Grand Totals2: Grand and Subtotals-1: Grand Totals at Top-2: Grand and Subtotals at Top 

Note: For subtotals, col_fields must have at least 2 columns. Numbers greater than 2 are supported provided col_field has sufficient columns.

col_sort_order

A number indicating how rows should be sorted. Numbers correspond with columns in col_fields followed by the columns in values. If the number is negative, the rows are sorted in descending/reverse order.

A vector of numbers can be provided when sorting based on only col_fields

filter_array

A column-oriented 1D array of Booleans that indicate whether the corresponding row of data should be considered.

Note: The length of the array must match the length of those provided to row_fields and col_fields

relative_to

When using an aggregation function that requires two arguments,  relative_to controls which values are provided to the 2nd argument of the aggregation function. This is typically used when PERCENTOF is supplied to function.

The possible values are:

0: Column Totals (Default)1: Row Totals2: Grand Totals3: Parent Col Total4: Parent Row Total 

Note: This argument only has an impact if function requires two arguments. If you supply a custom lambda function to function, it should follow this pattern: LAMBDA(subset,totalset,SUM(subset)/SUM(totalset)) 

Examples

Example 1: use PIVOTBY to generate a summary of total sales by product and year.

Using PIVOTBY to generate a summary of total sales by product and year. The formula reads: =PIVOTBY(C2:C76,A2:A76,D2:D76,SUM)

Example 2: use PIVOTBY to generate a summary of total sales by product and year. Sort descending by sales.

Example of the PIVOTBY function to generate a summary of total sales by product and year. The formula is =PIVOTBY(C2:C76,A2:A76,D2:D76,SUM,,,-2)

Need more help?

Want more options?

Explore subscription benefits, browse training courses, learn how to secure your device, and more.

Communities help you ask and answer questions, give feedback, and hear from experts with rich knowledge.