Ever wanted to make a random sentence or text? You can use Excel formulas to make totally random sentences. This is a great way to generate test data or dummy data-sets.
There are two ways to make the random sentences. You can use dynamic arrays in Excel 365 or regular functions in older versions.
Random sentences formula – Excel 365 with dynamic arrays
See next section if you are using older versions of Excel (2016 / 2013 etc.)
A random sentence is nothing but random string made of alphabets & punctuation. For sake of simplicity, let’s limit the character set to {a..z}, space and period.
The formula
=SUBSTITUTE( SUBSTITUTE( CONCAT( CHAR( RANDARRAY(120,1,97,124,TRUE) )), "{",". ") ,"|"," ")
How random sentence formula works?
Let’s go from inside.
RANDARRAY(120,1, 97,124, TRUE): This dynamic array function generates a list of 120 random integers between 97 and 124.
Wait a sec… what the function is RANDARRAY?
RANDARRAY is a part of newly introduced dynamic array functions in Excel 365. This function, just like other DA functions (FILTER, UNIQUE, SORT etc.) can generate an array of items and spill them out on the spreadsheet.
Read up more about RANDARRAY function.
Why 97 and 124?
Because 97 stands for “a” in computer code and 122 stands for “z” in computer code (ASCII code). We need two more numbers for SPACE and PERIOD.
CHAR(RANDARRAY(..)): This will turn the random numbers in to equivalent letters (a to z { and |)
CONCAT(CHAR(…)): This concatenates all the letters to one giant 120 letter string.
SUBSTITUTE(CONCAT(…), “{“, ” “): This replaces all { with SPACE.
SUBSTITUTE(…, “|”, “. “): This replaces all | with PERIOD-SPACE.
The result
We will end up with a random sentence. Just recalc (F9) to make a new sentence.
Lorem ipsum with Excel formulas – All versions
What if you don’t have RANDARRAY? Well, you can a simple formula to generate standing typesetting text – Lorem ipsum…
Lorem ipsum formula
First place the sample “Lorem ipsum” paragraph in a cell, say F6. You can download the entire paragraph from lipsum.com. Alternatively, you will find this in the sample Excel file too.
Now use below formula to fetch random words (between 9 to 16) from the text.
=LEFT($F$6, FIND("#", SUBSTITUTE($F$6," ","#",RANDBETWEEN(9,16))))
How this formula works?
This formula is a lot simpler than the RANDARRAY based one.
Going from inside,
- RANDBETWEEN(9,16) generates a random number
- SUBSTITUTE replaces that random space with # symbol
- FIND gets the location of #
- LEFT returns the words in F6 from left until it found that # symbol
Random Sentence Formulas – Explained
In case you are still foggy about the details of these formulas, check out below video. You can also watch it on my Youtube channel.
Download sample file – Random sentence formula
Click here to download the sample file to make random sentences. Examine the formulas to learn more about RANDARRAY, CONCAT, SUBSTITUTE, FIND and CHAR functions.
3 Responses to “Make a random sentence with Excel formulas”
Very Nice Blog. It is really worth Reading it trick to create random sentences through excel formulas. Thanks for Sharing this.
Does not say how to place the formula. Like most tech trainers you assume that people already know how to do the things you are teaching them.
=LEFT($F$6,
FIND("#",
SUBSTITUTE($F$6," ","#",RANDBETWEEN(9,16))))
Where? How? What do I do?
Tech trainers are the worst trainers on the planet.
Did you watch the video where everything is explained clearly? Also, did you conduct a survey or scientific study of all trainers on planet to come up with this conclusion?