-
Notifications
You must be signed in to change notification settings - Fork 5
/
Copy pathindex.html
456 lines (372 loc) · 13.2 KB
/
index.html
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
<!DOCTYPE html>
<html>
<head>
<title>Title</title>
<meta charset="utf-8">
<style>
@import url(https://fonts.googleapis.com/css?family=Yanone+Kaffeesatz);
@import url(https://fonts.googleapis.com/css?family=Droid+Serif:400,700,400italic);
@import url(https://fonts.googleapis.com/css?family=Ubuntu+Mono:400,700,400italic);
body { font-family: 'Droid Serif'; }
h1, h2, h3 {
font-family: 'Yanone Kaffeesatz';
font-weight: normal;
}
img {
width: 100%;
height: auto;
}
img#kixer-logo {
width: 130px;
height: 54px;
}
ul, ol {
margin: 6px 0 6px 0;
}
li {
margin: 0 0 12px 0;
}
.remark-code, .remark-inline-code { font-family: 'Ubuntu Mono'; }
@page {
/* for 16:9 */
/* size: 1210px 681px; */
/* for 4:3 */
size: 908px 681px;
margin: 0;
}
@media print {
.remark-slide-scaler {
width: 100% !important;
height: 100% !important;
transform: scale(1) !important;
top: 0 !important;
left: 0 !important;
}
}
</style>
</head>
<body>
<textarea id="source">
class: center, middle
# Horizontally Scalable Relational Databases with Spark
<image src="slides/kixer-logo.png" id="kixer-logo" />
---
# What is Citus?
* Standard Postgres
* Sharded across multiple nodes
* CREATE EXTENSION citus; -- not a fork of the codebase
* Good for live analytics, multi-tenant
* Open source, commercial support
---
# Where does Citus fit with Spark?
1. Shove your data into Kafka
2. Munge it with Spark
3. ???
4. Profit!
---
# Where does Citus fit with Spark?
1. Shove your data into Kafka
2. Munge it with Spark
3. Serve live traffic using
* ML models
* Key / Value stores
* ? Spark SQL ?
* ? Single node database ?
4. Profit!
---
# Spark SQL + HDFS pain points
* Multi-user
* Query latency
* Mutable rows
* Co-locating related writes for joins
---
# Relational database pain points
* "Schemaless" data
* Scaling out, without giving up
* Aggregations
* Joins
* Transactions
---
# "Schemaless" data
```sql
master# create table no_schema (
data JSONB);
master# create index on no_schema using gin(data);
master# insert into no_schema values
('{"user":"cody","cart":["apples","peanut_butter"]}'),
('{"user":"jake","cart":["whiskey"],"drunk":true}'),
('{"user":"omar","cart":["fireball"],"drunk":true}');
master# select data->'user' from no_schema where data->'drunk' = 'true';
?column?
----------
"jake"
"omar"
(2 rows)
```
---
# Scaling out
```
+--------------+
SELECT FROM table_1001 | |
+-------------------------> | Worker 1 |
| | |
| | table_1001 |
| SELECT FROM table_1003 | table_1003 |
+------------+ +-------------------------> | |
| | | | |
| Master | | +--------------+
SELECT FROM table | | |
+-------------------> | table | ---+
| metadata | | +--------------+
| | | SELECT FROM table_1002 | |
| | +-------------------------> | Worker 2 |
+------------+ | | |
| | table_1002 |
| SELECT FROM table_1004 | table_1004 |
+-------------------------> | |
| |
+--------------+
```
---
# Choosing a distribution key
* Commonly queried column (e.g. customer id)
* 1 master query : 1 worker query
* easy join on distribution key
* possible hot spots if load is skewed
* Evenly distributed column (e.g. event GUID)
* 1 master query : # of shards worker queries
* hard to join
* no hot spots
* Can duplicate table with different distribution key if needed
---
# Creating distributed tables
```sql
master# create table impressions(
date date,
ad_id integer,
site_id integer,
total integer);
master# set citus.shard_replication_factor = 1;
master# set citus.shard_count = 4;
master# select create_distributed_table('impressions', 'ad_id', 'hash');
```
---
Metadata in master tables
```sql
master# select * from pg_dist_shard;
logicalrelid | shardid | shardminvalue | shardmaxvalue
--------------+---------+---------------+---------------
impressions | 102008 | -2147483648 | -1073741825
impressions | 102009 | -1073741824 | -1
impressions | 102010 | 0 | 1073741823
impressions | 102011 | 1073741824 | 2147483647
```
Data in worker shard tables
```sql
worker1# \d
List of relations
Schema | Name | Type | Owner
--------+--------------------+-------+-------
public | impressions_102008 | table | cody
public | impressions_102010 | table | cody
```
---
# Writing data
```sql
master# insert into impressions values (now(), 23, 42, 1337);
master# update impressions set total = total + 1
where ad_id = 23 and site_id = 42;
master# \copy impressions from '/var/tmp/bogus_impressions';
```
Can also write directly to worker shards, as long as you hash correctly
---
# Aggregations
Commutative and associative operations "just work":
```sql
master# select site_id, avg(total)
from impressions group by 1 order by 2 desc limit 1;
site_id | avg
---------+---------------------
5225 | 790503.061538461538
(1 row)
```
In worker1's log:
```sql
COPY (SELECT site_id, sum(total) AS avg, count(total) AS avg
FROM impressions_102010 impressions WHERE true GROUP BY site_id) TO STDOUT
COPY (SELECT site_id, sum(total) AS avg, count(total) AS avg
FROM impressions_102008 impressions WHERE true GROUP BY site_id) TO STDOUT
```
For other operations, can usually query a subset of data to temp table on master, then use arbitrary SQL
---
# Joins
Co-located joins of tables with same distribution column work well
```sql
master# create table clicks(
date date,
ad_id integer,
site_id integer,
price numeric,
total integer);
master# select create_distributed_table('clicks', 'ad_id', 'hash');
master# select i.ad_id, sum(c.total) / sum(i.total)::float as clickthrough
from impressions i
inner join clicks c on i.ad_id = c.ad_id and i.date = c.date
and i.site_id = c.site_id group by 1 order by 2 desc limit 1;
ad_id | clickthrough
-------+----------
814 | 0.1
```
---
Distributed joins on non-distribution column will work, but are slow
```sql
master# create table discounts(
date date,
amt numeric);
master# select create_distributed_table('discounts', 'date', 'hash');
master# select c.ad_id, max(c.price * d.amt) from clicks c
inner join discounts d on c.date = d.date group by 1 order by 2 desc limit 1;
ERROR: cannot use real time executor with repartition jobs
HINT: Set citus.task_executor_type to "task-tracker".
master# SET citus.task_executor_type = 'task-tracker';
master# select c.ad_id, max(c.price * d.amt) from clicks c
inner join discounts d on c.date = d.date group by 1 order by 2 desc limit 1;
ad_id | max
-------+-----------------------------------
587 | 67.887149187736200000000000000000
(1 row)
Time: 3464.598 ms
```
---
Replicating the join table on every worker is faster
```sql
master# SET citus.shard_replication_factor = 2; -- equal to number of nodes
master# select create_reference_table('discounts2');
master# select c.ad_id, max(c.price * d.amt) from clicks c
inner join discounts2 d on c.date = d.date group by 1 order by 2 desc limit 1;
ad_id | max
-------+-----------------------------------
587 | 67.887149187736200000000000000000
(1 row)
Time: 31.237 ms
```
---
# Transactions
* No global transactions (Postgres-XL)
* Individual worker transactions are still extremely useful:
* If sharded by customer id, each customer sees consistent world
* Spark output actions are at-least-once
* Transactions allow consistent semantics for failures
* Even for non-idempotent updates
---
# Transactional writes from Spark to single DB
* Table of offset ranges (or batch ids)
* Foreach partition, start transaction on DB
* insert or update results
* update offsets table rows
* roll back if offsets weren't as expected
* On failure,
* begin from minimum offset range
* recalculate all results for that range (due to shuffle)
---
# Transactional writes from Spark to Citus
* **Partition Spark results to match Citus shards**
* Table of offset ranges (or batch ids) **on each worker**
* Foreach partition, start transaction **on corresponding worker**
* insert or update results
* update offsets table rows **for that shard**
* roll back if offsets weren't as expected
* On failure,
* begin from minimum offset range across all workers
* recalculate all results for that range (due to shuffle)
* **skip writes for shards that already have that offset range**
---
# Spark custom partitioner
```scala
/** same number of Spark partitions as Citus shards */
override def numPartitions: Int
/** given a key, which Spark partition */
override def getPartition(key: Any): Int
/** given a Spark partition, which worker shard */
def shardPlacement(partitionId: Int): ShardPlacement
```
* Citus uses Postgres hash (**hashfunc.c**) based on Jenkins' 2006 hash
* Min / max hash values for a given shard are in **pg_dist_shard** table
* Worker nodes for a given shard are in **pg_dist_shard_placement** table
* Idea is to query once at partitioner creation time, build a lookup array
---
```sql
select
(ds.logicalrelid::regclass)::varchar as tablename,
ds.shardmaxvalue::integer as hmax,
ds.shardid::integer,
p.nodename::varchar,
p.nodeport::integer
from pg_dist_shard ds
left join pg_dist_shard_placement p on ds.shardid = p.shardid
where (ds.logicalrelid::regclass)::varchar in ('impressions')
order by tablename, hmax asc;
tablename | hmax | shardid | nodename | nodeport
-------------+-------------+---------+-----------+----------
impressions | -1073741825 | 102008 | host1 | 9701
impressions | -1 | 102009 | host2 | 9702
impressions | 1073741823 | 102010 | host1 | 9701
impressions | 2147483647 | 102011 | host2 | 9702
```
* To find partition, hash key w/Jenkins, walk array until hmax >= hashed
* To find worker shard for a partition, index directly by partition #
* See github link at end of slides for working code
---
# Example offsets table
```sql
app | topic | part | shard_table_name | off
-------+-------------+------+--------------------+---------
myapp | impressions | 0 | impressions_102008 | 20000
myapp | impressions | 0 | impressions_102009 | 20000
myapp | impressions | 0 | impressions_102010 | 19000 -- behind
myapp | impressions | 0 | impressions_102011 | 20000
myapp | impressions | 1 | impressions_102008 | 20001
myapp | impressions | 1 | impressions_102009 | 20001
myapp | impressions | 1 | impressions_102010 | 18000 -- behind
myapp | impressions | 1 | impressions_102011 | 20001
```
* In this case, a failure occurred before writes to **impressions_102010** finished
* Restart Spark app from Kafka offset ranges
* partition 0 offsets 19000 -> 20000
* partition 1 offsets 18000 -> 20001
* Writes to **impressions_102010** succeed, other shards are skipped
---
# Lies, damn lies, and bar charts
<image src="slides/writes.png" />
---
# Lies, damn lies, and bar charts
<image src="slides/reads.png" />
---
# General lessons learned
* Be conservative with changing anything else when moving to sharded DB
* PgBouncer is necessary in front of workers, not just master
* especially if you have queries that hit all shards
* Some cognitive overhead about which SQL features work
* still better than layering SQL on a totally different data model
* Would be nice to have hash distribution on top of date-partitioned tables
* most of our queries involve date ranges
* drop table for expiring data retention rather than delete / vacuum
* can be done manually, easy way may be coming with Postgres 10
---
class: center, middle
# Questions?
<image src="slides/kixer-logo.png" id="kixer-logo" />
https://github.com/koeninger/spark-citus
</textarea>
<script src="slides/remark-latest.min.js">
</script>
<script>
// for 16:9
//var slideshow = remark.create({ratio: "16:9"});
// for 4:3
var slideshow = remark.create();
</script>
</body>
</html>