Skip to content

Commit

Permalink
materialized view should actually use column data
Browse files Browse the repository at this point in the history
fix get assignments endpoint
  • Loading branch information
raphaellaude committed Oct 8, 2024
1 parent b09e265 commit 64be91d
Show file tree
Hide file tree
Showing 8 changed files with 151 additions and 20 deletions.
4 changes: 3 additions & 1 deletion backend/app/alembic/env.py
Original file line number Diff line number Diff line change
Expand Up @@ -45,7 +45,9 @@ def get_url():

def include_object(object, name, type_, reflected, compare_to):
if name and (
name == "spatial_ref_sys" or re.match(r"document.assignments_.+", name)
name == "spatial_ref_sys"
or re.match(r"document.assignments_.+", name)
or re.match(r"parentchildedges_.+", name)
):
return False
return True
Expand Down
89 changes: 89 additions & 0 deletions backend/app/alembic/versions/5c4028ff26df_update_pop_udf.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
"""update pop udf
Revision ID: 5c4028ff26df
Revises: ccb2a6b81a8b
Create Date: 2024-10-07 20:30:15.230254
"""

from typing import Sequence, Union

from alembic import op
import sqlalchemy as sa
from app.constants import SQL_DIR


# revision identifiers, used by Alembic.
revision: str = "5c4028ff26df"
down_revision: Union[str, None] = "ccb2a6b81a8b"
branch_labels: Union[str, Sequence[str], None] = None
depends_on: Union[str, Sequence[str], None] = None


def upgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
op.create_unique_constraint("districtr_map_uuid_unique", "districtrmap", ["uuid"])
op.create_unique_constraint(
"districtr_map_parent_child_edge_unique",
"parentchildedges",
["districtr_map", "parent_path", "child_path"],
)
with open(f"{SQL_DIR}/total_pop_udf.sql") as f:
query = f.read()
op.execute(sa.text(query))
# ### end Alembic commands ###


def downgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
op.drop_constraint(
"districtr_map_parent_child_edge_unique", "parentchildedges", type_="unique"
)
op.drop_constraint("districtr_map_uuid_unique", "districtrmap", type_="unique")
op.execute(
sa.text("""
CREATE OR REPLACE FUNCTION get_total_population(document_id UUID)
RETURNS TABLE (zone TEXT, total_pop BIGINT) AS $$
DECLARE
gerrydb_table_name TEXT;
sql_query TEXT;
total_pop_column_name TEXT;
BEGIN
SELECT districtrmap.parent_layer INTO gerrydb_table_name
FROM document.document
LEFT JOIN districtrmap
ON document.gerrydb_table = districtrmap.gerrydb_table_name
WHERE document.document_id = $1;
IF gerrydb_table_name IS NULL THEN
RAISE EXCEPTION 'Table name not found for document_id: %', $1;
END IF;
SELECT column_name INTO total_pop_column_name
FROM INFORMATION_SCHEMA.COLUMNS
WHERE table_name = gerrydb_table_name
AND table_schema = 'gerrydb'
AND column_name IN ('total_pop', 'total_vap')
ORDER BY column_name ASC
LIMIT 1;
IF total_pop_column_name IS NULL THEN
RAISE EXCEPTION 'Population column not found for gerrydbview %', gerrydb_table_name;
END IF;
sql_query := format('
SELECT
assignments.zone::TEXT AS zone,
SUM(COALESCE(blocks.%I, 0))::BIGINT AS total_pop
FROM document.assignments
LEFT JOIN gerrydb.%I blocks
ON blocks.path = assignments.geo_id
WHERE assignments.document_id = $1
GROUP BY assignments.zone
', total_pop_column_name, gerrydb_table_name);
RETURN QUERY EXECUTE sql_query USING $1;
END;
$$ LANGUAGE plpgsql;
""")
)
# ### end Alembic commands ###
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,6 @@

from alembic import op
import sqlalchemy as sa
from app.constants import SQL_DIR


# revision identifiers, used by Alembic.
Expand All @@ -22,9 +21,52 @@

def upgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
with open(f"{SQL_DIR}/total_pop_udf.sql") as f:
query = f.read()
op.execute(sa.text(query))
op.execute(
sa.text("""
CREATE OR REPLACE FUNCTION get_total_population(document_id UUID)
RETURNS TABLE (zone TEXT, total_pop BIGINT) AS $$
DECLARE
gerrydb_table_name TEXT;
sql_query TEXT;
total_pop_column_name TEXT;
BEGIN
SELECT districtrmap.parent_layer INTO gerrydb_table_name
FROM document.document
LEFT JOIN districtrmap
ON document.gerrydb_table = districtrmap.gerrydb_table_name
WHERE document.document_id = $1;
IF gerrydb_table_name IS NULL THEN
RAISE EXCEPTION 'Table name not found for document_id: %', $1;
END IF;
SELECT column_name INTO total_pop_column_name
FROM INFORMATION_SCHEMA.COLUMNS
WHERE table_name = gerrydb_table_name
AND table_schema = 'gerrydb'
AND column_name IN ('total_pop', 'total_vap')
ORDER BY column_name ASC
LIMIT 1;
IF total_pop_column_name IS NULL THEN
RAISE EXCEPTION 'Population column not found for gerrydbview %', gerrydb_table_name;
END IF;
sql_query := format('
SELECT
assignments.zone::TEXT AS zone,
SUM(COALESCE(blocks.%I, 0))::BIGINT AS total_pop
FROM document.assignments
LEFT JOIN gerrydb.%I blocks
ON blocks.path = assignments.geo_id
WHERE assignments.document_id = $1
GROUP BY assignments.zone
', total_pop_column_name, gerrydb_table_name);
RETURN QUERY EXECUTE sql_query USING $1;
END;
$$ LANGUAGE plpgsql;
""")
)
# ### end Alembic commands ###


