fbpx
Search
Close this search box.

Excel TEXTJOIN Function – What is it, how to use it & 3 advanced examples

Share

Facebook
Twitter
LinkedIn

Use TEXTJOIN function to combine text values with optional delimiter. It is better than CONCATENATE because you can pass a range instead of individual cells and you can ignore empty cells too. Here is a sample use of TEXTJOIN Excel function.

textjoin excel function demo

TEXTJOIN Syntax & examples

To combine values in A1:A5 with comma separator, use =TEXTJOIN(",",,A1:A5) To ignore any blank values while concatenating, use =TEXTJOIN(",",TRUE, A1:A5)

TEXTJOIN Syntax: TEXTJOIN(delimiter, ignore empty values, range or list of values)

Why TEXTJOIN? Why not CONCATENATE or & operator?

  • TEXTJOIN is easy

To combine values in A1:A5 with CONCATENATE, we have to write =CONCATENATE(A1, A2, A3, A4, A5) or A1&A2&A3&A4&A5

With TEXTJOIN, you can simply say =TEXTJOIN(,,A1:A5)

  • Add delimiters

You can comma separate or add other delimiters when combining text with TEXTJOIN. While you can do the same with CONCATENATE, it becomes doubly annoying.

=TEXTJOIN(“, “,,A1:A5) gives you a comma separated text of values in A1:A5

3 Advanced TEXTJOIN uses

Here are three advanced examples of TEXTJOIN.

textjoin-combine only matching values1. Combine values that meet a criteria

Let’s say you want to combine all player names for kickers team as shown aside. You can use TEXTJOIN with IF formula to do this.

=TEXTJOIN(“, “,TRUE,IF($C$36:$C$63=”kickers”,$B$36:$B$63,””))

The inner IF function returns an array of team members or blank depending on whether they are in kickers or not. 

TEXTJOIN then ignores all blank values and returns comma seperated text.

Same formula with FILTER()

You can also use the newly introduced dynamic array function FILTER to do this job.

=TEXTJOIN(“, “,,FILTER(B36:B63,C36:C63=”kickers”))

Learn more about Excel Dynamic Array functions.

2. Reverse a text

reverse text with textjoin

You can use MID function to split a text value in to an array of characters and then reverse them with TEXTJOIN.

For example, below formula reverses “Chandoo”

=TEXTJOIN(,,MID(“Chandoo”,21-ROW($A$1:$A$20),1))

It works up to 20 letters.

How does it work?

MID(“Chandoo”,21-ROW($A$1:$A$20),1) portion returns an array of 20 items {“”;””;””;””;””;””;””;””;””;””;””;””;””;”o”;”o”;”d”;”n”;”a”;”h”;”C”}

This is then combined by TEXTJOIN to return 00dnahC

3. Substitution cipher with TEXTJOIN

substitution cipher with textjoinWant to communicate in a secret code with your colleague? You can use substitution cipher to map each letter with another letter of alphabet. 

We can use either XLOOKUP or VLOOKUP with TEXTJOIN to encrypt text values like this.

Imagine you have a mapping table as shown aside.  

To convert a message in cell H92, use this formula

=TEXTJOIN(,,XLOOKUP(MID(H92,ROW($A$1:$A$20),1),subs[Normal], subs[Code],””))

How does it work?

Using the MID() function, we split the text in H92 into an array of 20 values, one per character.

We then pass these letters to XLOOKUP to find matching [Code] from the subs table.

All these values are finally combined by TEXTJOIN to generated our coded message.

What the function - TEXTJOIN in Excel video

I recently started a series of videos on my Youtube channel to demystify Excel functions. This series is named What the function. Watch below WTF tutorial on TEXTJOIN to learn how to use it.

Click here for full WTF playlist.

Download TEXTJOIN Example Workbook

Click here to download the TEXTJOIN example file. Use the sample data and formulas to understand TEXTJOIN function better. Play with the data to create something cool on your own and post your TEXTJOIN ideas in the comments.

TEXTJOIN in use - Excel Risk Map

Excel Risk Map TemplateIf you want to get some inspiration on how TEXTJOIN can be a force of good, see this Excel risk map. It uses TEXTJOIN to show risks in a matrix format.

 

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Excel School made me great at work.
5/5

– Brenda

Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

Weighted Average in Excel with Percentage Weights

Weighted Average in Excel [Formulas]

Learn how to calculate weighted averages in excel using formulas. In this article we will learn what a weighted average is and how to Excel’s SUMPRODUCT formula to calculate weighted average / weighted mean.

What is weighted average?

Wikipedia defines weighted average as, “The weighted mean is similar to an arithmetic mean …, where instead of each of the data points contributing equally to the final average, some data points contribute more than others.”

Calculating weighted averages in excel is not straight forward as there is no built-in formula. But we can use SUMPRODUCT formula to easily calculate them. Read on to find out how.

2 Responses to “Excel TEXTJOIN Function – What is it, how to use it & 3 advanced examples”

  1. Daniel Dion says:

    How about SEQUENCE(20,,20,-1) instead of 21-ROW($A$1:$A$20) giving us a more robust formula

Leave a Reply