add search filtering based on foil card inventory amounts

This commit is contained in:
Gered 2016-06-29 14:41:10 -04:00
parent 5fe5568e2a
commit 2e0644057e
4 changed files with 114 additions and 50 deletions

View file

@ -0,0 +1,5 @@
DROP TRIGGER IF EXISTS cards_update_owned_foil_count_trigger ON collection;
DROP FUNCTION IF EXISTS update_card_owned_foil_count();
ALTER TABLE cards DROP COLUMN IF EXISTS owned_foil_count;

View file

@ -0,0 +1,49 @@
ALTER TABLE cards ADD COLUMN owned_foil_count INT NOT NULL DEFAULT 0;
CREATE INDEX cards_owned_foil_count_idx ON cards (owned_foil_count);
--
-- trigger to run whenever a collection row is added/updated that fills in
-- the owned_foil_count column in the corresponding card
--
CREATE OR REPLACE FUNCTION update_card_owned_foil_count()
RETURNS TRIGGER
AS $update_card_owned_foil_count$
DECLARE
update_card_id TEXT;
BEGIN
IF (TG_OP = 'DELETE') THEN
update_card_id = OLD.card_id;
ELSE
update_card_id = NEW.card_id;
END IF;
UPDATE cards
SET
owned_foil_count = (
SELECT COALESCE(SUM(quantity), 0)
FROM collection cl
WHERE cl.card_id = update_card_id AND cl.foil = TRUE
)
WHERE id = update_card_id;
RETURN NULL;
END;
$update_card_owned_foil_count$ LANGUAGE plpgsql;
CREATE TRIGGER cards_update_owned_foil_count_trigger
AFTER INSERT OR UPDATE OR DELETE ON collection
FOR EACH ROW EXECUTE PROCEDURE update_card_owned_foil_count();
--
-- fill in owned_foil_count in any existing cards
--
UPDATE cards c
SET
owned_foil_count = (
SELECT COALESCE(SUM(quantity), 0)
FROM collection cl
WHERE cl.card_id = c.id AND cl.foil = TRUE
);

View file

@ -130,7 +130,9 @@
:power {:label "Power" :type :text :comparisons [:=]}
:toughness {:label "Toughness" :type :text :comparisons [:=]}
:owned? {:label "Owned?" :type :boolean :comparisons [:=]}
:owned-foil? {:label "Owned Foil?" :type :boolean :comparisons [:=]}
:owned-count {:label "Owned Amount" :type :numeric :comparisons [:= :> :<] :validation-fn valid-integer? :transform-fn js/parseInt}
:owned-foil-count {:label "Owned Foil Amount" :type :numeric :comparisons [:= :> :<] :validation-fn valid-integer? :transform-fn js/parseInt}
:paper-price {:label "Price (Paper)" :type :numeric :comparisons [:= :> :<] :validation-fn valid-float? :transform-fn js/parseFloat}
:online-price {:label "Price (Online)" :type :numeric :comparisons [:= :> :<] :validation-fn valid-float? :transform-fn js/parseFloat}})

View file

@ -66,7 +66,8 @@
s.online_only,
c.paper_price,
c.online_price,
c.owned_count
c.owned_count,
c.owned_foil_count
from cards c
join sets s on c.set_code = s.code
where c.id = ?" id])
@ -163,13 +164,19 @@
:power (text-comparison-fn [:power] true)
:toughness (text-comparison-fn [:toughness] true)
:owned-count (numeric-comparison-fn [:owned_count])
:owned-foil-count (numeric-comparison-fn [:owned_foil_count])
:paper-price (numeric-comparison-fn [:paper_price])
:online-price (numeric-comparison-fn [:online_price])
:owned? (fn [value comparison]
(assert (= := comparison))
(case value
true [:> :owned_count 0]
false [:= :owned_count 0]))})
false [:= :owned_count 0]))
:owned-foil? (fn [value comparison]
(assert (= := comparison))
(case value
true [:> :owned_foil_count 0]
false [:= :owned_foil_count 0]))})
(defn- filter->hsql-where-criteria
[{:keys [field value comparison]}]
@ -199,7 +206,8 @@
:c.loyalty
:c.paper_price
:c.online_price
:c.owned_count]
:c.owned_count
:c.owned_foil_count]
:from [[:cards :c]]
:join [[:sets :s] [:= :c.set_code :s.code]]}
(if order-by