Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix 5122 add PostgreSql lateral join operator for subquery #5337

Draft
wants to merge 2 commits into
base: master
Choose a base branch
from

Conversation

griffio
Copy link
Contributor

@griffio griffio commented Jul 8, 2024

fixes #5122

🏗️ 🚧 ⛑️ Initial attempt at LATERAL join operator support in subqueries

Not supported: Table expressions e.g json, arrays, sets

Note: currently using wildcard * columns, incorrectly adds subquery columns to top level results

Supported queries

CREATE TABLE A (
  b_id INTEGER
);

CREATE TABLE B (
  id INTEGER
);

SELECT * FROM A, LATERAL (SELECT * FROM B WHERE B.id = A.b_id) AB;

CREATE TABLE Author (
  id INTEGER PRIMARY KEY,
  name TEXT
);

CREATE TABLE Genre (
  id INTEGER PRIMARY KEY,
  name TEXT
);

CREATE TABLE Book (
  id INTEGER PRIMARY KEY,
  title TEXT,
  author_id INTEGER REFERENCES Author(id),
  genre_id INTEGER REFERENCES Genre(id)
);

SELECT
  Author.name AS author_name,
  Genre.name AS genre_name,
  book_count
FROM
  Author,
  Genre,
  LATERAL (
    SELECT
      COUNT(*) AS book_count
    FROM
      Book
    WHERE
      Book.author_id = Author.id
      AND Book.genre_id = Genre.id
  ) AS book_counts;

CREATE TABLE Kickstarter_Data (
    pledged INTEGER,
    fx_rate NUMERIC,
    backers_count INTEGER,
    launched_at NUMERIC,
    deadline NUMERIC,
    goal INTEGER
);

SELECT
    pledged_usd,
    avg_pledge_usd,
    duration,
    (usd_from_goal / duration) AS usd_needed_daily
FROM Kickstarter_Data,
    LATERAL (SELECT pledged / fx_rate AS pledged_usd) pu,
    LATERAL (SELECT pledged_usd / backers_count AS avg_pledge_usd) apu,
    LATERAL (SELECT goal / fx_rate AS goal_usd) gu,
    LATERAL (SELECT goal_usd - pledged_usd AS usd_from_goal) ufg,
    LATERAL (SELECT (deadline - launched_at) / 86400.00 AS duration) dr;

CREATE TABLE Regions (
  id INTEGER,
  name VARCHAR(255)
);

CREATE TABLE SalesPeople (
  id INTEGER,
  full_name VARCHAR(255),
  home_region_id INTEGER
);

CREATE TABLE Sales (
  id INTEGER,
  amount NUMERIC,
  product_id INTEGER,
  salesperson_id INTEGER,
  region_id INTEGER
);

SELECT
  sp.id salesperson_id,
  sp.full_name,
  sp.home_region_id,
  rg.name AS home_region_name,
  home_region_sales.total_sales
FROM SalesPeople sp
  JOIN Regions rg ON sp.home_region_id = rg.id
  JOIN LATERAL (
    SELECT SUM(amount) AS total_sales
    FROM Sales s
    WHERE s.salesperson_id = sp.id
      AND s.region_id = sp.home_region_id
  ) home_region_sales ON TRUE;

@griffio griffio force-pushed the fix-5122-add-postgresql-lateral-subquery branch from 47761ec to bf5155a Compare July 8, 2024 17:45
LATERAL is used in two positions in the join_operator - for table subqueries and for table joins

Add Mixin to expose table/columns in a subquery - avoid recursion stackoverflow if child is same as subquery
Fixture tests
@griffio griffio force-pushed the fix-5122-add-postgresql-lateral-subquery branch from bf5155a to c27103e Compare July 10, 2024 15:35
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

[PostgreSQL Dialect]: Support LATERAL Subqueries
1 participant