Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
hdhillon
Advocate III
Advocate III

Replace non blanks with 1

All,

 

In Power Query, How do I replace all non blanks with 1

 

I have tried the Excel Find and Replace method of   *  to   1 

However this does not seem to work in Power BI

 

 

1 ACCEPTED SOLUTION
edhans
Super User
Super User

Hi @hdhillon , try this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSi/KLy1QMFTSUQJhUwOlWB10QUMDrKLmpmiiRljVGuMUNUIRNYKai2KsEZoTgEwQAjETi1PSYNxYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Group = _t, Month = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", Int64.Type}, {"Month", Int64.Type}}),
    #"Replaced Value" = 
        Table.ReplaceValue(
            #"Changed Type",
            each [Group],
            each
                let
                    varReplacementValue = if Text.Length([Group]) > 0 then "1" else [Group]
                in
            varReplacementValue,
            Replacer.ReplaceText,
            {"Group"}
        )
in
    #"Replaced Value"

It turns this:

edhans_0-1604946596158.png

Into this:

edhans_1-1604946621629.png

It looks for any field that has a length greater than 0 and replaces that field with "1" if it does.

 

How to use M code provided in a blank query:
1) In Power Query, select New Source, then Blank Query
2) On the Home ribbon, select "Advanced Editor" button
3) Remove everything you see, then paste the M code I've given you in that box.
4) Press Done
5) See this article if you need help using this M code in your model.

 

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

View solution in original post

6 REPLIES 6
Lon7171
New Member

I had this issue as well where I wanted to replace dates with 1 and leave null values. I converted the dates to whole numbers then I added a custom column and divided the whole number by itself giving a 1 for the date values and null for null values.

Hi @Lon7171, you could do something like this:

 

Before

dufoq3_0-1723986737459.png

 

After

dufoq3_1-1723986749292.png

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwMtE1MAQipVgdJK4RKtcYzEUQcAkzpdhYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t]),
    ChangedType = Table.TransformColumnTypes(Source,{{"Date", type date}}),
    ReplacedDate = Table.TransformColumns(ChangedType, {{"Date", each if _ <> null then 1 else null, Int64.Type}})
in
    ReplacedDate

Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

Anonymous
Not applicable

Powerquery

= IFERROR(IF(LEN(related(column_name))>0,"Y","-"),"-")

Anonymous
Not applicable

I know you said replace, but you could easily add a column like this:

Table.AddColumn(PriorStep, "NewColumnName", each if [Column] <> null then 1 else [Column], type number)

wdx223_Daniel
Super User
Super User

@hdhillon click the wdx223_Daniel_0-1605167304579.pngbutton beside the Edit Bar and input this formula

=Table.ReplaceValue(LastStepName,null,1,(x,y.z)=>if x=y or x="" then x else z,Table.ColumnNames(LastStepName))

LastStepName, is the last step name in your original M code

 

edhans
Super User
Super User

Hi @hdhillon , try this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSi/KLy1QMFTSUQJhUwOlWB10QUMDrKLmpmiiRljVGuMUNUIRNYKai2KsEZoTgEwQAjETi1PSYNxYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Group = _t, Month = _t, Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", Int64.Type}, {"Month", Int64.Type}}),
    #"Replaced Value" = 
        Table.ReplaceValue(
            #"Changed Type",
            each [Group],
            each
                let
                    varReplacementValue = if Text.Length([Group]) > 0 then "1" else [Group]
                in
            varReplacementValue,
            Replacer.ReplaceText,
            {"Group"}
        )
in
    #"Replaced Value"

It turns this:

edhans_0-1604946596158.png

Into this:

edhans_1-1604946621629.png

It looks for any field that has a length greater than 0 and replaces that field with "1" if it does.

 

How to use M code provided in a blank query:
1) In Power Query, select New Source, then Blank Query
2) On the Home ribbon, select "Advanced Editor" button
3) Remove everything you see, then paste the M code I've given you in that box.
4) Press Done
5) See this article if you need help using this M code in your model.

 

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.