• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Power Query Transform: Header Rows Repeat Until Next Header Adjacent column|Power Query|Excel Forum|My Online Training Hub

You are here: Home / Power Query Transform: Header Rows Repeat Until Next Header Adjacent column|Power Query|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumPower QueryPower Query Transform: Header Rows …
sp_PrintTopic sp_TopicIcon
Power Query Transform: Header Rows Repeat Until Next Header Adjacent column
Avatar
Steven Vaughan
Member
Members
Level 0
Forum Posts: 12
Member Since:
January 5, 2022
sp_UserOfflineSmall Offline
1
March 22, 2022 - 9:00 pm
sp_Permalink sp_Print sp_EditHistory

I think this is possible but I have no idea how to accomplish this.  What I am trying to do is repeat a row.  If you look under, the second screenshot below line description column, you will see headers like Salaires & Wages.  They are always identified as LineSubSequence 0 and maybe this is the key.  Is there a way to make the Salaries and Wages go on every single line blow the subaccounts until it reaches the next header row which in this case be Benefits?  I hope I am making good sense of this description.

 

So it would look like this:

BEFORE:

     
     
     
Salaries & Wages    
6005000000 Productive Wages  
6005050000 Productive Premium  
6025000000 CTO Wages  
6025050000 CTO_COB Payout  
6040000000 Non-Productive Wages  
     
     
AFTER:    
Salaries & Wages 6005000000 Productive Wages
Salaries & Wages 6005050000 Productive Premium
Salaries & Wages 6025000000 CTO Wages
Salaries & Wages 6025050000 CTO_COB Payout
Salaries & Wages 6040000000 Non-Productive Wages

 

thumbnail image 1 of blog post titled 
	
	
	 
	
	
	
				
		
			
				
						
							PowerQuery Help
							
						
					
			
		
	
			
	
	
	
	
	
Image Enlarger

sp_AnswersTopicSeeAnswer See Answer
Avatar
Alan Sidman
Steamboat Springs, CO
Member
Members


Trusted Members
Level 0
Forum Posts: 132
Member Since:
October 18, 2018
sp_UserOfflineSmall Offline
2
March 23, 2022 - 8:40 am
sp_Permalink sp_Print

let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type1" = Table.TransformColumnTypes(Source,{{"Salaries & Wages", type text}}),
#"Demoted Headers" = Table.DemoteHeaders(#"Changed Type1"),
#"Added Custom" = Table.AddColumn(#"Demoted Headers", "Custom", each if Text.Contains([Column1],"Salaries") then [Column1] else null),
#"Filled Down" = Table.FillDown(#"Added Custom",{"Custom"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([Column1] <> "Salaries & Wages")),
#"Reordered Columns" = Table.ReorderColumns(#"Filtered Rows",{"Custom", "Column1", "Column2"})
in
#"Reordered Columns"

Avatar
Riny van Eekelen
Örnsköldsvik, Sweden
Moderator
Members


Trusted Members

Moderators

Power BI
Level 0
Forum Posts: 440
Member Since:
January 31, 2022
sp_UserOfflineSmall Offline
3
March 23, 2022 - 9:15 pm
sp_Permalink sp_Print

As a variant and assuming you want to apply this not only to areas in the table (referring to the screenshot) where the header contains the word "Salaries".

let
Source = Excel.CurrentWorkbook(){[Name="myData"]}[Content],
#"Added Custom" = Table.AddColumn(Source, "Custom", each if [Column2] is null then [Column1] else null),
#"Filled Down" = Table.FillDown(#"Added Custom",{"Custom"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([Column2] <> null)),
#"Reordered Columns" = Table.ReorderColumns(#"Filtered Rows",{"Custom", "Column1", "Column2"})
in
#"Reordered Columns"

Screenshot-2022-03-23-121229.pngImage Enlarger

sp_PlupAttachments Attachments
  • sp_PlupImage Screenshot-2022-03-23-121229.png (21 KB)
Avatar
Steven Vaughan
Member
Members
Level 0
Forum Posts: 12
Member Since:
January 5, 2022
sp_UserOfflineSmall Offline
4
March 23, 2022 - 9:24 pm
sp_Permalink sp_Print

Hi Alan, First of all thank you for your response but I think I have not done a good job explaining this.  It is not only Salaries and Wages it will contain many other expense and revenue categories.  Please see below.  I do apologize but I am super new in PowerQuery and probablyl my lack of experience is hindering my exlanation and what you need.  Can I provide more information somehow to make my help request better?

 

