Skip to content

Commit

Permalink
fix(bq,sf,rs,pg|quadbin): improve precision of long lat conversion ne…
Browse files Browse the repository at this point in the history
…ar the latitude limits (#461)
  • Loading branch information
jgoizueta authored Jan 11, 2024
1 parent 6489119 commit b0a6e08
Show file tree
Hide file tree
Showing 10 changed files with 121 additions and 55 deletions.
18 changes: 5 additions & 13 deletions .github/workflows/redshift-ded.yml
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,7 @@ jobs:
(github.event.action == 'closed' && contains(github.event.pull_request.labels.*.name, 'dedicated_redshift')) ||
(github.event.action == 'synchronize' && contains(github.event.pull_request.labels.*.name, 'dedicated_redshift'))
runs-on: ubuntu-20.04
container: python:2.7.18-buster
timeout-minutes: 20
env:
RS_HOST: ${{ secrets.RS_HOST_CD }}
Expand All @@ -30,19 +31,8 @@ jobs:
steps:
- name: Checkout repo
uses: actions/checkout@v2
- name: Set RS_PREFIX for releases
if: startsWith(github.event.pull_request.head.ref, 'release/')
run: |
echo "RS_PREFIX=dedicated_release_${{ github.event.pull_request.number }}_" >> $GITHUB_ENV
- name: Set RS_PREFIX for hotfixes
if: startsWith(github.event.pull_request.head.ref, 'hotfix/')
run: |
echo "RS_PREFIX=dedicated_hotfix_${{ github.event.pull_request.number }}_" >> $GITHUB_ENV
- name: Set RS_PREFIX for regular deploys
if: |
!(startsWith(github.event.pull_request.head.ref, 'hotfix/')) &&
!(startsWith(github.event.pull_request.head.ref, 'release/'))
run: echo "RS_PREFIX=dedicated_${{ github.event.pull_request.number }}_" >> $GITHUB_ENV
- name: Check diff
uses: technote-space/get-diff-action@v4
- name: Setup node
uses: actions/setup-node@v1
with:
Expand All @@ -58,6 +48,8 @@ jobs:
curl "https://awscli.amazonaws.com/awscli-exe-linux-x86_64.zip" -o "awscliv2.zip"
unzip awscliv2.zip
./aws/install
- name: Setup virtualenv
run: pip install virtualenv==${{ env.VIRTUALENV_VERSION }}
- name: Configure AWS Credentials
uses: aws-actions/configure-aws-credentials@v1
with:
Expand Down
21 changes: 11 additions & 10 deletions clouds/bigquery/modules/sql/quadbin/QUADBIN_FROMLONGLAT.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
----------------------------
-- Copyright (C) 2022 CARTO
----------------------------
--------------------------------
-- Copyright (C) 2022-2024 CARTO
--------------------------------

CREATE OR REPLACE FUNCTION `@@BQ_DATASET@@.QUADBIN_FROMLONGLAT`
(longitude FLOAT64, latitude FLOAT64, resolution INT64)
Expand All @@ -17,7 +17,7 @@ AS ((
resolution AS z,
(1 << resolution) AS __z2,
ACOS(-1) AS pi,
GREATEST(-85.05, LEAST(85.05, latitude)) AS latitude
GREATEST(-89, LEAST(89, latitude)) AS latitude
),

___sinlat AS (
Expand Down Expand Up @@ -47,12 +47,13 @@ AS ((
CAST(
-- floor before cast to avoid up rounding to the next tiLe
FLOOR(
__z2 * (
0.5 - 0.25
* LN(
(1 + __sinlat) / (1 - __sinlat)
) / pi
)
GREATEST(0, LEAST(__z2 - 1,
__z2 * (
0.5 - 0.25
* LN(
(1 + __sinlat) / (1 - __sinlat)
) / pi
)))
) AS INT64
) AS y
FROM
Expand Down
28 changes: 16 additions & 12 deletions clouds/bigquery/modules/sql/quadbin/QUADBIN_POLYFILL.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,9 +16,9 @@ AS ((
__params AS (
SELECT
box.xmin AS minlon,
box.ymin AS minlat,
GREATEST(-89, LEAST(89, box.ymin)) AS minlat,
box.xmax AS maxlon,
box.ymax AS maxlat,
GREATEST(-89, LEAST(89, box.ymax)) AS maxlat,
(1 << resolution) AS z2,
ACOS(-1) AS pi
FROM __bbox
Expand All @@ -37,23 +37,27 @@ AS ((
) AS xmin,
CAST(
FLOOR(
z2 * (
0.5 - 0.25 * LN(
(1 + sinlat_max) / (1 - sinlat_max)
) / pi
)
GREATEST(0, LEAST(z2 - 1,
z2 * (
0.5 - 0.25 * LN(
(1 + sinlat_max) / (1 - sinlat_max)
) / pi
)
))
) AS INT64
) AS ymin,
CAST(
FLOOR(z2 * ((maxlon / 360.0) + 0.5)) AS INT64
) AS xmax,
CAST(
FLOOR(
z2 * (
0.5 - 0.25 * LN(
(1 + sinlat_min) / (1 - sinlat_min)
) / pi
)
GREATEST(0, LEAST(z2 - 1,
z2 * (
0.5 - 0.25 * LN(
(1 + sinlat_min) / (1 - sinlat_min)
) / pi
)
))
) AS INT64
) AS ymax
FROM __params, __sinlat
Expand Down
20 changes: 18 additions & 2 deletions clouds/bigquery/modules/test/quadbin/QUADBIN_FROMLONGLAT.test.js
Original file line number Diff line number Diff line change
@@ -1,10 +1,26 @@
const { runQuery } = require('../../../common/test-utils');

test('QUADBIN_FROMLONGLAT should work', async () => {
const query = 'SELECT CAST(`@@BQ_DATASET@@.QUADBIN_FROMLONGLAT`(40.4168, -3.7038, 4) AS STRING) AS output';
const query = `
WITH inputs AS (
SELECT 1 AS id, CAST(\`@@BQ_DATASET@@.QUADBIN_FROMLONGLAT\`(40.4168, -3.7038, 4) AS STRING) AS output
UNION ALL SELECT 2, CAST(\`@@BQ_DATASET@@.QUADBIN_FROMLONGLAT\`(0, 85.05112877980659, 26) AS STRING)
UNION ALL SELECT 3, CAST(\`@@BQ_DATASET@@.QUADBIN_FROMLONGLAT\`(0, 88, 26) AS STRING)
UNION ALL SELECT 4, CAST(\`@@BQ_DATASET@@.QUADBIN_FROMLONGLAT\`(0, 90, 26) AS STRING)
UNION ALL SELECT 5, CAST(\`@@BQ_DATASET@@.QUADBIN_FROMLONGLAT\`(0, -85.05112877980659, 26) AS STRING)
UNION ALL SELECT 6, CAST(\`@@BQ_DATASET@@.QUADBIN_FROMLONGLAT\`(0, -88, 26) AS STRING)
UNION ALL SELECT 7, CAST(\`@@BQ_DATASET@@.QUADBIN_FROMLONGLAT\`(0, -90, 26) AS STRING)
)
SELECT * FROM inputs ORDER BY id ASC`;
const rows = await runQuery(query);
expect(rows.length).toEqual(1);
expect(rows.length).toEqual(7);
expect(rows[0].output).toEqual('5209574053332910079');
expect(rows[1].output).toEqual('5306366260949286912');
expect(rows[2].output).toEqual('5306366260949286912');
expect(rows[3].output).toEqual('5306366260949286912');
expect(rows[4].output).toEqual('5309368660700867242');
expect(rows[5].output).toEqual('5309368660700867242');
expect(rows[6].output).toEqual('5309368660700867242');
});

test('QUADBIN_FROMLONGLAT should return null if the input is null', async () => {
Expand Down
10 changes: 5 additions & 5 deletions clouds/postgres/modules/sql/quadbin/QUADBIN_FROMLONGLAT.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
----------------------------
-- Copyright (C) 2022 CARTO
----------------------------
--------------------------------
-- Copyright (C) 2022-2024 CARTO
--------------------------------

CREATE OR REPLACE FUNCTION @@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(
longitude DOUBLE PRECISION,
Expand All @@ -21,7 +21,7 @@ $BODY$
SELECT
resolution AS z,
(1 << resolution) AS __z2,
GREATEST(-85.05, LEAST(85.05, latitude)) AS latitude
GREATEST(-89, LEAST(89, latitude)) AS latitude
),
___sinlat AS (
SELECT
Expand All @@ -41,7 +41,7 @@ $BODY$
WHEN __x < 0 THEN __x + __z2
ELSE __x
END AS x,
(FLOOR(__z2 * (0.5 - 0.25 * (LN((1 + __sinlat)/(1 - __sinlat)) / PI()))))::BIGINT AS y
(FLOOR(GREATEST(0, LEAST(__z2 - 1, __z2 * (0.5 - 0.25 * (LN((1 + __sinlat)/(1 - __sinlat)) / PI()))))))::BIGINT AS y
FROM
__params,
___sinlat,
Expand Down
24 changes: 22 additions & 2 deletions clouds/postgres/modules/test/quadbin/test_QUADBIN_FROMLONGLAT.py
Original file line number Diff line number Diff line change
Expand Up @@ -4,8 +4,28 @@

def test_quadbin_longlat():
"""Computes quadbin for longitude latitude."""
result = run_query('SELECT @@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(40.4168, -3.7038, 4)')
assert result[0][0] == 5209574053332910079
result = run_query(
"""
WITH inputs AS (
SELECT 1 AS ID, @@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(40.4168, -3.7038, 4)
UNION ALL SELECT 2,
@@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(0, 85.05112877980659, 26)
UNION ALL SELECT 3, @@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(0, 88, 26)
UNION ALL SELECT 4, @@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(0, 90, 26)
UNION ALL SELECT 5,
@@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(0, -85.05112877980659, 26)
UNION ALL SELECT 6, @@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(0, -88, 26)
UNION ALL SELECT 7, @@PG_SCHEMA@@.QUADBIN_FROMLONGLAT(0, -90, 26)
)
SELECT * FROM inputs ORDER BY id ASC"""
)
assert result[0][1] == 5209574053332910079
assert result[1][1] == 5306366260949286912
assert result[2][1] == 5306366260949286912
assert result[3][1] == 5306366260949286912
assert result[4][1] == 5309368660700867242
assert result[5][1] == 5309368660700867242
assert result[6][1] == 5309368660700867242


def test_quadbin_longlat_null_input():
Expand Down
2 changes: 1 addition & 1 deletion clouds/redshift/libraries/python/requirements.txt
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
quadbin==0.2.0
quadbin==0.2.2
geojson==2.5.0
pygc==1.1.0
numpy==1.8.2
Expand Down
26 changes: 22 additions & 4 deletions clouds/redshift/modules/test/quadbin/test_QUADBIN_FROMLONGLAT.py
Original file line number Diff line number Diff line change
Expand Up @@ -4,10 +4,28 @@


def test_quadbin_fromlonglat():
result = run_query('SELECT @@RS_SCHEMA@@.QUADBIN_FROMLONGLAT(40.4168, -3.7038, 4)')

assert len(result[0]) == 1
assert result[0][0] == 5209574053332910079
result = run_query(
"""
WITH inputs AS (
SELECT 1 AS ID, @@RS_SCHEMA@@.QUADBIN_FROMLONGLAT(40.4168, -3.7038, 4)
UNION ALL SELECT 2,
@@RS_SCHEMA@@.QUADBIN_FROMLONGLAT(0, 85.05112877980659, 26)
UNION ALL SELECT 3, @@RS_SCHEMA@@.QUADBIN_FROMLONGLAT(0, 88, 26)
UNION ALL SELECT 4, @@RS_SCHEMA@@.QUADBIN_FROMLONGLAT(0, 90, 26)
UNION ALL SELECT 5,
@@RS_SCHEMA@@.QUADBIN_FROMLONGLAT(0, -85.05112877980659, 26)
UNION ALL SELECT 6, @@RS_SCHEMA@@.QUADBIN_FROMLONGLAT(0, -88, 26)
UNION ALL SELECT 7, @@RS_SCHEMA@@.QUADBIN_FROMLONGLAT(0, -90, 26)
)
SELECT * FROM inputs ORDER BY id ASC"""
)
assert result[0][1] == 5209574053332910079
assert result[1][1] == 5306366260949286912
assert result[2][1] == 5306366260949286912
assert result[3][1] == 5306366260949286912
assert result[4][1] == 5309368660700867242
assert result[5][1] == 5309368660700867242
assert result[6][1] == 5309368660700867242


def test_quadbin_fromlonglat_null():
Expand Down
7 changes: 3 additions & 4 deletions clouds/snowflake/modules/sql/quadbin/QUADBIN_FROMLONGLAT.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
--------------------------------
-- Copyright (C) 2022-2023 CARTO
-- Copyright (C) 2022-2024 CARTO
--------------------------------

CREATE OR REPLACE SECURE FUNCTION @@SF_SCHEMA@@.QUADBIN_FROMLONGLAT
Expand All @@ -16,14 +16,13 @@ AS $$
SELECT
resolution AS z,
ACOS(-1) AS PI,
GREATEST(-85.05, LEAST(85.05, latitude)) AS params_latitude
GREATEST(-89, LEAST(89, latitude)) AS params_latitude
),
__zxy AS (
SELECT
z,
BITAND( CAST(FLOOR(BITSHIFTLEFT(1, z) * ((longitude / 360.0) + 0.5)) AS INT), (BITSHIFTLEFT(1, z) - 1)) AS x,
BITAND( CAST(FLOOR(BITSHIFTLEFT(1, z) * (0.5 - (LN(TAN(PI/4.0 + params_latitude/2.0 * PI/180.0)) / (2*PI)))) AS INT),
(BITSHIFTLEFT(1, z) - 1)) AS y
BITAND( CAST(FLOOR(GREATEST(0, LEAST(BITSHIFTLEFT(1, z) - 1, BITSHIFTLEFT(1, z) * (0.5 - (LN(TAN(PI/4.0 + params_latitude/2.0 * PI/180.0)) / (2*PI)))))) AS INT),(BITSHIFTLEFT(1, z) - 1)) AS y
FROM __params
)
SELECT @@SF_SCHEMA@@.QUADBIN_FROMZXY(z, x, y)
Expand Down
20 changes: 18 additions & 2 deletions clouds/snowflake/modules/test/quadbin/QUADBIN_FROMLONGLAT.test.js
Original file line number Diff line number Diff line change
@@ -1,8 +1,24 @@
const { runQuery } = require('../../../common/test-utils');

test('QUADBIN_FROMLONGLAT should work', async () => {
const query = 'SELECT CAST(QUADBIN_FROMLONGLAT(40.4168, -3.7038, 4) AS STRING) AS OUTPUT';
const query = `
WITH inputs AS (
SELECT 1 AS ID, CAST(QUADBIN_FROMLONGLAT(40.4168, -3.7038, 4) AS STRING) AS OUTPUT
UNION ALL SELECT 2, CAST(QUADBIN_FROMLONGLAT(0, 85.05112877980659, 26) AS STRING)
UNION ALL SELECT 3, CAST(QUADBIN_FROMLONGLAT(0, 88, 26) AS STRING)
UNION ALL SELECT 4, CAST(QUADBIN_FROMLONGLAT(0, 90, 26) AS STRING)
UNION ALL SELECT 5, CAST(QUADBIN_FROMLONGLAT(0, -85.05112877980659, 26) AS STRING)
UNION ALL SELECT 6, CAST(QUADBIN_FROMLONGLAT(0, -88, 26) AS STRING)
UNION ALL SELECT 7, CAST(QUADBIN_FROMLONGLAT(0, -90, 26) AS STRING)
)
SELECT * FROM inputs ORDER BY id ASC`;
const rows = await runQuery(query);
expect(rows.length).toEqual(1);
expect(rows.length).toEqual(7);
expect(rows[0].OUTPUT).toEqual('5209574053332910079');
expect(rows[1].OUTPUT).toEqual('5306366260949286912');
expect(rows[2].OUTPUT).toEqual('5306366260949286912');
expect(rows[3].OUTPUT).toEqual('5306366260949286912');
expect(rows[4].OUTPUT).toEqual('5309368660700867242');
expect(rows[5].OUTPUT).toEqual('5309368660700867242');
expect(rows[6].OUTPUT).toEqual('5309368660700867242');
});

0 comments on commit b0a6e08

Please sign in to comment.