Unified Paid Media table¶
The Unified Paid Media table builds customer profiles that contain all known PII–including email addresses, phone numbers, names, and physical addresses–for each Amperity ID. This is different from the Merged Customers table, which has only the best PII for each Amperity ID. Use the Unified Paid Media to help increase the total number of matched customers with your paid media campaigns.
Note
The Unified Paid Media table is built from the Unified Coalesced table to build customer profiles that include all known personally identifiable information (PII), including email addresses, phone numbers, and physical addresses.
Add this table to your customer 360 database when your brand wants to send all known PII downstream for use with paid media campaigns.
Add table¶
The Unified Paid Media table is an optional table for the customer 360 database. The Unified Paid Media table is built using a SQL template.
Note
The Unified Paid Media table uses a Spark SQL query to pull the Amperity ID, along with all known PII data, from the Unified Coalesced table.
The Unified Coalesced table has all PII data processed through Stitch. Each semantic tag is a column header. All data is coalesced into a single table. A unique Amperity ID may appear in more than one row.
To add the Unified Paid Media table
From the Customer 360 page, under All Databases, select the menu for the customer 360 database, and then click Edit.
From the Database Editor, click Add Table.
Name the table “Unified_Paid_Media”.
Set the build mode to SQL.
Click Apply template, and then select Unified Paid Media.
Click Validate to verify the SQL runs without error.
Optional. Adjust the row limit.
Click Next. This opens the Database Table Definition page.
Add a table description. This enables a tooltip that is visible from other areas in Amperity.
Verify that semantic tags—given_name, surname, email, phone, address, city, state, postal, birthdate, gender, etc.—were applied to all PII fields correctly.
Tip
You can clear incorrectly tagged semantics individually or for the entire table. To clear semantic tags for the entire table, under Semantic Suggestions click Clear semantics.
Under Version History, select Enable table version history.
Click Save.
SQL query¶
The following SQL query is the recommended starting point for the Unified Paid Media table. It is a series of window function that collects and groups all known PII data, and then a statement that updates the Unified Paid Media table with the results.
Recommended starting point¶
The following query is the starting point for the Unified Paid Media table.
1WITH pii_row_limit AS (
2 SELECT 10 AS limit
3)
4
5,all_ampids AS (
6 SELECT DISTINCT
7 amperity_id
8 FROM Unified_Coalesced
9)
10
11,address_and_details_prep AS (
12 SELECT DISTINCT
13 amperity_id
14 ,LOWER(given_name) AS given_name
15 ,LOWER(surname) AS surname
16 ,LOWER(address) AS address
17 ,LOWER(address2) AS address_line_2
18 ,LOWER(city) AS city
19 ,CASE
20 WHEN TRIM(LOWER(state)) IN ('alabama','al') THEN 'AL'
21 WHEN TRIM(LOWER(state)) IN ('alaska','ak') THEN 'AK'
22 WHEN TRIM(LOWER(state)) IN ('arizona','az') THEN 'AZ'
23 WHEN TRIM(LOWER(state)) IN ('arkansas','ar') THEN 'AR'
24 WHEN TRIM(LOWER(state)) IN ('california','ca') THEN 'CA'
25 WHEN TRIM(LOWER(state)) IN ('colorado','co') THEN 'CO'
26 WHEN TRIM(LOWER(state)) IN ('connecticut','ct') THEN 'CT'
27 WHEN TRIM(LOWER(state)) IN ('delaware','de') THEN 'DE'
28 WHEN TRIM(LOWER(state)) IN ('district of columbia','dc') THEN 'DC'
29 WHEN TRIM(LOWER(state)) IN ('florida','fl') THEN 'FL'
30 WHEN TRIM(LOWER(state)) IN ('georgia','ga') THEN 'GA'
31 WHEN TRIM(LOWER(state)) IN ('hawaii','hi') THEN 'HI'
32 WHEN TRIM(LOWER(state)) IN ('idaho','id') THEN 'ID'
33 WHEN TRIM(LOWER(state)) IN ('illinois','il') THEN 'IL'
34 WHEN TRIM(LOWER(state)) IN ('indiana','IN') THEN 'IN'
35 WHEN TRIM(LOWER(state)) IN ('iowa','ia') THEN 'IA'
36 WHEN TRIM(LOWER(state)) IN ('kansas','ks') THEN 'KS'
37 WHEN TRIM(LOWER(state)) IN ('kentucky','ky') THEN 'KY'
38 WHEN TRIM(LOWER(state)) IN ('louisiana','la') THEN 'LA'
39 WHEN TRIM(LOWER(state)) IN ('maine','me') THEN 'ME'
40 WHEN TRIM(LOWER(state)) IN ('maryland','md') THEN 'MD'
41 WHEN TRIM(LOWER(state)) IN ('massachusetts','ma') THEN 'MA'
42 WHEN TRIM(LOWER(state)) IN ('michigan','mi') THEN 'MI'
43 WHEN TRIM(LOWER(state)) IN ('minnesota','mn') THEN 'MN'
44 WHEN TRIM(LOWER(state)) IN ('mississippi','ms') THEN 'MS'
45 WHEN TRIM(LOWER(state)) IN ('missouri','mo') THEN 'MO'
46 WHEN TRIM(LOWER(state)) IN ('montana','mt') THEN 'MT'
47 WHEN TRIM(LOWER(state)) IN ('nebraska','ne') THEN 'NE'
48 WHEN TRIM(LOWER(state)) IN ('nevada','nv') THEN 'NV'
49 WHEN TRIM(LOWER(state)) IN ('new hampshire','nh') THEN 'NH'
50 WHEN TRIM(LOWER(state)) IN ('new jersey','nj') THEN 'NJ'
51 WHEN TRIM(LOWER(state)) IN ('new mexico','nm') THEN 'NM'
52 WHEN TRIM(LOWER(state)) IN ('new york','ny') THEN 'NY'
53 WHEN TRIM(LOWER(state)) IN ('north carolina','nc') THEN 'NC'
54 WHEN TRIM(LOWER(state)) IN ('north dakota','nd') THEN 'ND'
55 WHEN TRIM(LOWER(state)) IN ('ohio','oh') THEN 'OH'
56 WHEN TRIM(LOWER(state)) IN ('oklahoma','ok') THEN 'OK'
57 WHEN TRIM(LOWER(state)) IN ('oregon','or') THEN 'OR'
58 WHEN TRIM(LOWER(state)) IN ('pennsylvania','pa') THEN 'PA'
59 WHEN TRIM(LOWER(state)) IN ('rhode island','ri') THEN 'RI'
60 WHEN TRIM(LOWER(state)) IN ('south carolina', 'sc') THEN 'SC'
61 WHEN TRIM(LOWER(state)) IN ('south dakota', 'sd') THEN 'SD'
62 WHEN TRIM(LOWER(state)) IN ('tennessee', 'tn') THEN 'TN'
63 WHEN TRIM(LOWER(state)) IN ('texas', 'tx') THEN 'TX'
64 WHEN TRIM(LOWER(state)) IN ('utah', 'ut') THEN 'UT'
65 WHEN TRIM(LOWER(state)) IN ('vermont', 'vt') THEN 'VT'
66 WHEN TRIM(LOWER(state)) IN ('virginia', 'va') THEN 'VA'
67 WHEN TRIM(LOWER(state)) IN ('washington', 'wa') THEN 'WA'
68 WHEN TRIM(LOWER(state)) IN ('west virginia', 'wv') THEN 'WV'
69 WHEN TRIM(LOWER(state)) IN ('wisconsin', 'wi') THEN 'WI'
70 WHEN TRIM(LOWER(state)) IN ('wyoming', 'wy') THEN 'WY'
71 WHEN TRIM(LOWER(state)) IN ('american samoa', 'as') THEN 'AS'
72 WHEN TRIM(LOWER(state)) IN ('guam', 'gu') THEN 'GU'
73 WHEN TRIM(LOWER(state)) IN ('northern mariana islands', 'mp') THEN 'MP'
74 WHEN TRIM(LOWER(state)) IN ('puerto rico', 'pr') THEN 'PR'
75 WHEN TRIM(LOWER(state)) IN ('us virgin islands', 'vi') THEN 'VI'
76 WHEN TRIM(LOWER(state)) IN ('us minor outlying islands', 'um') THEN 'UM'
77 WHEN TRIM(LOWER(state)) IN ('marshall islands', 'mh') THEN 'MH'
78 WHEN TRIM(LOWER(state)) IN ('micronesia', 'fm') THEN 'FM'
79 WHEN TRIM(LOWER(state)) IN ('palau', 'pw') THEN 'PW'
80 WHEN TRIM(LOWER(state)) IN ('us armed forces americas', 'aa') THEN 'AA'
81 WHEN TRIM(LOWER(state)) IN ('us armed forces europe', 'ae') THEN 'AE'
82 WHEN TRIM(LOWER(state)) IN ('us armed forces pacific', 'ap') THEN 'AP'
83 WHEN TRIM(LOWER(state)) IN ('alberta', 'ab') THEN 'AB'
84 WHEN TRIM(LOWER(state)) IN ('british columbia', 'bc') THEN 'BC'
85 WHEN TRIM(LOWER(state)) IN ('manitoba', 'mb') THEN 'MB'
86 WHEN TRIM(LOWER(state)) IN ('new brunswick', 'nb') THEN 'NB'
87 WHEN TRIM(LOWER(state)) IN ('newfoundland AND labrador', 'nl') THEN 'NL'
88 WHEN TRIM(LOWER(state)) IN ('nova scotia', 'ns') THEN 'NS'
89 WHEN TRIM(LOWER(state)) IN ('ontario', 'on') THEN 'ON'
90 WHEN TRIM(LOWER(state)) IN ('prince edward island', 'pe') THEN 'PE'
91 WHEN TRIM(LOWER(state)) IN ('quebec', 'qc') THEN 'QC'
92 WHEN TRIM(LOWER(state)) IN ('saskatchewan', 'sk') THEN 'SK'
93 WHEN TRIM(LOWER(state)) IN ('northwest territories','nt') THEN 'NT'
94 WHEN TRIM(LOWER(state)) IN ('nunavut','nu') THEN 'NU'
95 WHEN TRIM(LOWER(state)) IN ('yukon','yt') THEN 'YT'
96 ELSE UPPER(state)
97 END AS state
98 ,postal AS zip
99 ,CASE
100 WHEN LOWER(country) IN ('united states','usa') THEN 'us'
101 ELSE LOWER(country)
102 END AS country
103 ,birthdate
104 ,CASE
105 WHEN LOWER(gender) IN ('female','woman','w') THEN 'f'
106 WHEN LOWER(gender) IN ('male','man') THEN 'm'
107 WHEN LOWER(gender) IN ('unknown','undefined','u','null') THEN null
108 ELSE LOWER(gender)
109 END AS gender
110 ,MAX(update_dt) AS update_dt
111 ,MAX(pk) AS pk
112 FROM Unified_Coalesced
113 GROUP BY amperity_id
114 ,given_name
115 ,surname
116 ,address
117 ,address_line_2
118 ,city
119 ,state
120 ,zip
121 ,country
122 ,birthdate
123 ,gender
124)
125
126,address_and_details AS (
127 SELECT DISTINCT
128 amperity_id
129 ,given_name
130 ,surname
131 ,address
132 ,address_line_2
133 ,city
134 ,state
135 ,zip
136 ,country
137 ,birthdate
138 ,gender
139 FROM (
140 SELECT
141 amperity_id
142 ,given_name
143 ,surname
144 ,address
145 ,address_line_2
146 ,city
147 ,state
148 ,zip
149 ,country
150 ,birthdate
151 ,gender
152 ,ROW_NUMBER() OVER (
153 PARTITION BY amperity_id
154 ORDER BY (
155 INT(ISNOTNULL(address)) +
156 INT(ISNOTNULL(given_name)) +
157 INT(ISNOTNULL(surname)) +
158 INT(ISNOTNULL(zip))
159 ) DESC
160 ,update_dt DESC
161 ,pk
162 ) AS update_rank
163 FROM address_and_details_prep
164 WHERE COALESCE (
165 given_name
166 ,surname
167 ,address
168 ,address_line_2
169 ,city
170 ,state
171 ,zip
172 ,country
173 ,birthdate
174 ,gender
175 ) IS NOT NULL
176 )
177 WHERE update_rank <= (
178 SELECT limit FROM pii_row_limit
179 )
180)
181
182,cleaned_emails AS (
183 SELECT
184 DISTINCT
185 amperity_id
186 ,email
187 FROM (
188 SELECT
189 amperity_id
190 ,EXPLODE(SPLIT(LOWER(email), ',')) AS email
191 ,update_dt
192 ,pk
193 ,ROW_NUMBER() OVER (
194 PARTITION BY amperity_id
195 ORDER BY update_dt DESC
196 ,pk
197 ) AS update_rank
198 FROM Unified_Coalesced
199 WHERE email IS NOT NULL
200 )
201 WHERE update_rank <= (
202 SELECT limit FROM pii_row_limit
203 )
204)
205
206,cleaned_phones AS (
207 SELECT DISTINCT
208 amperity_id
209 ,phone
210 FROM (
211 SELECT
212 amperity_id
213 ,EXPLODE(SPLIT(REGEXP_REPLACE(phone, '[-.()]', ''), ',')) AS phone
214 ,update_dt
215 ,pk
216 ,ROW_NUMBER() OVER (
217 PARTITION BY amperity_id
218 ORDER BY update_dt DESC
219 ,pk
220 ) AS update_rank
221 FROM Unified_Coalesced
222 WHERE phone IS NOT NULL
223 )
224 WHERE update_rank <= (
225 SELECT limit FROM pii_row_limit
226 )
227)
228
229SELECT
230 aa.amperity_id
231 ,ad.given_name
232 ,ad.surname
233 ,TRIM(ce.email) AS email
234 ,TRIM(cp.phone) AS phone
235 ,ad.address
236 ,ad.address_line_2
237 ,ad.city
238 ,ad.state
239 ,ad.zip
240 ,ad.country
241 ,ad.birthdate
242 ,ad.gender
243FROM all_ampids aa
244LEFT JOIN address_and_details ad ON aa.amperity_id = ad.amperity_id
245LEFT JOIN cleaned_emails ce ON aa.amperity_id=ce.amperity_id
246LEFT JOIN cleaned_phones cp ON aa.amperity_id=cp.amperity_id
247 WHERE (
248 ISNOTNULL(ad.address)
249 AND ISNOTNULL(ad.zip)
250 )
251OR ISNOTNULL(COALESCE(ce.email,cp.phone))
Optional updates¶
The Unified Paid Media does not require customization, but you may make the following updates:
Configure the row limit¶
The Unified Paid Media table is configured by default to include a ranked list of up to 10 phone numbers, email addresses, and addresses/details for each unique Amperity ID.
Important
Amperity IDs are duplicated in the Unified Paid Media table, but are limited by the configured row limit.
You can configure the row limit by changing a value in the pii_row_limit common table expression at the start of the query. For example, a value of “3” will include the top 3 ranked phone numbers, email addresses, and physical addresses for each unique Amperity ID:
1WITH pii_row_limit AS (
2 SELECT 3 AS limit
3)
How many rows are defined by the row limit?
If the limit is set to 10, and there are 10 rows each for email addresses, phone numbers, and address/details, there will be 10 x 10 x 10 combinations of rows, or 1000 rows in the Unified Paid Media table.
If the limit is set to 5, and there are 5 rows each, there will be 5 x 5 x 5 combinations of rows, or 125 rows.
If the limit is set to 3, and there are 3 rows each, there will be 3 x 3 x 3 combinations of rows, or 27 rows.
Adjust the row limit to control the size of the Unified Paid Media table, as required to support your brand’s goals for match rates and customer matches in downstream marketing applications.
When an audiences is sent to a destination and that audience uses the Unified Paid Media table, only the fields that are supported by the downstream marketing application will be sent. For example, if a downstream marketing tool only requires email addresses, a row limit of 10 will send up to 10 email addresses for each Amperity ID that matched the audience that was built in Amperity.
State, province, and territory codes¶
Amperity uses a CASE statement ot define standardized state and province codes for the United States (states and territories) and Canada (provinces and territories).
The default CASE statement located in the address_and_details_prep common table expression standardizes states, provinces, and territories into two digit codes:
1,CASE
2 WHEN TRIM(LOWER(state)) IN ('alabama','al') THEN 'AL'
3 WHEN TRIM(LOWER(state)) IN ('alaska','ak') THEN 'AK'
4 [... 72 rows ...]
5 WHEN TRIM(LOWER(state)) IN ('nunavut','nu') THEN 'NU'
6 WHEN TRIM(LOWER(state)) IN ('yukon','yt') THEN 'YT'
7 ELSE UPPER(state)
8END AS state
You may update the codes within the CASE statement located in the address_and_details_prep common table expression to align to the codes your brand uses or you may use a separate mapping file that is joined to this table.
Column reference¶
The Unified Paid Media table only contains field associated with customer profile semantic tags (names, physical addresses, phone numbers, email addresses, birthdates, and gender) along with the Amperity ID.
Column name |
Data type |
Description |
---|---|---|
Amperity ID |
String |
The unique identifier that is assigned to clusters of customer records that all represent the same individual. Each row in this table is associated with an Amperity ID; rows in this table are not unique by Amperity ID. |
Address |
String |
The address connected with the location of a customer, such as “123 Main Street”. |
Address Line 2 |
String |
Address information, such as an apartment number or a post office box, connected with the location of a customer, such as “Apt #9”. |
Birthdate |
Date |
The date of birth connected with a customer. |
City |
String |
The city connected with the location of a customer. |
Country |
String |
The country connected with the location of a customer. |
String |
The email address connected with a customer. A customer may have more than one email address. |
|
Gender |
String |
The gender connected with a customer. |
Given Name |
String |
The first name connected with a customer. |
Phone |
String |
The phone number connected with a customer. A customer may have more than one phone number. |
Zip |
String |
The zip code or postal code connected with the location of a customer. |
State |
String |
The state or province connected with the location of a customer. |
Surname |
String |
The last name connected with a customer. |