Advent of Code In BigQuery - Day 8

I enjoyed this one! Windowing functions worked nicely for this. WITH raw_input AS ( SELECT """30373 25512 65332 33549 35390""" AS raw_text ), raw_rows AS ( SELECT o, raw_row FROM ( SELECT SPLIT(raw_text, '\n') raw_row_array FROM raw_input ), UNNEST(raw_row_array) raw_row WITH OFFSET o ), split_rows AS ( SELECT SPLIT(raw_row, '') as split_row, raw_row, o FROM raw_rows ), unnested_rows AS ( SELECT raw_row, o AS row_num, col_num, CAST(col AS INT) AS col FROM split_rows, UNNEST(split_row) col WITH offset col_num ), agg_rows as ( SELECT ARRAY_AGG(col) OVER (PARTITION BY col_num ORDER BY row_num ASC) AS down, ARRAY_AGG(col) OVER (PARTITION BY col_num ORDER BY row_num DESC) AS up, ARRAY_AGG(col) OVER (PARTITION BY row_num ORDER BY col_num ASC) AS left_, ARRAY_AGG(col) OVER (PARTITION BY row_num ORDER BY col_num DESC) AS right_, col, col_num, row_num, raw_row FROM unnested_rows ), part_1 AS ( SELECT COUNT(1) FROM agg_rows WHERE -- if evaluates to null, is an edge tree IFNULL( col > (SELECT MAX(down[SAFE_OFFSET(o - 1)]) FROM UNNEST(down) x WITH OFFSET o) -- visible down OR col > (SELECT MAX(up[SAFE_OFFSET(o - 1)]) FROM UNNEST(up) x WITH OFFSET o) -- visible up, OR col > (SELECT MAX(left_[SAFE_OFFSET(o - 1)]) FROM UNNEST(left_) x WITH OFFSET o) -- visible left, OR col > (SELECT MAX(right_[SAFE_OFFSET(o - 1)]) FROM UNNEST(right_) x WITH OFFSET o) -- visible right, , TRUE) ), max_counts as ( SELECT MAX(row_num) max_row, MAX(col_num) max_col FROM agg_rows ), line_of_sight AS ( SELECT row_num - IFNULL((SELECT MAX(o) FROM UNNEST(down) x WITH OFFSET o WHERE x >= col AND o <> row_num), 0) AS down_visible, (SELECT MAX(o) FROM UNNEST(up) x WITH OFFSET o WHERE x >= col AND o <> (max_row - row_num)) as up, (max_row - row_num) - IFNULL((SELECT MAX(o) FROM UNNEST(up) x WITH OFFSET o WHERE x >= col AND o <> (max_row - row_num)), 0) AS up_visible, col_num - IFNULL((SELECT MAX(o) FROM UNNEST(left_) x WITH OFFSET o WHERE x >= col AND o <> col_num), 0) AS left_visible, (max_col - col_num) - IFNULL((SELECT MAX(o) FROM UNNEST(right_) x WITH OFFSET o WHERE x >= col AND o <> (max_col - col_num)), 0) AS right_visible, * FROM agg_rows, max_counts ) -- SELECT * FROM part_1 SELECT MAX(down_visible * up_visible * left_visible * right_visible) AS max_scenic_score FROM line_of_sight ...

December 21, 2022 · 2 min · Peter Boone  · Source

Advent of Code In BigQuery - Day 7

I have fallen behind since day 6, but am attempting to make up some ground. Day 7 proved to be pretty tough. I kept track of the “current” directory by appending all of the cd commands. I then removed the directory before the .., ie one/dir/.. -> one. I attempted to use a recursive regex for this, but unfortunatly BigQuery uses the re2 regex library which does not support recursive syntax....

December 20, 2022 · 3 min · Peter Boone  · Source

Advent of Code In BigQuery - Day 6