Expand Down
1 change: 0 additions & 1 deletion backend/app/alembic/versions/ccb2a6b81a8b_shattering.py
Original file line number Diff line number Diff line change
Expand Up @@ -93,7 +93,6 @@ def upgrade() -> None:
"create_shatterable_gerrydb_view.sql",
"create_districtr_map_udf.sql",
"shatter_parent.sql",
"total_pop_udf.sql",
]:
with open(SQL_PATH / file_name, "r") as f:
sql = f.read()
Expand Down
8 changes: 5 additions & 3 deletions backend/app/main.py
Original file line number Diff line number Diff line change
Expand Up @@ -181,12 +181,14 @@ async def get_assignments(document_id: str, session: Session = Depends(get_sessi
Assignments.document_id,
ParentChildEdges.parent_path,
)
.outerjoin(ParentChildEdges, Assignments.geo_id == ParentChildEdges.child_path)
.join(DistrictrMap, ParentChildEdges.districtr_map == DistrictrMap.uuid)
.join(Document, Assignments.document_id == Document.document_id)
.join(
DistrictrMap,
Document.gerrydb_table == DistrictrMap.gerrydb_table_name,
)
.outerjoin(ParentChildEdges, Assignments.geo_id == ParentChildEdges.child_path)
.where(
Assignments.document_id == document_id,
DistrictrMap.gerrydb_table_name == Document.gerrydb_table
)
)

Expand Down
4 changes: 2 additions & 2 deletions backend/app/sql/create_shatterable_gerrydb_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -31,9 +31,9 @@ BEGIN

sql_query := format('
CREATE MATERIALIZED VIEW gerrydb.%I AS
SELECT %L FROM gerrydb.%I
SELECT %s FROM gerrydb.%I
UNION ALL
SELECT %L
SELECT %s
FROM gerrydb.%I
', gerrydb_table_name, col_list, parent_gerrydb_table_name, col_list, child_gerrydb_table_name);

Expand Down
12 changes: 6 additions & 6 deletions backend/app/sql/total_pop_udf.sql
Original file line number Diff line number Diff line change
@@ -1,30 +1,30 @@
CREATE OR REPLACE FUNCTION get_total_population(document_id UUID)
RETURNS TABLE (zone TEXT, total_pop BIGINT) AS $$
DECLARE
gerrydb_table_name TEXT;
doc_districtrmap RECORD;
sql_query TEXT;
total_pop_column_name TEXT;
BEGIN
SELECT districtrmap.parent_layer INTO gerrydb_table_name
SELECT districtrmap.* INTO doc_districtrmap
FROM document.document
LEFT JOIN districtrmap
ON document.gerrydb_table = districtrmap.gerrydb_table_name
WHERE document.document_id = $1;

IF gerrydb_table_name IS NULL THEN
IF doc_districtrmap.gerrydb_table_name IS NULL THEN
RAISE EXCEPTION 'Table name not found for document_id: %', $1;
END IF;

SELECT column_name INTO total_pop_column_name
FROM INFORMATION_SCHEMA.COLUMNS
WHERE table_name = gerrydb_table_name
WHERE table_name = doc_districtrmap.parent_layer
AND table_schema = 'gerrydb'
AND column_name IN ('total_pop', 'total_vap')
ORDER BY column_name ASC
LIMIT 1;

IF total_pop_column_name IS NULL THEN
RAISE EXCEPTION 'Population column not found for gerrydbview %', gerrydb_table_name;
RAISE EXCEPTION 'Population column not found for gerrydbview %', doc_districtrmap.gerrydb_table_name;
END IF;

sql_query := format('
Expand All @@ -36,7 +36,7 @@ BEGIN
ON blocks.path = assignments.geo_id
WHERE assignments.document_id = $1
GROUP BY assignments.zone
', total_pop_column_name, gerrydb_table_name);
', total_pop_column_name, doc_districtrmap.gerrydb_table_name);
RETURN QUERY EXECUTE sql_query USING $1;
END;
$$ LANGUAGE plpgsql;
3 changes: 0 additions & 3 deletions backend/tests/conftest.py
Original file line number Diff line number Diff line change
Expand Up @@ -21,9 +21,6 @@ def client_fixture(session: Session):
def get_session_override():
return session

def get_auth_result_override():
return True

app.dependency_overrides[get_session] = get_session_override

client = TestClient(app, headers={"origin": "http://localhost:5173"})
Expand Down

0 comments on commit 64be91d

Please sign in to comment.