Skip to content

Commit

Permalink
Fix room SQL query
Browse files Browse the repository at this point in the history
  • Loading branch information
Serious-senpai committed Dec 19, 2024
1 parent a5ad167 commit 3ff19b6
Show file tree
Hide file tree
Showing 4 changed files with 50 additions and 49 deletions.
6 changes: 3 additions & 3 deletions app/resident_manager/lib/src/widgets/admin/residents.dart
Original file line number Diff line number Diff line change
Expand Up @@ -368,9 +368,9 @@ class _ResidentsPageState extends AbstractCommonState<ResidentsPage> with Common

@override
void initState() {
final room = state.extras["room-search"] as Room?;
if (room != null) {
this.room = room.room.toString();
final r = state.extras["room-search"] as int?;
if (r != null) {
room = r.toString();
state.extras["room-search"] = null;
}

Expand Down
6 changes: 3 additions & 3 deletions app/resident_manager/lib/src/widgets/admin/rooms.dart
Original file line number Diff line number Diff line change
Expand Up @@ -311,9 +311,9 @@ class _RoomsPageState extends AbstractCommonState<RoomsPage> with CommonScaffold
children: [
IconButton(
icon: const Icon(Icons.search_outlined),
onPressed: () async {
state.extras["room-search"] = room;
await Navigator.pushReplacementNamed(context, ApplicationRoute.adminResidentsPage);
onPressed: () {
state.extras["room-search"] = r.room;
Navigator.pushReplacementNamed(context, ApplicationRoute.adminResidentsPage);
},
),
IconButton(
Expand Down
30 changes: 30 additions & 0 deletions scripts/procedures/query_rooms.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
CREATE OR ALTER PROCEDURE QueryRooms
@Room SMALLINT,
@Floor SMALLINT,
@Offset INT,
@FetchNext INT
AS
BEGIN
SET NOCOUNT ON;

WITH all_rooms (room, area, motorbike, car, residents) AS (
SELECT
IIF(rooms.room IS NULL, approved_residents.room, rooms.room),
area,
motorbike,
car,
IIF(residents IS NULL, 0, residents)
FROM rooms
FULL OUTER JOIN (
SELECT room, COUNT(1) AS residents
FROM accounts
WHERE approved = 1
GROUP BY room
) AS approved_residents ON rooms.room = approved_residents.room
)
SELECT * FROM all_rooms
WHERE (@Room IS NULL OR @Room = room) AND (@Floor IS NULL OR @Floor = room / 100)
ORDER BY room
OFFSET @Offset ROWS
FETCH NEXT @FetchNext ROWS ONLY
END
57 changes: 14 additions & 43 deletions server/v1/models/rooms.py
Original file line number Diff line number Diff line change
Expand Up @@ -169,13 +169,9 @@ async def count(
"""
WITH rooms_union AS (
SELECT t1.room FROM rooms t1
UNION ALL
SELECT DISTINCT t2.room FROM accounts t2
WHERE t2.approved = 1 AND NOT EXISTS (
SELECT 1
FROM rooms
WHERE rooms.room = t2.room
)
UNION
SELECT t2.room FROM accounts t2
WHERE t2.approved = 1
)
SELECT COUNT(1) FROM rooms_union
""",
Expand Down Expand Up @@ -216,44 +212,19 @@ async def query(
"""
async with Database.instance.pool.acquire() as connection:
async with connection.cursor() as cursor:
having: List[str] = []
params: List[Any] = []

if room is not None:
having.append("ru.room = ?")
params.append(room)

if floor is not None:
having.append("ru.room / 100 = ?")
params.append(floor)

query = [
await cursor.execute(
"""
WITH rooms_union (room, area, motorbike, car) AS (
SELECT t1.room, t1.area, t1.motorbike, t1.car
FROM rooms t1
UNION ALL
SELECT DISTINCT t2.room, NULL, NULL, NULL
FROM accounts t2
WHERE t2.approved = 1 AND NOT EXISTS (
SELECT 1
FROM rooms
WHERE rooms.room = t2.room
)
)
SELECT ru.room, ru.area, ru.motorbike, ru.car, COUNT(1) AS residents
FROM rooms_union ru
LEFT JOIN accounts ON ru.room = accounts.room
GROUP BY ru.room, ru.area, ru.motorbike, ru.car
EXECUTE QueryRooms
@Room = ?,
@Floor = ?,
@Offset = ?,
@FetchNext = ?
""",
]

if len(having) > 0:
query.append("HAVING " + " AND ".join(having))

query.append("ORDER BY ru.room OFFSET ? ROWS FETCH NEXT ? ROWS ONLY")

await cursor.execute("\n".join(query), *params, offset, DB_PAGINATION_QUERY)
room,
floor,
offset,
DB_PAGINATION_QUERY,
)

rows = await cursor.fetchall()
return [cls.from_row(row) for row in rows]

0 comments on commit 3ff19b6

Please sign in to comment.