Current Quarter vs Previous Quarter

jimrward

Well-known Member
Joined
Feb 24, 2003
Messages
1,896
Office Version
  1. 2021
  2. 2019
  3. 2016
  4. 2013
  5. 2011
  6. 2010
  7. 2007
  8. 2003 or older
Platform
  1. Windows
My raw data consists of date, year, qtr, mydata1, mydata2,mydata3 etc from which I currently extract all of the data regardless of time period
what I would like to do is extract data for the current quarter, and also the previous quarter I dont mind if it’s separate sheets
as I want to compare the scores and give a placing update up,down, same

the main problem is how to handle quarters when it is Q1, the easy option as the data is from 2019 to current is have a lookup to find current quarter and choose line before. Saves having to say if Q1 then year-1,Q4
can a power query do a lookup and use cell contents as a criteria in a query
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
If the source table is sorted by year and quarter as it is supposed to be then you can add an index column, and use Table.AddColumn() function with a function to get the previous row's data (this could be also done by using the interface only).
Power Query:
let
    // Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("VdBBDsUgCEXRvTBuAg+12mX8sen+t1HA2nwm2OQk3sqcBAar0EEqcfxgA0L3Malyy6bxHdb5ylZslGUQhmatNuqrDLsWC7GTbSdVMnrz3E2tGT3av6j2rB4dO1rM1//HEdFrYfN3/pvGDhYOHhm9iXdDsMcgs0fhS7of", BinaryEncoding.Base64), Compression.Deflate)), type table [Date, Year, Quarter, Data]),

    // Add an index column starting from 0
    Indexed = Table.AddIndexColumn(Source, "Index", 0, 1, Int64.Type),
    // Add anonther column to get the previous row data
    AddColumn = Table.AddColumn(Indexed, "Previous Quarter", each Indexed{[Index] - 1}[Data]),
    // Replace the first row value which will be an error (no previous quarter) 
    ReplaceError = Table.ReplaceErrorValues(AddColumn, {{"Previous Quarter", "0"}}),
    // Remove the index column
    Result = Table.RemoveColumns(ReplaceError,{"Index"})
in
    Result

Result:
DateYearQuarterDataPrevious Quarter
1/1/202020Q1100
4/5/202020Q22010
7/9/202020Q33020
10/12/202020Q44030
1/15/212021Q15040
4/20/212021Q26050
7/24/212021Q37060
10/27/212021Q48070
1/30/222022Q19080
5/5/222022Q210090
8/8/222022Q3110100
11/11/222022Q4120110

Unlikely, but let's say the data is not sorted properly, then we can search for the previous quarter by providing year and quarter value for each row. I know this won't be the case, and actually the data could be also sorted properly in M before the actual transformation but I'd like to demostrate a filter table method as well.
Power Query:
let
    // Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("VdBBDsUgCEXRvTBuAg+12mX8sen+t1HA2nwm2OQk3sqcBAar0EEqcfxgA0L3Malyy6bxHdb5ylZslGUQhmatNuqrDLsWC7GTbSdVMnrz3E2tGT3av6j2rB4dO1rM1//HEdFrYfN3/pvGDhYOHhm9iXdDsMcgs0fhS7of", BinaryEncoding.Base64), Compression.Deflate)), type table [Date, Year, Quarter, Data]),

    // Add a new column for the previous quarter data
    PreviousQ = Table.AddColumn(Source, "Previous", each
        let
            // Current year from the current row
            CurrentY = [Year],
            // Current quarter from the current row
            CurrentQ = [Quarter],
            // Extract quarter index from the quarter string
            CurrentIndex = Number.From(Text.Range(CurrentQ, 1)),
            // Find the row where year and quarter according to current year and quarter.
            // Not that it is different calculation if the current quarter is Q1 
            Previous = if CurrentIndex = 1 then [Year = Text.From(Number.From(CurrentY) - 1), Quarter = "Q4"]
                else [Year = CurrentY, Quarter = "Q" & Text.From(CurrentIndex - 1)],
            // Return the found row (it is supposed to be a single row)
            Result = Table.SelectRows(Source, each ([Year] = Previous[Year]) and ([Quarter] = Previous[Quarter]))
        in
            Result
    ),
    // Expand the newly added column that contains the single row table
    Result = Table.ExpandTableColumn(PreviousQ, "Previous", {"Data"}, {"Previous.Data"})
in
    Result

Same result.
Note: I used sample data to make it easy to test. Simply copy and paste it into the advanced editor.
 
Upvote 0

Forum statistics

Threads
1,223,939
Messages
6,175,530
Members
452,651
Latest member
wordsearch

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top