-- Users --------------------------------------------------------------------------- -- :name create-user! : now() - interval '1 hour') AND i.contract_address IS NULL; -- :name pending-bounties :? :* -- :doc bounties with merged pull-requests awaiting to be signed SELECT i.contract_address AS contract_address, r.owner AS owner, r.repo AS repo, i.comment_id AS comment_id, i.issue_number AS issue_number, i.issue_id AS issue_id, i.balance_eth AS balance_eth, i.tokens AS tokens, i.value_usd AS value_usd, u.login AS winner_login, u.address AS payout_address FROM issues i, pull_requests p, users u, repositories r WHERE p.issue_id = i.issue_id AND p.repo_id = i.repo_id AND p.commit_sha = i.commit_sha AND r.repo_id = i.repo_id AND u.id = p.user_id AND i.execute_hash IS NULL; -- :name pending-payouts :? :* -- :doc recently closed issues awaiting for bot confirmation to be mined SELECT i.contract_address AS contract_address, i.issue_id AS issue_id, u.address AS payout_address, i.execute_hash AS execute_hash FROM issues i, pull_requests p, users u WHERE p.issue_id = i.issue_id AND p.repo_id = i.repo_id AND u.id = p.user_id AND i.confirm_hash IS NULL AND i.execute_hash IS NOT NULL; -- :name confirmed-payouts :? :* -- :doc lists all recently confirmed bounty payouts SELECT i.contract_address AS contract_address, r.owner AS owner, r.repo AS repo, i.comment_id AS comment_id, i.issue_number AS issue_number, i.issue_id AS issue_id, i.balance_eth AS balance_eth, i.tokens AS tokens, i.value_usd AS value_usd, u.address AS payout_address, u.login AS payee_login, i.confirm_hash AS confirm_hash, i.payout_hash AS payout_hash, i.updated AS updated FROM issues i, pull_requests p, users u, repositories r WHERE p.issue_id = i.issue_id AND p.repo_id = i.repo_id AND r.repo_id = i.repo_id AND p.state = 1 AND u.id = p.user_id AND i.payout_receipt IS NULL AND i.payout_hash IS NOT NULL; -- :name update-confirm-hash :! :n -- :doc updates issue with confirmation hash UPDATE issues SET confirm_hash = :confirm_hash, updated = timezone('utc'::text, now()) WHERE issue_id = :issue_id; -- :name update-execute-hash :! :n -- :doc updates issue with execute transaction hash UPDATE issues SET execute_hash = :execute_hash, updated = timezone('utc'::text, now()) WHERE issue_id = :issue_id; -- :name update-winner-login :! :n UPDATE issues SET winner_login = :winner_login WHERE issue_id = :issue_id; -- :name update-watch-hash :! :n -- :doc updates issue with watch transaction hash UPDATE issues SET watch_hash = :watch_hash WHERE issue_id = :issue_id; -- :name pending-watch-calls :? :* -- :doc issues with a pending watch transaction SELECT issue_id, watch_hash FROM issues WHERE watch_hash IS NOT NULL; -- :name update-payout-hash :! :n -- :doc updates issue with payout transaction hash UPDATE issues SET payout_hash = :payout_hash, updated = timezone('utc'::text, now()) WHERE issue_id = :issue_id; -- :name reset-payout-hash :! :n -- :doc sets issue's payout transaction hash to NULL UPDATE issues SET payout_hash = NULL, winner_login = NULL WHERE issue_id = :issue_id; -- :name update-payout-receipt :! :n -- :doc updates issue with payout transaction receipt UPDATE issues SET payout_receipt = :payout_receipt::jsonb, updated = timezone('utc'::text, now()) WHERE issue_id = :issue_id; -- :name update-token-balances :! :n -- :doc updates issue with given token balances UPDATE issues SET tokens = :token_balances::jsonb, updated = timezone('utc'::text, now()) WHERE contract_address = :contract_address; -- :name update-usd-value :! :n -- :doc updates issue with given USD value UPDATE issues SET value_usd = :usd_value, value_usd_updated = timezone('utc'::text, now()) WHERE contract_address = :contract_address; -- :name update-issue-open :! :n -- :doc updates issue's open status UPDATE issues SET is_open = :is_open WHERE issue_id = :issue_id; -- :name issue-exists :1 -- :doc returns true if given issue exists SELECT exists(SELECT 1 FROM issues WHERE issue_id = :issue_id); -- :name get-issue :? :1 -- :doc get issue from DB by repo-id and issue-number SELECT issue_id, issue_number, is_open, winner_login, commit_sha FROM issues WHERE repo_id = :repo_id AND issue_number = :issue_number; -- :name open-bounties :? :* -- :doc all open bounty issues SELECT i.contract_address AS contract_address, i.issue_id AS issue_id, i.issue_number AS issue_number, i.title AS issue_title, i.repo_id AS repo_id, i.balance_eth AS balance_eth, i.tokens AS tokens, i.value_usd AS value_usd, i.confirm_hash AS confirm_hash, i.payout_hash AS payout_hash, i.payout_receipt AS payout_receipt, i.updated AS updated, r.owner AS repo_owner, r.owner_avatar_url AS repo_owner_avatar_url, r.repo AS repo_name, (SELECT count(*) FROM pull_requests WHERE issue_id = i.issue_id AND state = 0) AS claim_count FROM issues i, repositories r WHERE r.repo_id = i.repo_id AND i.contract_address IS NOT NULL AND i.confirm_hash IS NULL AND i.is_open = true ORDER BY updated desc; -- :name owner-bounties :? :* -- :doc all bounty issues for given owner SELECT i.contract_address AS contract_address, i.issue_id AS issue_id, i.issue_number AS issue_number, i.title AS issue_title, i.repo_id AS repo_id, i.balance_eth AS balance_eth, i.tokens AS tokens, i.value_usd AS value_usd, i.confirm_hash AS confirm_hash, i.payout_hash AS payout_hash, i.payout_receipt AS payout_receipt, i.updated AS updated, i.winner_login AS winner_login, r.repo AS repo_name, o.address AS owner_address, u.address AS payout_address FROM users o, repositories r, issues i LEFT OUTER JOIN users u ON u.login = i.winner_login WHERE r.repo_id = i.repo_id AND r.user_id = o.id AND r.user_id = :owner_id; -- :name bounty-claims :? :* -- :doc open, merged and closed PRs referencing given bounty issue SELECT i.contract_address AS contract_address, i.issue_id AS issue_id, i.issue_number AS issue_number, i.title AS issue_title, i.repo_id AS repo_id, i.balance_eth AS balance_eth, i.tokens AS tokens, i.value_usd AS value_usd, i.confirm_hash AS confirm_hash, i.payout_hash AS payout_hash, i.payout_receipt AS payout_receipt, p.state AS pr_state, p.pr_id AS pr_id, p.user_id AS user_id, p.pr_number AS pr_number, u.address AS payout_address, u.login AS user_login, u.name AS user_name, u.avatar_url AS user_avatar_url, r.owner AS repo_owner, r.repo AS repo_name, o.address AS owner_address FROM issues i, pull_requests p, users u, users o, repositories r WHERE p.issue_id = i.issue_id AND p.repo_id = i.repo_id AND u.id = p.user_id AND r.repo_id = i.repo_id AND r.user_id = o.id AND i.issue_id = :issue_id; -- :name open-bounty-contracts :? :* -- :doc bounty issues with mined bounty contracts SELECT i.contract_address AS contract_address, r.owner AS owner, r.repo AS repo, i.comment_id AS comment_id, i.issue_number AS issue_number, i.issue_id AS issue_id, i.balance_eth AS balance_eth, i.tokens AS tokens, i.value_usd AS value_usd, i.watch_hash AS watch_hash FROM issues i, repositories r WHERE r.repo_id = i.repo_id AND contract_address IS NOT NULL AND i.execute_hash IS NULL AND i.is_open = true; -- :name get-bounty :? :1 -- :doc details for a bounty issue given owner, repo and issue nunber SELECT i.contract_address AS contract_address, i.issue_id AS issue_id, i.issue_number AS issue_number, i.balance_eth AS balance_eth, i.tokens AS tokens, i.value_usd AS value_usd, r.owner AS owner, r.repo AS repo FROM issues i, repositories r WHERE i.issue_number = :issue_number AND r.repo_id = i.repo_id AND r.owner = :owner AND r.repo = :repo; -- :name update-eth-balance :! :n -- :doc updates balance of a wallet attached to a given issue UPDATE issues SET balance_eth = :balance_eth, updated = timezone('utc'::text, now()) WHERE contract_address = :contract_address; -- :name save-issue-comment-image! :