Store payout receipt as postgresql jsonb

* store bounty payout receipt as a jsonb object in the database
  instead of a varchar containing json
This commit is contained in:
Teemu Patja 2017-03-09 21:50:57 +02:00
parent 2d788cad32
commit 219d697fee
No known key found for this signature in database
GPG Key ID: F5B7035E6580FD4C
6 changed files with 105 additions and 5 deletions

View File

@ -0,0 +1,91 @@
drop view if exists activity_feed_view cascade;
drop view if exists claims_view cascade;
drop view if exists bounties_view cascade;
ALTER TABLE "public"."issues" ALTER COLUMN "payout_receipt" TYPE jsonb USING "payout_receipt"::jsonb;
create view claims_view as
SELECT i.title AS issue_title,
i.issue_number,
r.repo AS repo_name,
r.owner AS repo_owner,
u.name AS user_name,
u.avatar_url AS user_avatar_url,
i.payout_receipt,
p.updated,
i.balance,
p.state AS pr_state
FROM issues i,
users u,
repositories r,
pull_requests p
WHERE r.repo_id = i.repo_id AND p.issue_id = i.issue_id AND p.user_id = u.id AND i.contract_address IS NOT NULL AND i.comment_id IS NOT NULL
ORDER BY p.updated;
create view bounties_view as
SELECT i.title AS issue_title,
i.issue_number,
r.repo AS repo_name,
r.owner AS repo_owner,
u.name AS user_name,
u.avatar_url AS user_avatar_url,
i.payout_receipt,
i.balance,
i.updated
FROM issues i,
users u,
repositories r
WHERE r.repo_id = i.repo_id AND r.user_id = u.id AND i.contract_address IS NOT NULL AND i.comment_id IS NOT NULL
ORDER BY i.updated;
create view activity_feed_view as
SELECT 'open-claim'::text AS type,
claims_view.issue_title,
claims_view.repo_name,
claims_view.repo_owner,
claims_view.issue_number,
claims_view.user_name,
claims_view.user_avatar_url,
claims_view.balance,
claims_view.updated
FROM claims_view
WHERE claims_view.pr_state = 0 AND claims_view.payout_receipt IS NULL
UNION
SELECT 'claim-payout'::text AS type,
claims_view.issue_title,
claims_view.repo_name,
claims_view.repo_owner,
claims_view.issue_number,
claims_view.user_name,
claims_view.user_avatar_url,
claims_view.balance,
claims_view.updated
FROM claims_view
WHERE claims_view.pr_state = 1 AND claims_view.payout_receipt IS NOT NULL
UNION
SELECT 'new-bounty'::text AS type,
bounties_view.issue_title,
bounties_view.repo_name,
bounties_view.repo_owner,
bounties_view.issue_number,
bounties_view.user_name,
bounties_view.user_avatar_url,
bounties_view.balance,
bounties_view.updated
FROM bounties_view
WHERE bounties_view.balance = 0::numeric AND bounties_view.payout_receipt IS NULL
UNION
SELECT 'balance-update'::text AS type,
bounties_view.issue_title,
bounties_view.repo_name,
bounties_view.repo_owner,
bounties_view.issue_number,
bounties_view.user_name,
bounties_view.user_avatar_url,
bounties_view.balance,
bounties_view.updated
FROM bounties_view
WHERE bounties_view.balance > 0::numeric AND bounties_view.payout_receipt IS NULL
ORDER BY updated DESC;

View File

@ -273,7 +273,7 @@ WHERE issue_id = :issue_id;
-- :name update-payout-receipt :! :n
-- :doc updates issue with payout transaction receipt
UPDATE issues
SET payout_receipt = :payout_receipt,
SET payout_receipt = :payout_receipt::jsonb,
updated = timezone('utc'::text, now())
WHERE issue_id = :issue_id;

View File

@ -54,7 +54,8 @@
(defn update-payout-receipt
[issue-id payout-receipt]
(jdbc/with-db-connection [con-db *db*]
(db/update-payout-receipt con-db {:issue_id issue-id :payout_receipt payout-receipt})))
(db/update-payout-receipt con-db {:issue_id issue-id
:payout_receipt payout-receipt})))
(defn get-bounty
[owner repo issue-number]

View File

@ -84,3 +84,13 @@
(sql-value [value] (to-pg-json value))
IPersistentVector
(sql-value [value] (to-pg-json value)))
(defn jsonb-insert-test [m]
(jdbc/with-db-connection [con-db *db*]
(jsonb-insert {:data m})))
(defn jsonb-select-test []
(jdbc/with-db-connection [con-db *db*]
(jsonb-query)))

View File

@ -75,9 +75,7 @@
(log/debug "confirmed payout:" payout-hash)
(when-let [receipt (eth/get-transaction-receipt payout-hash)]
(log/info "payout receipt for issue #" issue-id ": " receipt)
;;TODO: not sure if saving the transaction-receipt clojure map as
;; a string is a good idea
(db-bounties/update-payout-receipt issue-id (str receipt)))))
(db-bounties/update-payout-receipt issue-id receipt))))
(defn abs