I need to create a lot of sample data for tutorials and courses. One of the things that I needed for a recent course I am building was to generate a column containing dummy passwords in Google Sheets. Each password needed to consist of letters, numbers and characters.
Until recently, this task would have been relegated to Google Apps Script.
However, with the recent introduction of the LAMBDA function (Well, at the time of writing this anyway), we can do so much more with our Google Sheets.
Before we dive into the formula, it’s important to understand that these ‘passwords’ or random strings of characters are dynamically generated. This means every time you update a cell or reload your Google Sheet the characters in each cell will change.
So once you generate your passwords, copy the range and paste the values back in (Ctrl + c, Ctrl + Shift + v). This way only the values remain.
If you just want to grab the formula and be on your way, you can copy it from the section below. However, if you want to learn how it all works, read on for a breakdown.
The Password Maker Formula
Note in the formulas below there are three parameters that you can change:
- [NumChars]: The number of characters in each string in each cell.
- [NumRows]: The number of rows to produce the random string of characters in.
- [NumCols]: The number of columns to produce the random string of characters in.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 |
=MAKEARRAY( [NumRows], [NumCols], LAMBDA( row_index, column_index, JOIN( "", MAP( SEQUENCE(1,[NumChars]), LAMBDA( cell, MID( "0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz~`!@#$%^&*()_-+{[}]|\:;<,>.?/", RANDBETWEEN(1,91), 1 ) ) ) ) ) ) |
Replace the items in the square [] braces with your own values.
For example, if we wanted to generate a matrix of passwords 4 rows deep, 5 columns wide and with each cell containing 12 random characters we would do this:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 |
=MAKEARRAY( 4, 5, LAMBDA( row_index, column_index, JOIN( "", MAP( SEQUENCE(1,12), LAMBDA( cell, MID( "0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz~`!@#$%^&*()_-+{[}]|\:;<,>.?/", RANDBETWEEN(1,91), 1 ) ) ) ) ) ) |
Use just numbers, numbers and letters, etc.
To quickly change the formula to produce only a certain subset of characters, you will need to delete the desired characters from the string contained in the MID function on line 14 of the example above.
You will also need to change the second argument of the RANDBETWEEN function to the length of your new string of characters.
Hint! You can quickly count the string of characters by copying the characters in the formula (including the double quotation marks on each end) and pasting it inside a LEN function. For example:
=LEN("GOAT!1234") = 9
Check out the sample sets below and their letter lengths for convenience.
Name | Character Set | Length |
---|---|---|
Numbers | “0123456789” | 1o |
Letters UPPER |
“ABCDEFGHIJKLMNOPQRSTUVWXYZ” | 26 |
Letters lower |
“abcdefghijklmnopqrstuvwxyz” | 26 |
Letters UPPER and lower |
“ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz” | 52 |
Alphanumeric UPPER |
“0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ” | 36 |
Alphanumeric lower |
“0123456789abcdefghijklmnopqrstuvwxyz” | 36 |
Alphanumeric UPPER & lower |
“0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz” | 62 |
Characters only | “~!@#$%^&*()_-+{[}]|\:;<,>.?/" |
29 |
Formula Breakdown
In this section, we will walk through the process of creating the random string generator. Not only does this help to provide an understanding of how the formula works, but it also gives you some insight into a good workflow for building your own complex formulas in Google Sheets.
The Video
The Starter Sheet - To Play Along
If you want to get hands-on to make things more fun, grab the starter sheet from here:
RANDOM STRINGS - Starter Sheet
I'll be referring to locations in the starter sheet as a part of the walkthrough below.
The Character List
Our character list is as follows:
0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz~
!@#$%^&*()_-+{[}]|\:;<,>.?/
Place the list in a separate cell so you can reference it during testing. In the example (The Starter Sheet), I have added this to cell B2.
If you want to learn how to create a character list with a formula check out the tutorial below:
5 ways to create an ordered alphanumeric list in Google Sheets
Get the length of characters
The first thing we need to do is get the total number of characters in our list. This number will be used in another formula later.
We can do this quickly with the LEN function which gets the length of a string.
In our example I reference the string in cell B2 and apply LEN to it:
= LEN(B2) = 91
Select a Random Character from the String
RANDBETWEEN
We can select a random number from between 1 and 91 with the RANDBETWEEN function.
Check out this tutorial for an advanced use of RANDBETWEEN Skewed Random Range in Google Sheets (RANDBETWEEN)
This function takes two arguments, the starting value and the end value. Let’s input our range:
=RANDBETWEEN(1,91) = A random number between 1 and 91
It will dynamically return a random value between 1 and 91.
Note! The Google Sheets RANDBETWEEN function updates dynamically. This means that every time you apply a change to your sheet the random number will change.
MID
We can then use the MID function to find a character in the string at a designated position. For us, this position will be determined by the number that our RANDBETWEEN function returns.
MID takes 3 variables:
- The reference string or cell.
- The start index in the cell that contains the string.
- The length of characters to extract.
So in our example, our formulas would look like this:
=MID(B1, RANDBETWEEN(1,91),1) = A random character from our string.
Where B1 in our example is the string of characters.
You can see in the example above that the formula randomly selected the pipe (|
) characters from the string in B1.
Set a Sequence of n Columns
Let’s work on another part of the formula now. We need a way to create a string of random characters at any length we desire – we’ll call this n.
The first part of this process is to generate a row that is n cells wide.
This can be achieved with the SEQUENCE function. With this function, we can generate a range or matrix of values at any row or column width.
The SEQUENCE function takes 4 arguments:
- Number of rows: For us, this will always be 1.
- Number of columns: We will assign our desired n length here.
- The Starting value (optional): This will always be 1 in our formula.
- The Step between each value (optional): This will also always be one in our formula.
Let’s say we want to create a formula one row deep and five columns across:
=SEQUENCE(1, 5, 1, 1) = Array [1, 2, 3, 4, 5]
Map a Random Character to Each Sequence Item
Now that we have our sequence, we can map a random character to each item in the sequence. To do this we use the Google Sheets MAP function. This is a helper function of the LAMBDA function set.
The MAP function allows you to traverse an array and modify each item in the array. For us, we are going to apply a random character to each item in the sequence we generated.
MAP can take a number of arrays or ranges as its first argument and then a LAMBDA function as its last argument.
The nested LAMBDA array takes an iterator item argument. This represents the current cell the item is modifying as it works through each item in the range. We need to add this argument even if we don’t use it in our formula.
The second LAMBDA argument is the formula expression. That is, what we are doing to change the value in each of the cells.
=MAP(array,LAMBDA(iterator argument, formula expression)
For us, our first argument is our SEQUENCE, and our formula expression is our MID-RANDBETWEEN combo.
=MAP(SEQUENCE(1,5),LAMBDA(cell, MID(B1,RANDBETWEEN(1,91),1)))
Note that we can always change the second argument of the SEQUENCE to change the number of columns containing random characters.
Join the array of random characters into one password string
We can combine our random character array into a single string of characters to generate a password with the JOIN function.
JOIN takes two arguments:
- The delimiter – This is the value we want to use to separate each cell item when we combine it into a string. In our example, we don’t want to separate the characters so we will leave this as an empty string.
- The array – This will be the array we generated in the previous section.
=JOIN(delimiter, array)
=JOIN("",MAP(SEQUENCE(1,5),LAMBDA(cell, MID(B1,RANDBETWEEN(1,91),1))))
If you just want a single password, then this is a pretty good place to stop, but if you want a bunch of passwords across columns and rows, read on.
Generate an Array of Passwords
We can use another LAMBDA helper function for us to create an array n rows deep by n rows wide. To do this we can the MAKEARRAY function.
As the name suggests, MAKEARRAY generates a 2-dimensional array of data generated by whatever is in the contained LAMBDA function.
MAKEARRAY takes three arguments:
- Number of Rows: How many passwords deep that we want to run.
- Number of Columns: The total number of passwords we want to run across our Google Sheet.
- The LAMBDA function: The MAKEARRAY lambda function also requires three arguments:
- The Row Argument: We won’t use this or the Column argument, but they are mandatory for a MAKEARRAY function. We’ll call this argument row_index.
- The Column Argument: Again, this is not needed for our password maker, but we will name this argument column_index.
- Formula Expression: Here we can insert our password generate from the previous section.
We will also add the string data now into our entire formula. We don’t need to keep it separate.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 |
=MAKEARRAY( 5, 2, LAMBDA( row_index, column_index, JOIN( "", MAP( SEQUENCE(1,5), LAMBDA( cell, MID( "0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz~`!@#$%^&*()_-+{[}]|\:;<,>.?/", RANDBETWEEN(1,91), 1 ) ) ) ) ) ) |
In the example above we have created an array two columns wide and five columns deep with a random password length of 5 characters (See the second argument of the SEQUENCE)..
Conclusion
This password generator is a really helpful tool for templating spreadsheets to create examples or quickly generate a password or random string of characters for codes.
As we mentioned above, the passwords will change each time you update the sheet. The best solution to provide a static password would be to use a bit of Google Apps Script Magic connected to an onEdit()
function similar to this tutorial:
If you have found the tutorial helpful, why not shout me a coffee ☕? I'd really appreciate it.
Did you enjoy the tutorial? Want to upskill and get a solid step-by-step course to become a pro at Google Sheets? Check out my course, Google Sheets: Learn the Essentials with Three Detailed Projects. Sign up today.
~ Yagi