Okay, hope in SQL has been temporarily restored. This problem fits SQL a bit better so I did not have to do anything too wild. For part 2, I decided to copy/past LAG(4) - LAG(13). There might be a better way to do it but I decided to keep it simple for myself. WITH raw_input AS ( SELECT 'mjqjpqmgbljsphdztnvjfqwrcgsmlb' AS raw_row ), points as ( SELECT TO_CODE_POINTS(raw_row) p FROM raw_input ), point_rows AS ( SELECT CHR(cp) cp, o FROM points, UNNEST(p) cp WITH offset o ), points_grouped AS ( SELECT CONCAT( LAG(cp, 1) OVER (ORDER BY o), LAG(cp, 2) OVER (ORDER BY o), LAG(cp, 3) OVER (ORDER BY o), LAG(cp, 4) OVER (ORDER BY o), LAG(cp, 5) OVER (ORDER BY o), LAG(cp, 6) OVER (ORDER BY o), LAG(cp, 7) OVER (ORDER BY o), LAG(cp, 8) OVER (ORDER BY o), LAG(cp, 9) OVER (ORDER BY o), LAG(cp, 10) OVER (ORDER BY o), LAG(cp, 11) OVER (ORDER BY o), LAG(cp, 12) OVER (ORDER BY o), LAG(cp, 13) OVER (ORDER BY o), cp ) str, o FROM point_rows ) SELECT o + 1 FROM points_grouped WHERE ARRAY_LENGTH(ARRAY(( SELECT DISTINCT element FROM UNNEST(SPLIT(str,'')) as element ))) = 14 ORDER BY o LIMIT 1 ...

December 6, 2022 · 1 min · Peter Boone  · Source

Advent of Code In BigQuery - Day 5

Oof, this one was rough. This may be the start of the end for my SQL Advent of Code journey. I tried a few different approaches before “cheating” and falling back on a Javascript UDF. This code is a mess and I would definitly not recommend reading it. I don’t have the stomach to go back and read it myself to clean it up. CREATE TEMP FUNCTION move_box(directions ARRAY<STRUCT<quantity INT64, move_from INT64, move_to INT64>>, start_positions ARRAY<STRUCT<c INT64, value STRING>>) RETURNS STRING LANGUAGE js AS r""" let x = {}; for (let i = 0; i < start_positions....

December 5, 2022 · 2 min · Peter Boone  · Source

Advent of Code In BigQuery

This year, I am be taking a page out of Felipe Hoffa’s book and will be attempting to complete the Advent of Code using BigQuery SQL. Until I reach the point where I can’t solve the puzzles with SQL, I’ll keep track of things here. Day 1 WITH raw_input AS ( /* To start, I just copy/paste the input as a raw text string, and then parse that string into rows....

December 4, 2022 · 4 min · Peter Boone  · Source

Sequencing my genome

We’ve come a long way since the Human Genome Project. This effort to sequence the human genome for the first time was a tremendous achievement that lasted 13 (ish) years and cost $3 billion dollars. Thanks to this pioneering work and major advancements over the years it’s now possible to get your own genome sequenced for $300 in a few months. That’s a 10,000x decrease in cost! If the price of homes decreased at a similar rate since 1990, the median home would cost $7....

October 8, 2021 · 4 min · Peter Boone  · Source

NULL in BigQuery

When in doubt, NULL means “we don’t know the state of this thing so we can’t perform an operation on it.” Keeping track of how NULL values are handled in different SQL dialects can be tricky. This post will serve as a living document where I keep track of how BigQuery does this. NULL and STRING comparison Comparison always returns NULL. SELECT CAST(NULL AS STRING) = '', -- null CAST(NULL AS STRING) = 'value', -- null CAST(NULL AS STRING) = CAST(NULL AS STRING) -- null NULL and BOOL comparison NULL is not TRUE or FALSE....

September 14, 2021 · 7 min · Peter Boone  · Source

The practical use of repetition and definition levels in BigQuery

Google’s Dremel paper is an interesting read that explains some of the concepts that underlie BigQuery. I am still processing the paper and have noticed a few things about repetition and definition levels that are relevant to the every day use of BigQuery. Columnar Data and Records The underlying storage format for BigQuery is columnar. One of the first pieces of advice given to people using BigQuery is to only select the rows that you need....

September 12, 2021 · 2 min · Peter Boone  · Source