Data Studio + BigQuery + GA4: Viewing a Parameter Across Multiple Events

Sometimes you have multiple actions (with separate event names) that share a common parameter. This post will allow you to view how frequently each event occurred by the value of your event parameter.
Contents
Let’s Start with an Example
Imagine that you have an app that contains courses (like LinkedIn Learning, or Coursera). When a user interacts with a course they might create multiple events, such as: “course_viewed”, “course_started” and “course_completed”. Each of those events might contain a parameter called “course_name”.
So, as an Analyst, you might need to create a conversion funnel that displays how many users viewed, started and completed each course. I like to visualize this with a stacked bar chart so that it sort of looks like a funnel, which requires the data to look like this:
Course_Name | Event_Name | Unique_Users |
---|---|---|
Algebra | course_viewed | 100 |
Algebra | course_started | 65 |
Algebra | course_completed | 45 |
Trigonometry | course_viewed | 110 |
Viewing a Parameter Across Multiple Events in BigQuery
To generate this table in BigQuery, you will need to use the UNNEST operator on the event_params column. If you’re familiar with UNNEST you can keep reading, but if this concept is new to you then you’ll want to take a look at my post on How to Flatten a BigQuery Table with UNNEST.
Here is what it looks like in BigQuery:
1SELECT
2 params.value.string_value AS Course_Name,
3 event_name,
4 COUNT(DISTINCT user_pseudo_id) AS Unique_Users
5FROM `<project ID>.<dataset ID>.events_*`,
6 UNNEST(event_params) as params
7WHERE
8 _TABLE_SUFFIX BETWEEN '20200401' AND '20200402'
9 AND event_name IN ('course_viewed','course_started','course_completed')
10 AND params.key='course_name'
11GROUP BY 1, 2
Viewing a Parameter Across Multiple Events in Data Studio
To create this stacked bar chart in Data Studio you have two options. Regardless of whether you choose option 1 or 2 above, your chart should look something like this.
Option 1
You could use the same query above as a Custom Query in Data Studio. If you do this, I suggest you add a few other fields to use as filters and replace the start and end date with parameters (see below).
To create the stacked bar chart we discussed, you’ll connect to this new data source, set Course_Name as your dimension, and set your breakdown dimension to event_name.
1SELECT
2 event_date,
3 platform,
4 event_name,
5 params.value.string_value AS Course_Name,
6 COUNT(1) AS eventCount,
7 COUNT(DISTINCT user_pseudo_id) AS Unique_Users
8FROM `<project ID>.<dataset ID>.events_*`,
9 UNNEST(event_params) as params
10WHERE
11 _TABLE_SUFFIX BETWEEN @DS_START_DATE AND @DS_END_DATE
12 AND event_name IN ('course_viewed','course_started','course_completed')
13 AND params.key='course_name'
14GROUP BY 1, 2, 3, 4
Option 2
Alternatively, Data Studio can also create this with filters rather than a custom query. To do this, simply create a filter that selects the proper Event Names and Event Param Name. Your dimension will be the Event Param Name, and your breakdown dimension will be the Event Name.
Other Resources for BigQuery and GA4
Here are a few other posts that I’ve created for using BigQuery with data from Google Analytics 4:
- Cross-Stream First-Touch Attribution with Google Analytics 4 and BigQuery
- How the WITH Clause Can Simplify Your SQL Queries
- BigQuery + GA4: How To Get the First or Most Recent Event for a User
- How to Use the Over clause to Create a Moving Average in BigQuery
- Data Studio + BigQuery + GA4: Viewing a Parameter Across Multiple Events
- Data Studio + BigQuery + GA4: How to View Multiple Parameters on the Same Event
- How to Flatten a BigQuery Table with UNNEST