Skip to content

Commit

Permalink
Fix boolean handling under Postgres
Browse files Browse the repository at this point in the history
The change in cce5bf9 fixed booleans on older SQLite versions, but broke
the queries for Postgres. This is a workaround that should make both
databases happy.
Since Postgres is extra pedantic in CASE epxressions, the complex order
position queries had to be moved to the set of dialect-specific queries.
  • Loading branch information
antweb committed Nov 22, 2024
1 parent 0f07d21 commit 707279d
Show file tree
Hide file tree
Showing 9 changed files with 97 additions and 54 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -1043,7 +1043,7 @@ class AsyncCheckProvider(private val config: ConfigStore, private val db: SyncDa
true
}

val positions = db.orderPositionQueries.search(
val positions = db.compatQueries.searchOrderPosition(
queryStartsWith = "$query%",
queryContains = "%$query%",
use_event_filter = useEventFilter,
Expand Down Expand Up @@ -1163,7 +1163,7 @@ class AsyncCheckProvider(private val config: ConfigStore, private val db: SyncDa
}

for (`var` in product.variations) {
val position_count = db.orderPositionQueries.countForStatus(
val position_count = db.compatQueries.countOrderPositionForStatus(
event_slug = list.eventSlug,
include_pending = list.includePending,
subevent_id = subEventId,
Expand All @@ -1174,7 +1174,7 @@ class AsyncCheckProvider(private val config: ConfigStore, private val db: SyncDa
variation_id = `var`.server_id,
).executeAsOne().toInt()

val ci_count = db.orderPositionQueries.countForStatus(
val ci_count = db.compatQueries.countOrderPositionForStatus(
event_slug = list.eventSlug,
include_pending = list.includePending,
subevent_id = subEventId,
Expand All @@ -1193,7 +1193,7 @@ class AsyncCheckProvider(private val config: ConfigStore, private val db: SyncDa
))
}

val position_count = db.orderPositionQueries.countForStatus(
val position_count = db.compatQueries.countOrderPositionForStatus(
event_slug = list.eventSlug,
include_pending = list.includePending,
subevent_id = subEventId,
Expand All @@ -1204,7 +1204,7 @@ class AsyncCheckProvider(private val config: ConfigStore, private val db: SyncDa
variation_id = -1L,
).executeAsOne().toInt()

val ci_count = db.orderPositionQueries.countForStatus(
val ci_count = db.compatQueries.countOrderPositionForStatus(
event_slug = list.eventSlug,
include_pending = list.includePending,
subevent_id = subEventId,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,7 @@ selectDefaultForEventSlug:
SELECT *
FROM BadgeLayout
WHERE
is_default = 1
CAST(is_default AS INTEGER) = 1
AND event_slug = ?;

insert:
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -16,15 +16,15 @@ WHERE event_slug = ?;
countBlockedForSecret:
SELECT COUNT(*)
FROM BlockedTicketSecret
WHERE blocked = 1 AND secret = ?;
WHERE CAST(blocked AS INTEGER) = 1 AND secret = ?;

deleteByServerId:
DELETE FROM BlockedTicketSecret
WHERE server_id = ?;

deleteNotBlocked:
DELETE FROM BlockedTicketSecret
WHERE blocked = 0;
WHERE CAST(blocked AS INTEGER) = 0;

insert:
INSERT INTO BlockedTicketSecret(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ selectClosedWithoutServerId:
SELECT *
FROM Closing
WHERE
open = 0
CAST(open AS INTEGER) = 0
AND server_id IS NULL;

insert:
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -80,46 +80,3 @@ SET
subevent_id = ?,
variation_id = ?
WHERE id = ?;

search:
SELECT OrderPosition.*
FROM OrderPosition
LEFT JOIN orders ON OrderPosition.order_ref = orders.id
LEFT JOIN Item ON OrderPosition.item = Item.id
WHERE (
UPPER(OrderPosition.secret) LIKE :queryStartsWith
OR UPPER(OrderPosition.attendee_name) LIKE :queryContains
OR UPPER(OrderPosition.attendee_email) LIKE :queryContains
OR UPPER(orders.email) LIKE :queryContains
OR UPPER(orders.code) LIKE :queryStartsWith
)
AND (
CASE WHEN (:use_event_filter) THEN (orders.event_slug IN :event_filter) ELSE 0 END
OR CASE WHEN (:use_event_item_filter) THEN (orders.event_slug IN :event_item_filter_events AND OrderPosition.item IN :event_item_filter_items) ELSE 0 END
OR CASE WHEN (:use_event_subevent_filter) THEN (orders.event_slug IN :event_subevent_filter_events AND OrderPosition.subevent_id IN :event_subevent_filter_subevents) ELSE 0 END
OR CASE WHEN (:use_all_filter) THEN (orders.event_slug IN :all_filter_events AND OrderPosition.item IN :all_filter_items AND OrderPosition.subevent_id IN :all_filter_subevents) ELSE 0 END
)
LIMIT :limit
OFFSET :offset;

countForStatus:
-- TODO: Check if DISTINCT is required here
SELECT COUNT(DISTINCT OrderPosition.id)
FROM OrderPosition
LEFT JOIN orders ON OrderPosition.order_ref = orders.id
WHERE(
orders.event_slug = :event_slug
AND CASE WHEN (:include_pending)
THEN orders.status IN ('p', 'n')
ELSE (orders.status = 'p' OR (orders.status = 'n' AND orders.valid_if_pending = 1))
END
AND CASE WHEN (:subevent_id > 0) THEN OrderPosition.subevent_id = :subevent_id ELSE 1 END
AND CASE WHEN (:not_all_items) THEN OrderPosition.item IN :list_item_ids ELSE 1 END
AND CASE WHEN (:only_checked_in_list_server_id > 0) THEN
(OrderPosition.id IN (SELECT position FROM CheckIn WHERE listId = :only_checked_in_list_server_id AND type = 'entry'))
ELSE
1
END
AND OrderPosition.item = :item_id
AND CASE WHEN (:variation_id > 0) THEN OrderPosition.variation_id = :variation_id ELSE 1 END
);
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ WHERE id = ?;
selectUnlockedWithoutError:
SELECT *
FROM QueuedOrder
WHERE locked = 0 AND error IS NULL;
WHERE CAST(locked AS INTEGER) = 0 AND error IS NULL;

delete:
DELETE FROM QueuedOrder
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,7 @@ selectDefaultForEventSlug:
SELECT *
FROM TicketLayout
WHERE
is_default = 1
CAST(is_default AS INTEGER) = 1
AND event_slug = ?;

deleteByServerId:
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -74,3 +74,46 @@ TRUNCATE
SubEvent,
TaxRule,
TicketLayout;

searchOrderPosition:
SELECT OrderPosition.*
FROM OrderPosition
LEFT JOIN orders ON OrderPosition.order_ref = orders.id
LEFT JOIN Item ON OrderPosition.item = Item.id
WHERE (
UPPER(OrderPosition.secret) LIKE :queryStartsWith
OR UPPER(OrderPosition.attendee_name) LIKE :queryContains
OR UPPER(OrderPosition.attendee_email) LIKE :queryContains
OR UPPER(orders.email) LIKE :queryContains
OR UPPER(orders.code) LIKE :queryStartsWith
)
AND (
CASE WHEN (:use_event_filter) THEN (orders.event_slug IN :event_filter) ELSE FALSE END
OR CASE WHEN (:use_event_item_filter) THEN (orders.event_slug IN :event_item_filter_events AND OrderPosition.item IN :event_item_filter_items) ELSE FALSE END
OR CASE WHEN (:use_event_subevent_filter) THEN (orders.event_slug IN :event_subevent_filter_events AND OrderPosition.subevent_id IN :event_subevent_filter_subevents) ELSE FALSE END
OR CASE WHEN (:use_all_filter) THEN (orders.event_slug IN :all_filter_events AND OrderPosition.item IN :all_filter_items AND OrderPosition.subevent_id IN :all_filter_subevents) ELSE FALSE END
)
LIMIT :limit
OFFSET :offset;

countOrderPositionForStatus:
-- TODO: Check if DISTINCT is required here
SELECT COUNT(DISTINCT OrderPosition.id)
FROM OrderPosition
LEFT JOIN orders ON OrderPosition.order_ref = orders.id
WHERE(
orders.event_slug = :event_slug
AND CASE WHEN (:include_pending)
THEN orders.status IN ('p', 'n')
ELSE (orders.status = 'p' OR (orders.status = 'n' AND orders.valid_if_pending = TRUE))
END
AND CASE WHEN (:subevent_id > 0) THEN OrderPosition.subevent_id = :subevent_id ELSE TRUE END
AND CASE WHEN (:not_all_items) THEN OrderPosition.item IN :list_item_ids ELSE TRUE END
AND CASE WHEN (:only_checked_in_list_server_id > 0) THEN
(OrderPosition.id IN (SELECT position FROM CheckIn WHERE listId = :only_checked_in_list_server_id AND type = 'entry'))
ELSE
TRUE
END
AND OrderPosition.item = :item_id
AND CASE WHEN (:variation_id > 0) THEN OrderPosition.variation_id = :variation_id ELSE TRUE END
);
Original file line number Diff line number Diff line change
Expand Up @@ -74,3 +74,46 @@ truncateAllTables {
DELETE FROM TaxRule;
DELETE FROM TicketLayout;
}

searchOrderPosition:
SELECT OrderPosition.*
FROM OrderPosition
LEFT JOIN orders ON OrderPosition.order_ref = orders.id
LEFT JOIN Item ON OrderPosition.item = Item.id
WHERE (
UPPER(OrderPosition.secret) LIKE :queryStartsWith
OR UPPER(OrderPosition.attendee_name) LIKE :queryContains
OR UPPER(OrderPosition.attendee_email) LIKE :queryContains
OR UPPER(orders.email) LIKE :queryContains
OR UPPER(orders.code) LIKE :queryStartsWith
)
AND (
CASE WHEN (:use_event_filter) THEN (orders.event_slug IN :event_filter) ELSE 0 END
OR CASE WHEN (:use_event_item_filter) THEN (orders.event_slug IN :event_item_filter_events AND OrderPosition.item IN :event_item_filter_items) ELSE 0 END
OR CASE WHEN (:use_event_subevent_filter) THEN (orders.event_slug IN :event_subevent_filter_events AND OrderPosition.subevent_id IN :event_subevent_filter_subevents) ELSE 0 END
OR CASE WHEN (:use_all_filter) THEN (orders.event_slug IN :all_filter_events AND OrderPosition.item IN :all_filter_items AND OrderPosition.subevent_id IN :all_filter_subevents) ELSE 0 END
)
LIMIT :limit
OFFSET :offset;

countOrderPositionForStatus:
-- TODO: Check if DISTINCT is required here
SELECT COUNT(DISTINCT OrderPosition.id)
FROM OrderPosition
LEFT JOIN orders ON OrderPosition.order_ref = orders.id
WHERE(
orders.event_slug = :event_slug
AND CASE WHEN (:include_pending)
THEN orders.status IN ('p', 'n')
ELSE (orders.status = 'p' OR (orders.status = 'n' AND orders.valid_if_pending = 1))
END
AND CASE WHEN (:subevent_id > 0) THEN OrderPosition.subevent_id = :subevent_id ELSE 1 END
AND CASE WHEN (:not_all_items) THEN OrderPosition.item IN :list_item_ids ELSE 1 END
AND CASE WHEN (:only_checked_in_list_server_id > 0) THEN
(OrderPosition.id IN (SELECT position FROM CheckIn WHERE listId = :only_checked_in_list_server_id AND type = 'entry'))
ELSE
1
END
AND OrderPosition.item = :item_id
AND CASE WHEN (:variation_id > 0) THEN OrderPosition.variation_id = :variation_id ELSE 1 END
);

0 comments on commit 707279d

Please sign in to comment.