Skip to content

Commit aac949a

Browse files
authored
Add practice exercise: poker (#203)
1 parent 6f58059 commit aac949a

File tree

11 files changed

+621
-0
lines changed

11 files changed

+621
-0
lines changed

config.json

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -450,6 +450,14 @@
450450
"prerequisites": [],
451451
"difficulty": 8
452452
},
453+
{
454+
"slug": "poker",
455+
"name": "Poker",
456+
"uuid": "b9ec94e1-8c20-4095-b627-889b614e2a99",
457+
"practices": [],
458+
"prerequisites": [],
459+
"difficulty": 8
460+
},
453461
{
454462
"slug": "protein-translation",
455463
"name": "Protein Translation",
Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,7 @@
1+
# SQLite-specific instructions
2+
3+
## JSON documentation
4+
5+
See [JSON Functions And Operators][json-docs] for SQLite JSON functions.
6+
7+
[json-docs]: https://www.sqlite.org/json1.html
Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,7 @@
1+
# Instructions
2+
3+
Pick the best hand(s) from a list of poker hands.
4+
5+
See [Wikipedia][poker-hands] for an overview of poker hands.
6+
7+
[poker-hands]: https://en.wikipedia.org/wiki/List_of_poker_hands
Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,19 @@
1+
{
2+
"authors": [
3+
"jimmytty"
4+
],
5+
"files": {
6+
"solution": [
7+
"poker.sql"
8+
],
9+
"test": [
10+
"poker_test.sql"
11+
],
12+
"example": [
13+
".meta/example.sql"
14+
]
15+
},
16+
"blurb": "Pick the best hand(s) from a list of poker hands.",
17+
"source": "Inspired by the training course from Udacity.",
18+
"source_url": "https://www.udacity.com/course/design-of-computer-programs--cs212"
19+
}
Lines changed: 291 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,291 @@
1+
DROP TABLE IF EXISTS ranking;
2+
CREATE TEMPORARY TABLE ranking (
3+
id INTEGER PRIMARY KEY,
4+
name TEXT NOT NULL
5+
);
6+
INSERT INTO ranking (id, name)
7+
VALUES
8+
(10, 'straight flush' ),
9+
(20, 'four of a kind' ),
10+
(30, 'full house' ),
11+
(40, 'flush' ),
12+
(50, 'straight' ),
13+
(60, 'three of a kind'),
14+
(70, 'two pair' ),
15+
(80, 'one pair' ),
16+
(90, 'high card' )
17+
;
18+
19+
DROP TABLE IF EXISTS tmp;
20+
CREATE TABLE tmp (
21+
hand TEXT PRIMARY KEY,
22+
deck TEXT,
23+
name TEXT
24+
);
25+
INSERT INTO tmp (hand)
26+
SELECT DISTINCT(j.value)
27+
FROM poker, JSON_TREE(hands) j
28+
WHERE j.type = 'text'
29+
;
30+
31+
UPDATE tmp
32+
SET deck = (
33+
WITH to_cards (rank, suite) AS (
34+
WITH RECURSIVE to_cards (hand, card) AS (
35+
VALUES (hand || ' ', NULL)
36+
UNION ALL
37+
SELECT
38+
SUBSTR(hand, INSTR(hand, ' ') + 1),
39+
SUBSTR(hand, 1, INSTR(hand, ' ') - 1)
40+
FROM to_cards
41+
WHERE hand <> ''
42+
LIMIT 10
43+
)
44+
SELECT SUBSTR(card, 1, LENGTH(card) - 1) AS rank,
45+
SUBSTR(card, -1) AS suite
46+
FROM to_cards
47+
WHERE card NOTNULL
48+
)
49+
SELECT JSON_GROUP_ARRAY(JSON(card))
50+
FROM (
51+
SELECT JSON_ARRAY(rank, suite) card
52+
FROM (
53+
SELECT
54+
CASE rank
55+
WHEN 'A' THEN 14
56+
WHEN 'J' THEN 11
57+
WHEN 'Q' THEN 12
58+
WHEN 'K' THEN 13
59+
ELSE rank
60+
END * 1 AS rank,
61+
suite
62+
FROM to_cards
63+
)
64+
ORDER BY rank DESC, suite ASC
65+
)
66+
)
67+
;
68+
69+
ALTER TABLE tmp ADD COLUMN is_sequential BOOLEAN;
70+
UPDATE tmp
71+
SET is_sequential =
72+
(SELECT JSON_ARRAY_LENGTH(ranks) = 5
73+
AND JSON_EXTRACT(ranks, '$[0]') =
74+
JSON_EXTRACT(ranks, '$[4]') + 4
75+
FROM (SELECT
76+
JSON_GROUP_ARRAY(
77+
DISTINCT(JSON_EXTRACT(j.value, '$[0]'))) AS ranks
78+
FROM JSON_EACH(deck) j))
79+
OR
80+
(SELECT JSON_ARRAY_LENGTH(ranks) = 5
81+
AND JSON_EXTRACT(ranks, '$[0]') =
82+
JSON_EXTRACT(ranks, '$[4]') + 4
83+
FROM (
84+
SELECT JSON_GROUP_ARRAY(rank) AS ranks
85+
FROM (
86+
SELECT IIF(rank = 14, 1, rank) rank
87+
FROM (
88+
SELECT DISTINCT(JSON_EXTRACT(j.value, '$[0]')) AS rank
89+
FROM JSON_EACH(deck) j
90+
)
91+
ORDER BY rank DESC
92+
)
93+
)
94+
)
95+
;
96+
97+
ALTER TABLE tmp ADD COLUMN same_suite BOOLEAN;
98+
UPDATE tmp
99+
SET same_suite = (
100+
SELECT JSON_ARRAY_LENGTH(suites) = 1
101+
FROM (
102+
SELECT JSON_GROUP_ARRAY(
103+
DISTINCT(JSON_EXTRACT(j.value, '$[1]'))
104+
) AS suites
105+
FROM JSON_EACH(deck) j
106+
)
107+
)
108+
;
109+
110+
UPDATE tmp
111+
SET name = 'straight flush'
112+
WHERE is_sequential AND same_suite
113+
AND name ISNULL
114+
;
115+
116+
UPDATE tmp
117+
SET name = 'four of a kind'
118+
WHERE (SELECT 1
119+
FROM (
120+
SELECT JSON_EXTRACT(j.value, '$[0]') rank
121+
FROM JSON_EACH(deck) j
122+
)
123+
GROUP BY rank
124+
HAVING COUNT(*) = 4
125+
)
126+
AND name ISNULL
127+
;
128+
129+
UPDATE tmp
130+
SET name = 'full house'
131+
WHERE (SELECT GROUP_CONCAT(dup) = '3,2'
132+
FROM (
133+
SELECT dup
134+
FROM (
135+
SELECT COUNT(*) dup
136+
FROM (
137+
SELECT JSON_EXTRACT(j.value, '$[0]') rank
138+
FROM JSON_EACH(deck) j
139+
)
140+
GROUP BY rank
141+
)
142+
ORDER BY dup DESC
143+
)
144+
)
145+
AND name ISNULL
146+
;
147+
148+
UPDATE tmp
149+
SET name = 'flush'
150+
WHERE same_suite
151+
AND name ISNULL
152+
;
153+
154+
UPDATE tmp
155+
SET name = 'straight'
156+
WHERE is_sequential
157+
AND name ISNULL
158+
;
159+
160+
UPDATE tmp
161+
SET name = 'three of a kind'
162+
WHERE (SELECT 1
163+
FROM (
164+
SELECT JSON_EXTRACT(j.value, '$[0]') rank
165+
FROM JSON_EACH(deck) j
166+
)
167+
GROUP BY rank
168+
HAVING COUNT(*) = 3
169+
)
170+
AND name ISNULL
171+
;
172+
173+
UPDATE tmp
174+
SET name = 'two pair'
175+
WHERE (SELECT GROUP_CONCAT(dup) = '2,2,1'
176+
FROM (
177+
SELECT dup
178+
FROM (
179+
SELECT COUNT(*) dup
180+
FROM (
181+
SELECT JSON_EXTRACT(j.value, '$[0]') rank
182+
FROM JSON_EACH(deck) j
183+
)
184+
GROUP BY rank
185+
)
186+
ORDER BY dup DESC
187+
)
188+
)
189+
AND name ISNULL
190+
;
191+
192+
UPDATE tmp
193+
SET name = 'one pair'
194+
WHERE (SELECT 1
195+
FROM (
196+
SELECT JSON_EXTRACT(j.value, '$[0]') rank
197+
FROM JSON_EACH(deck) j
198+
)
199+
GROUP BY rank
200+
HAVING COUNT(*) = 2
201+
)
202+
AND name ISNULL
203+
;
204+
205+
UPDATE tmp
206+
SET name = 'high card'
207+
WHERE name ISNULL
208+
;
209+
210+
ALTER TABLE tmp ADD COLUMN ranks_id INTEGER;
211+
UPDATE tmp
212+
SET ranks_id =
213+
CASE
214+
WHEN name NOT IN ('four of a kind', 'three of a kind', 'full house')
215+
THEN (
216+
(SELECT GROUP_CONCAT(rank, '')
217+
FROM (
218+
SELECT IIF(rank = '14' AND
219+
LIKE('straight%', name) AND
220+
JSON_EXTRACT(
221+
deck, '$[0][0]', '$[1][0]') = JSON_ARRAY(14,5),
222+
1,
223+
rank
224+
) rank
225+
FROM (
226+
SELECT PRINTF('%02d', JSON_EXTRACT(j.value, '$[0]')) rank
227+
FROM JSON_EACH(deck) j
228+
)
229+
ORDER BY rank DESC
230+
)
231+
)
232+
)
233+
ELSE (
234+
WITH
235+
by_rank AS (
236+
SELECT JSON_EXTRACT(j.value, '$[0]') rank, j.*
237+
FROM JSON_EACH(deck) j
238+
),
239+
dup (rank) AS (
240+
SELECT rank
241+
FROM by_rank
242+
GROUP BY rank
243+
ORDER BY COUNT(*) DESC
244+
LIMIT 1
245+
),
246+
same (rank) AS (
247+
SELECT PRINTF('%02d', by_rank.rank)
248+
FROM by_rank, dup
249+
WHERE by_rank.rank = dup.rank
250+
),
251+
kickers (rank) AS (
252+
SELECT PRINTF('%02d', by_rank.rank)
253+
FROM by_rank, dup
254+
WHERE by_rank.rank != dup.rank
255+
ORDER BY by_rank.rank DESC
256+
)
257+
SELECT GROUP_CONCAT(rank, '')
258+
FROM (
259+
SELECT rank FROM same
260+
UNION ALL
261+
SELECT rank FROM kickers
262+
)
263+
)
264+
END
265+
;
266+
267+
268+
269+
UPDATE poker
270+
SET result = (
271+
WITH
272+
analysis AS (
273+
SELECT j.value hand, tmp.name, tmp.deck, ranking.id, tmp.ranks_id
274+
FROM JSON_TREE(hands) j, tmp, ranking
275+
WHERE j.value = tmp.hand
276+
AND tmp.name = ranking.name
277+
AND j.type = 'text'
278+
),
279+
winners AS (
280+
SELECT hand, ranks_id
281+
FROM analysis WHERE id = (SELECT MIN(id) FROM analysis)
282+
),
283+
tiebreaker AS (
284+
SELECT winners.hand
285+
FROM winners
286+
WHERE ranks_id = (SELECT MAX(ranks_id) FROM winners)
287+
)
288+
SELECT JSON_GROUP_ARRAY(hand)
289+
FROM (SELECT hand FROM tiebreaker ORDER BY hand)
290+
)
291+
;

0 commit comments

Comments
 (0)