Salaries & Wages
6005000000
6005050000
6025000000
6025050000
6040000000
6041000000
Total Salaries & Wages
Benefits
6102000000
6104020000
6104060000
6106000000
6108000000
6202000000
6206020000
6214000000
Total Benefits
Fees
7202000000
7210000000
7222000000
Total Fees
Utilities
6302000000
Total Utilities
Supplies - Medical
7602000000
Total Supplies - Medical
Supplies - Other
7402000000
7422000000
7424000000
7426000000
7426020000
Total Supplies - Other
Purchased Services
Avatar
Steven Vaughan
Member
Members
Level 0
Forum Posts: 12
Member Since:
January 5, 2022
sp_UserOfflineSmall Offline
5
March 23, 2022 - 9:34 pm
sp_Permalink sp_Print sp_EditHistory

PPQ.pngImage Enlarger

Riny, I placed the formula in but it says it cannot find the excel table.  I tried both MyData nd PS Detailed.  I think maybe it is how I am pulling in the table perhaps.  I added the screnshot so maybe it can offer some clues.  It is a connection to an SQL Server, in the database name PMReporting_Work and it its grabbing table PS Detailed.  Sorry guys I am just so new this and I am probablly frustrating some people.  I hope to get better at PowerQuery.

 

Expression.Error: We couldn't find an Excel table named 'MyData'. 

OR

Expression.Error: We couldn't find an Excel table named 'PS Detailed'.

sp_PlupAttachments Attachments
  • sp_PlupImage PPQ.png (61 KB)
sp_AnswersTopicAnswer
Answers Post
Avatar
Riny van Eekelen
Örnsköldsvik, Sweden
Moderator
Members


Trusted Members

Moderators

Power BI
Level 0
Forum Posts: 440
Member Since:
January 31, 2022
sp_UserOfflineSmall Offline
6
March 23, 2022 - 11:09 pm
sp_Permalink sp_Print sp_EditHistory

The Source step and Column names used in the query are subject to your own data structure. It it's a structured table, use the correct table name. In my example I used a named range called myData (with a small m) and without headers. So it landed in PQ with two columns called Column1 and Column2.

So, just connect to the source as you normally would and when you get to the point that you want to add the custom column, make sure that the #"Added Custom" step is referring to the correct column names, whatever these are at this point in the query.

You can follow it step-by-step in the file I uploaded with my first answer.

Avatar
Steven Vaughan
Member
Members
Level 0
Forum Posts: 12
Member Since:
January 5, 2022
sp_UserOfflineSmall Offline
7
March 25, 2022 - 9:06 pm
sp_Permalink sp_Print sp_EditHistory

How-Data-is-Pulled-in.pngImage Enlarger

PQ-Help.pngImage Enlarger
PQError.pngImage Enlarger
Hi Riny,

I am sorry but I just cannot get it to work.  It must be something trivial that I am missing.

I think I fixed the connection to the table issue by adjusting as follows but now I am getting an error saying that the subaccount column was not found. 

let
Source = Sql.Database("vwp-fi-", "PMReporting_Work"),
#"dbo_PS Detailed" = Source{[Schema="dbo",Item="PS Detailed"]}[Data],
#"Added Custom" = Table.AddColumn(Source, "Custom", each if [Subaccount Description] is null then [Subaccount] else null),
#"Filled Down" = Table.FillDown(#"Added Custom",{"Custom"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([Line_Description_Desc] <> null)),
#"Reordered Columns" = Table.ReorderColumns(#"Filtered Rows",{"Custom", "Subaccount", "Subaccount Description"})
in
#"Reordered Columns"

Sorry I am doing my best I just cant seemt o figure it out.  I changed the two column names so its easier to distinguish.  I tried to put in as much detail for you to see and hopefully it is something you can spot off the bat.

Thank you for your patientce with me.

sp_PlupAttachments Attachments
  • sp_PlupImage How-Data-is-Pulled-in.png (246 KB)
  • sp_PlupImage PQ-Help.png (429 KB)
  • sp_PlupImage PQError.png (20 KB)
Avatar
Riny van Eekelen
Örnsköldsvik, Sweden
Moderator
Members


Trusted Members

Moderators

Power BI
Level 0
Forum Posts: 440
Member Since:
January 31, 2022
sp_UserOfflineSmall Offline
8
March 26, 2022 - 10:09 pm
sp_Permalink sp_Print

I can't really relate the error message to the script you copied into your message, but are you sure that the column name is really "Subaccount" at this stage? Two steps down you refer to [Line_Description_Desc] which, based on your first message seems to contain what you now refer to as [Subaccount]. Make sure that the column names are indeed as included in the previous step. Attaching a file with my mockup that looks a bit like yours now.

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online:
Guest(s) 11
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
John Chisholm
vexokeb sdfg
John Jack
Malcolm Toy
Ray-Yu Yang
George Shihadeh
Naomi Rumble
Uwe von Gostomski
Jonathan Jones
drsven
Forum Stats:
Groups: 3
Forums: 24
Topics: 6212
Posts: 27236

 

Member Stats:
Guest Posters: 49
Members: 31888
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.