sats to msats
This commit is contained in:
		
							parent
							
								
									e79f39274b
								
							
						
					
					
						commit
						bcdd5410a3
					
				@ -33,10 +33,10 @@ export default {
 | 
			
		||||
 | 
			
		||||
      return await models.$queryRaw(
 | 
			
		||||
        `SELECT date_trunc('month', "ItemAct".created_at) AS time,
 | 
			
		||||
        sum(CASE WHEN act = 'STREAM' THEN "ItemAct".sats ELSE 0 END) as jobs,
 | 
			
		||||
        sum(CASE WHEN act IN ('VOTE', 'POLL') AND "Item"."userId" = "ItemAct"."userId" THEN "ItemAct".sats ELSE 0 END) as fees,
 | 
			
		||||
        sum(CASE WHEN act = 'BOOST' THEN "ItemAct".sats ELSE 0 END) as boost,
 | 
			
		||||
        sum(CASE WHEN act = 'TIP' THEN "ItemAct".sats ELSE 0 END) as tips
 | 
			
		||||
        floor(sum(CASE WHEN act = 'STREAM' THEN "ItemAct".msats ELSE 0 END)/1000) as jobs,
 | 
			
		||||
        floor(sum(CASE WHEN act IN ('VOTE', 'POLL') AND "Item"."userId" = "ItemAct"."userId" THEN "ItemAct".msats ELSE 0 END)/1000) as fees,
 | 
			
		||||
        floor(sum(CASE WHEN act = 'BOOST' THEN "ItemAct".msats ELSE 0 END)/1000) as boost,
 | 
			
		||||
        floor(sum(CASE WHEN act = 'TIP' THEN "ItemAct".msats ELSE 0 END)/1000) as tips
 | 
			
		||||
        FROM "ItemAct"
 | 
			
		||||
        JOIN "Item" on "ItemAct"."itemId" = "Item".id
 | 
			
		||||
        WHERE date_trunc('month', now_utc()) <> date_trunc('month',  "ItemAct".created_at)
 | 
			
		||||
@ -60,17 +60,17 @@ export default {
 | 
			
		||||
    },
 | 
			
		||||
    stackedGrowth: async (parent, args, { models }) => {
 | 
			
		||||
      return await models.$queryRaw(
 | 
			
		||||
        `SELECT time, sum(airdrop) as rewards, sum(post) as posts, sum(comment) as comments
 | 
			
		||||
        `SELECT time, floor(sum(airdrop)/1000) as rewards, floor(sum(post)/1000) as posts, floor(sum(comment)/1000) as comments
 | 
			
		||||
        FROM
 | 
			
		||||
        ((SELECT date_trunc('month', "ItemAct".created_at) AS time, 0 as airdrop,
 | 
			
		||||
          CASE WHEN "Item"."parentId" IS NULL THEN 0 ELSE "ItemAct".sats END as comment,
 | 
			
		||||
          CASE WHEN "Item"."parentId" IS NULL THEN "ItemAct".sats ELSE 0 END as post
 | 
			
		||||
          CASE WHEN "Item"."parentId" IS NULL THEN 0 ELSE "ItemAct".msats END as comment,
 | 
			
		||||
          CASE WHEN "Item"."parentId" IS NULL THEN "ItemAct".msats ELSE 0 END as post
 | 
			
		||||
          FROM "ItemAct"
 | 
			
		||||
          JOIN "Item" on "ItemAct"."itemId" = "Item".id AND "Item"."userId" <> "ItemAct"."userId"
 | 
			
		||||
          WHERE date_trunc('month', now_utc()) <> date_trunc('month', "ItemAct".created_at) AND
 | 
			
		||||
          "ItemAct".act IN ('VOTE', 'TIP'))
 | 
			
		||||
        UNION ALL
 | 
			
		||||
        (SELECT date_trunc('month', created_at) AS time, msats / 1000 as airdrop, 0 as post, 0 as comment
 | 
			
		||||
        (SELECT date_trunc('month', created_at) AS time, msats as airdrop, 0 as post, 0 as comment
 | 
			
		||||
          FROM "Earn"
 | 
			
		||||
          WHERE date_trunc('month', now_utc()) <> date_trunc('month', created_at))) u
 | 
			
		||||
        GROUP BY time
 | 
			
		||||
@ -121,10 +121,10 @@ export default {
 | 
			
		||||
    spentWeekly: async (parent, args, { models }) => {
 | 
			
		||||
      const [stats] = await models.$queryRaw(
 | 
			
		||||
        `SELECT json_build_array(
 | 
			
		||||
          json_build_object('name', 'jobs', 'value', sum(CASE WHEN act = 'STREAM' THEN "ItemAct".sats ELSE 0 END)),
 | 
			
		||||
          json_build_object('name', 'fees', 'value', sum(CASE WHEN act in ('VOTE', 'POLL') AND "Item"."userId" = "ItemAct"."userId" THEN "ItemAct".sats ELSE 0 END)),
 | 
			
		||||
          json_build_object('name', 'boost', 'value', sum(CASE WHEN act = 'BOOST' THEN "ItemAct".sats ELSE 0 END)),
 | 
			
		||||
          json_build_object('name', 'tips', 'value', sum(CASE WHEN act = 'TIP' THEN "ItemAct".sats ELSE 0 END))) as array
 | 
			
		||||
          json_build_object('name', 'jobs', 'value', floor(sum(CASE WHEN act = 'STREAM' THEN "ItemAct".msats ELSE 0 END)/1000)),
 | 
			
		||||
          json_build_object('name', 'fees', 'value', floor(sum(CASE WHEN act in ('VOTE', 'POLL') AND "Item"."userId" = "ItemAct"."userId" THEN "ItemAct".msats ELSE 0 END)/1000)),
 | 
			
		||||
          json_build_object('name', 'boost', 'value',floor(sum(CASE WHEN act = 'BOOST' THEN "ItemAct".msats ELSE 0 END)/1000)),
 | 
			
		||||
          json_build_object('name', 'tips', 'value', floor(sum(CASE WHEN act = 'TIP' THEN "ItemAct".msats ELSE 0 END)/1000))) as array
 | 
			
		||||
        FROM "ItemAct"
 | 
			
		||||
        JOIN "Item" on "ItemAct"."itemId" = "Item".id
 | 
			
		||||
        WHERE "ItemAct".created_at >= now_utc() - interval '1 week'`)
 | 
			
		||||
@ -134,20 +134,20 @@ export default {
 | 
			
		||||
    stackedWeekly: async (parent, args, { models }) => {
 | 
			
		||||
      const [stats] = await models.$queryRaw(
 | 
			
		||||
        `SELECT json_build_array(
 | 
			
		||||
          json_build_object('name', 'rewards', 'value', sum(airdrop)),
 | 
			
		||||
          json_build_object('name', 'posts', 'value', sum(post)),
 | 
			
		||||
          json_build_object('name', 'comments', 'value', sum(comment))
 | 
			
		||||
          json_build_object('name', 'rewards', 'value', floor(sum(airdrop)/1000)),
 | 
			
		||||
          json_build_object('name', 'posts', 'value', floor(sum(post)/1000)),
 | 
			
		||||
          json_build_object('name', 'comments', 'value', floor(sum(comment)/1000))
 | 
			
		||||
        ) as array
 | 
			
		||||
        FROM
 | 
			
		||||
        ((SELECT 0 as airdrop,
 | 
			
		||||
          CASE WHEN "Item"."parentId" IS NULL THEN 0 ELSE "ItemAct".sats END as comment,
 | 
			
		||||
          CASE WHEN "Item"."parentId" IS NULL THEN "ItemAct".sats ELSE 0 END as post
 | 
			
		||||
          CASE WHEN "Item"."parentId" IS NULL THEN 0 ELSE "ItemAct".msats END as comment,
 | 
			
		||||
          CASE WHEN "Item"."parentId" IS NULL THEN "ItemAct".msats ELSE 0 END as post
 | 
			
		||||
          FROM "ItemAct"
 | 
			
		||||
          JOIN "Item" on "ItemAct"."itemId" = "Item".id AND "Item"."userId" <> "ItemAct"."userId"
 | 
			
		||||
          WHERE  "ItemAct".created_at >= now_utc() - interval '1 week' AND
 | 
			
		||||
          "ItemAct".act IN ('VOTE', 'TIP'))
 | 
			
		||||
        UNION ALL
 | 
			
		||||
        (SELECT msats / 1000 as airdrop, 0 as post, 0 as comment
 | 
			
		||||
        (SELECT msats as airdrop, 0 as post, 0 as comment
 | 
			
		||||
          FROM "Earn"
 | 
			
		||||
          WHERE  created_at >= now_utc() - interval '1 week')) u`)
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
@ -8,6 +8,7 @@ import {
 | 
			
		||||
  BOOST_MIN, ITEM_SPAM_INTERVAL, MAX_POLL_NUM_CHOICES,
 | 
			
		||||
  MAX_TITLE_LENGTH, ITEM_FILTER_THRESHOLD, DONT_LIKE_THIS_COST
 | 
			
		||||
} from '../../lib/constants'
 | 
			
		||||
import { msatsToSats } from '../../lib/format'
 | 
			
		||||
 | 
			
		||||
async function comments (me, models, id, sort) {
 | 
			
		||||
  let orderBy
 | 
			
		||||
@ -74,7 +75,7 @@ async function topOrderClause (sort, me, models) {
 | 
			
		||||
    case 'comments':
 | 
			
		||||
      return 'ORDER BY ncomments DESC'
 | 
			
		||||
    case 'sats':
 | 
			
		||||
      return 'ORDER BY sats DESC'
 | 
			
		||||
      return 'ORDER BY msats DESC'
 | 
			
		||||
    default:
 | 
			
		||||
      return await topOrderByWeightedSats(me, models)
 | 
			
		||||
  }
 | 
			
		||||
@ -690,6 +691,12 @@ export default {
 | 
			
		||||
    }
 | 
			
		||||
  },
 | 
			
		||||
  Item: {
 | 
			
		||||
    sats: async (item, args, { models }) => {
 | 
			
		||||
      return msatsToSats(item.msats)
 | 
			
		||||
    },
 | 
			
		||||
    commentSats: async (item, args, { models }) => {
 | 
			
		||||
      return msatsToSats(item.commentMsats)
 | 
			
		||||
    },
 | 
			
		||||
    isJob: async (item, args, { models }) => {
 | 
			
		||||
      return item.subName === 'jobs'
 | 
			
		||||
    },
 | 
			
		||||
@ -771,10 +778,7 @@ export default {
 | 
			
		||||
      return comments(me, models, item.id, 'hot')
 | 
			
		||||
    },
 | 
			
		||||
    upvotes: async (item, args, { models }) => {
 | 
			
		||||
      const { sum: { sats } } = await models.itemAct.aggregate({
 | 
			
		||||
        sum: {
 | 
			
		||||
          sats: true
 | 
			
		||||
        },
 | 
			
		||||
      const count = await models.itemAct.count({
 | 
			
		||||
        where: {
 | 
			
		||||
          itemId: Number(item.id),
 | 
			
		||||
          userId: {
 | 
			
		||||
@ -784,12 +788,12 @@ export default {
 | 
			
		||||
        }
 | 
			
		||||
      })
 | 
			
		||||
 | 
			
		||||
      return sats || 0
 | 
			
		||||
      return count
 | 
			
		||||
    },
 | 
			
		||||
    boost: async (item, args, { models }) => {
 | 
			
		||||
      const { sum: { sats } } = await models.itemAct.aggregate({
 | 
			
		||||
      const { sum: { msats } } = await models.itemAct.aggregate({
 | 
			
		||||
        sum: {
 | 
			
		||||
          sats: true
 | 
			
		||||
          msats: true
 | 
			
		||||
        },
 | 
			
		||||
        where: {
 | 
			
		||||
          itemId: Number(item.id),
 | 
			
		||||
@ -797,7 +801,7 @@ export default {
 | 
			
		||||
        }
 | 
			
		||||
      })
 | 
			
		||||
 | 
			
		||||
      return sats || 0
 | 
			
		||||
      return (msats && msatsToSats(msats)) || 0
 | 
			
		||||
    },
 | 
			
		||||
    wvotes: async (item) => {
 | 
			
		||||
      return item.weightedVotes - item.weightedDownVotes
 | 
			
		||||
@ -805,9 +809,9 @@ export default {
 | 
			
		||||
    meSats: async (item, args, { me, models }) => {
 | 
			
		||||
      if (!me) return 0
 | 
			
		||||
 | 
			
		||||
      const { sum: { sats } } = await models.itemAct.aggregate({
 | 
			
		||||
      const { sum: { msats } } = await models.itemAct.aggregate({
 | 
			
		||||
        sum: {
 | 
			
		||||
          sats: true
 | 
			
		||||
          msats: true
 | 
			
		||||
        },
 | 
			
		||||
        where: {
 | 
			
		||||
          itemId: Number(item.id),
 | 
			
		||||
@ -823,7 +827,7 @@ export default {
 | 
			
		||||
        }
 | 
			
		||||
      })
 | 
			
		||||
 | 
			
		||||
      return sats || 0
 | 
			
		||||
      return (msats && msatsToSats(msats)) || 0
 | 
			
		||||
    },
 | 
			
		||||
    meDontLike: async (item, args, { me, models }) => {
 | 
			
		||||
      if (!me) return false
 | 
			
		||||
@ -1010,7 +1014,7 @@ export const SELECT =
 | 
			
		||||
  "Item".text, "Item".url, "Item"."userId", "Item"."fwdUserId", "Item"."parentId", "Item"."pinId", "Item"."maxBid",
 | 
			
		||||
  "Item".company, "Item".location, "Item".remote,
 | 
			
		||||
  "Item"."subName", "Item".status, "Item"."uploadId", "Item"."pollCost",
 | 
			
		||||
  "Item".sats, "Item".ncomments, "Item"."commentSats", "Item"."lastCommentAt", "Item"."weightedVotes",
 | 
			
		||||
  "Item".msats, "Item".ncomments, "Item"."commentMsats", "Item"."lastCommentAt", "Item"."weightedVotes",
 | 
			
		||||
  "Item"."weightedDownVotes", "Item".freebie, ltree2text("Item"."path") AS "path"`
 | 
			
		||||
 | 
			
		||||
async function newTimedOrderByWeightedSats (me, models, num) {
 | 
			
		||||
 | 
			
		||||
@ -106,7 +106,7 @@ export default {
 | 
			
		||||
        if (meFull.noteItemSats) {
 | 
			
		||||
          queries.push(
 | 
			
		||||
            `(SELECT "Item".id::TEXT, MAX("ItemAct".created_at) AS "sortTime",
 | 
			
		||||
              sum("ItemAct".sats) as "earnedSats", 'Votification' AS type
 | 
			
		||||
              floor(sum("ItemAct".msats)/1000) as "earnedSats", 'Votification' AS type
 | 
			
		||||
              FROM "Item"
 | 
			
		||||
              JOIN "ItemAct" ON "ItemAct"."itemId" = "Item".id
 | 
			
		||||
              WHERE "ItemAct"."userId" <> $1
 | 
			
		||||
 | 
			
		||||
@ -1,5 +1,6 @@
 | 
			
		||||
import { AuthenticationError, UserInputError } from 'apollo-server-errors'
 | 
			
		||||
import { decodeCursor, LIMIT, nextCursorEncoded } from '../../lib/cursor'
 | 
			
		||||
import { msatsToSats } from '../../lib/format'
 | 
			
		||||
import { createMentions, getItem, SELECT, updateItem, filterClause } from './item'
 | 
			
		||||
import serialize from './serial'
 | 
			
		||||
 | 
			
		||||
@ -92,7 +93,7 @@ export default {
 | 
			
		||||
      let users
 | 
			
		||||
      if (sort === 'spent') {
 | 
			
		||||
        users = await models.$queryRaw(`
 | 
			
		||||
          SELECT users.*, sum("ItemAct".sats) as spent
 | 
			
		||||
          SELECT users.*, floor(sum("ItemAct".msats)/1000) as spent
 | 
			
		||||
          FROM "ItemAct"
 | 
			
		||||
          JOIN users on "ItemAct"."userId" = users.id
 | 
			
		||||
          WHERE "ItemAct".created_at <= $1
 | 
			
		||||
@ -125,16 +126,16 @@ export default {
 | 
			
		||||
          LIMIT ${LIMIT}`, decodedCursor.time, decodedCursor.offset)
 | 
			
		||||
      } else {
 | 
			
		||||
        users = await models.$queryRaw(`
 | 
			
		||||
          SELECT u.id, u.name, u."photoId", sum(amount) as stacked
 | 
			
		||||
          SELECT u.id, u.name, u."photoId", floor(sum(amount)/1000) as stacked
 | 
			
		||||
          FROM
 | 
			
		||||
          ((SELECT users.*, "ItemAct".sats as amount
 | 
			
		||||
          ((SELECT users.*, "ItemAct".msats as amount
 | 
			
		||||
            FROM "ItemAct"
 | 
			
		||||
            JOIN "Item" on "ItemAct"."itemId" = "Item".id
 | 
			
		||||
            JOIN users on "Item"."userId" = users.id
 | 
			
		||||
            WHERE act <> 'BOOST' AND "ItemAct"."userId" <> users.id AND "ItemAct".created_at <= $1
 | 
			
		||||
            ${within('ItemAct', when)})
 | 
			
		||||
          UNION ALL
 | 
			
		||||
          (SELECT users.*, "Earn".msats/1000 as amount
 | 
			
		||||
          (SELECT users.*, "Earn".msats as amount
 | 
			
		||||
            FROM "Earn"
 | 
			
		||||
            JOIN users on users.id = "Earn"."userId"
 | 
			
		||||
            WHERE "Earn".msats > 0 ${within('Earn', when)})) u
 | 
			
		||||
@ -422,22 +423,22 @@ export default {
 | 
			
		||||
 | 
			
		||||
      if (!when) {
 | 
			
		||||
        // forever
 | 
			
		||||
        return Math.floor((user.stackedMsats || 0) / 1000)
 | 
			
		||||
        return (user.stackedMsats && msatsToSats(user.stackedMsats)) || 0
 | 
			
		||||
      } else {
 | 
			
		||||
        const [{ stacked }] = await models.$queryRaw(`
 | 
			
		||||
          SELECT sum(amount) as stacked
 | 
			
		||||
          FROM
 | 
			
		||||
          ((SELECT sum("ItemAct".sats) as amount
 | 
			
		||||
          ((SELECT sum("ItemAct".msats) as amount
 | 
			
		||||
            FROM "ItemAct"
 | 
			
		||||
            JOIN "Item" on "ItemAct"."itemId" = "Item".id
 | 
			
		||||
            WHERE act <> 'BOOST' AND "ItemAct"."userId" <> $2 AND "Item"."userId" = $2
 | 
			
		||||
            AND "ItemAct".created_at >= $1)
 | 
			
		||||
          UNION ALL
 | 
			
		||||
          (SELECT sum("Earn".msats/1000) as amount
 | 
			
		||||
          (SELECT sum("Earn".msats) as amount
 | 
			
		||||
            FROM "Earn"
 | 
			
		||||
            WHERE "Earn".msats > 0 AND "Earn"."userId" = $2
 | 
			
		||||
            AND "Earn".created_at >= $1)) u`, withinDate(when), Number(user.id))
 | 
			
		||||
        return stacked || 0
 | 
			
		||||
        return (stacked && msatsToSats(stacked)) || 0
 | 
			
		||||
      }
 | 
			
		||||
    },
 | 
			
		||||
    spent: async (user, { when }, { models }) => {
 | 
			
		||||
@ -445,9 +446,9 @@ export default {
 | 
			
		||||
        return user.spent
 | 
			
		||||
      }
 | 
			
		||||
 | 
			
		||||
      const { sum: { sats } } = await models.itemAct.aggregate({
 | 
			
		||||
      const { sum: { msats } } = await models.itemAct.aggregate({
 | 
			
		||||
        sum: {
 | 
			
		||||
          sats: true
 | 
			
		||||
          msats: true
 | 
			
		||||
        },
 | 
			
		||||
        where: {
 | 
			
		||||
          userId: user.id,
 | 
			
		||||
@ -457,13 +458,13 @@ export default {
 | 
			
		||||
        }
 | 
			
		||||
      })
 | 
			
		||||
 | 
			
		||||
      return sats || 0
 | 
			
		||||
      return (msats && msatsToSats(msats)) || 0
 | 
			
		||||
    },
 | 
			
		||||
    sats: async (user, args, { models, me }) => {
 | 
			
		||||
      if (me?.id !== user.id) {
 | 
			
		||||
        return 0
 | 
			
		||||
      }
 | 
			
		||||
      return Math.floor(user.msats / 1000.0)
 | 
			
		||||
      return msatsToSats(user.msats)
 | 
			
		||||
    },
 | 
			
		||||
    bio: async (user, args, { models }) => {
 | 
			
		||||
      return getItem(user, { id: user.bioId }, { models })
 | 
			
		||||
 | 
			
		||||
@ -5,6 +5,7 @@ import { decodeCursor, LIMIT, nextCursorEncoded } from '../../lib/cursor'
 | 
			
		||||
import lnpr from 'bolt11'
 | 
			
		||||
import { SELECT } from './item'
 | 
			
		||||
import { lnurlPayDescriptionHash } from '../../lib/lnurl'
 | 
			
		||||
import { msatsToSats } from '../../lib/format'
 | 
			
		||||
 | 
			
		||||
export async function getInvoice (parent, { id }, { me, models }) {
 | 
			
		||||
  if (!me) {
 | 
			
		||||
@ -93,7 +94,7 @@ export default {
 | 
			
		||||
      if (include.has('stacked')) {
 | 
			
		||||
        queries.push(
 | 
			
		||||
          `(SELECT ('stacked' || "Item".id) as id, "Item".id as "factId", NULL as bolt11,
 | 
			
		||||
          MAX("ItemAct".created_at) as "createdAt", sum("ItemAct".sats) * 1000 as msats,
 | 
			
		||||
          MAX("ItemAct".created_at) as "createdAt", sum("ItemAct".msats) as msats,
 | 
			
		||||
          0 as "msatsFee", NULL as status, 'stacked' as type
 | 
			
		||||
          FROM "ItemAct"
 | 
			
		||||
          JOIN "Item" on "ItemAct"."itemId" = "Item".id
 | 
			
		||||
@ -114,7 +115,7 @@ export default {
 | 
			
		||||
      if (include.has('spent')) {
 | 
			
		||||
        queries.push(
 | 
			
		||||
          `(SELECT ('spent' || "Item".id) as id, "Item".id as "factId", NULL as bolt11,
 | 
			
		||||
          MAX("ItemAct".created_at) as "createdAt", sum("ItemAct".sats) * 1000 as msats,
 | 
			
		||||
          MAX("ItemAct".created_at) as "createdAt", sum("ItemAct".msats) as msats,
 | 
			
		||||
          0 as "msatsFee", NULL as status, 'spent' as type
 | 
			
		||||
          FROM "ItemAct"
 | 
			
		||||
          JOIN "Item" on "ItemAct"."itemId" = "Item".id
 | 
			
		||||
@ -254,10 +255,14 @@ export default {
 | 
			
		||||
  },
 | 
			
		||||
 | 
			
		||||
  Withdrawl: {
 | 
			
		||||
    satsPaying: w => Math.floor(w.msatsPaying / 1000),
 | 
			
		||||
    satsPaid: w => Math.floor(w.msatsPaid / 1000),
 | 
			
		||||
    satsFeePaying: w => Math.floor(w.msatsFeePaying / 1000),
 | 
			
		||||
    satsFeePaid: w => Math.floor(w.msatsFeePaid / 1000)
 | 
			
		||||
    satsPaying: w => msatsToSats(w.msatsPaying),
 | 
			
		||||
    satsPaid: w => msatsToSats(w.msatsPaid),
 | 
			
		||||
    satsFeePaying: w => msatsToSats(w.msatsFeePaying),
 | 
			
		||||
    satsFeePaid: w => msatsToSats(w.msatsFeePaid)
 | 
			
		||||
  },
 | 
			
		||||
 | 
			
		||||
  Invoice: {
 | 
			
		||||
    satsReceived: i => msatsToSats(i.msatsReceived)
 | 
			
		||||
  },
 | 
			
		||||
 | 
			
		||||
  Fact: {
 | 
			
		||||
@ -271,7 +276,9 @@ export default {
 | 
			
		||||
        WHERE id = $1`, Number(fact.factId))
 | 
			
		||||
 | 
			
		||||
      return item
 | 
			
		||||
    }
 | 
			
		||||
    },
 | 
			
		||||
    sats: fact => msatsToSats(fact.msats),
 | 
			
		||||
    satsFee: fact => msatsToSats(fact.msatsFee)
 | 
			
		||||
  }
 | 
			
		||||
}
 | 
			
		||||
 | 
			
		||||
@ -285,7 +292,7 @@ async function createWithdrawal (parent, { invoice, maxFee }, { me, models, lnd
 | 
			
		||||
    throw new UserInputError('could not decode invoice')
 | 
			
		||||
  }
 | 
			
		||||
 | 
			
		||||
  if (!decoded.mtokens || Number(decoded.mtokens) <= 0) {
 | 
			
		||||
  if (!decoded.mtokens || BigInt(decoded.mtokens) <= 0) {
 | 
			
		||||
    throw new UserInputError('your invoice must specify an amount')
 | 
			
		||||
  }
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
@ -21,7 +21,7 @@ export default gql`
 | 
			
		||||
    expiresAt: String!
 | 
			
		||||
    cancelled: Boolean!
 | 
			
		||||
    confirmedAt: String
 | 
			
		||||
    msatsReceived: Int
 | 
			
		||||
    satsReceived: Int
 | 
			
		||||
  }
 | 
			
		||||
 | 
			
		||||
  type Withdrawl {
 | 
			
		||||
@ -29,13 +29,9 @@ export default gql`
 | 
			
		||||
    createdAt: String!
 | 
			
		||||
    hash: String!
 | 
			
		||||
    bolt11: String!
 | 
			
		||||
    msatsPaying: Int!
 | 
			
		||||
    satsPaying: Int!
 | 
			
		||||
    msatsPaid: Int
 | 
			
		||||
    satsPaid: Int
 | 
			
		||||
    msatsFeePaying: Int!
 | 
			
		||||
    satsFeePaying: Int!
 | 
			
		||||
    msatsFeePaid: Int
 | 
			
		||||
    satsFeePaid: Int
 | 
			
		||||
    status: String
 | 
			
		||||
  }
 | 
			
		||||
@ -45,8 +41,8 @@ export default gql`
 | 
			
		||||
    factId: ID!
 | 
			
		||||
    bolt11: String
 | 
			
		||||
    createdAt: String!
 | 
			
		||||
    msats: Int!
 | 
			
		||||
    msatsFee: Int
 | 
			
		||||
    sats: Int!
 | 
			
		||||
    satsFee: Int
 | 
			
		||||
    status: String
 | 
			
		||||
    type: String!
 | 
			
		||||
    description: String
 | 
			
		||||
 | 
			
		||||
@ -5,7 +5,7 @@ export function Invoice ({ invoice }) {
 | 
			
		||||
  let status = 'waiting for you'
 | 
			
		||||
  if (invoice.confirmedAt) {
 | 
			
		||||
    variant = 'confirmed'
 | 
			
		||||
    status = `${invoice.msatsReceived / 1000} sats deposited`
 | 
			
		||||
    status = `${invoice.satsReceived} sats deposited`
 | 
			
		||||
  } else if (invoice.cancelled) {
 | 
			
		||||
    variant = 'failed'
 | 
			
		||||
    status = 'cancelled'
 | 
			
		||||
 | 
			
		||||
@ -12,7 +12,7 @@ import React, { useEffect, useState } from 'react'
 | 
			
		||||
import GithubSlugger from 'github-slugger'
 | 
			
		||||
import LinkIcon from '../svgs/link.svg'
 | 
			
		||||
import Thumb from '../svgs/thumb-up-fill.svg'
 | 
			
		||||
import {toString} from 'mdast-util-to-string'
 | 
			
		||||
import { toString } from 'mdast-util-to-string'
 | 
			
		||||
import copy from 'clipboard-copy'
 | 
			
		||||
 | 
			
		||||
function myRemarkPlugin () {
 | 
			
		||||
@ -32,8 +32,6 @@ function myRemarkPlugin () {
 | 
			
		||||
  }
 | 
			
		||||
}
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
function Heading ({ h, slugger, noFragments, topLevel, children, node, ...props }) {
 | 
			
		||||
  const [copied, setCopied] = useState(false)
 | 
			
		||||
  const [id] = useState(noFragments ? undefined : slugger.slug(toString(node).replace(/[^\w\-\s]+/gi, '')))
 | 
			
		||||
@ -44,20 +42,20 @@ function Heading ({ h, slugger, noFragments, topLevel, children, node, ...props
 | 
			
		||||
    <div className={styles.heading}>
 | 
			
		||||
      {React.createElement(h, { id, ...props }, children)}
 | 
			
		||||
      {!noFragments && topLevel &&
 | 
			
		||||
      <a className={`${styles.headingLink} ${copied ? styles.copied : ''}`} href={`#${id}`}>
 | 
			
		||||
        <Icon
 | 
			
		||||
          onClick={() => {
 | 
			
		||||
            const location = new URL(window.location)
 | 
			
		||||
            location.hash = `${id}`
 | 
			
		||||
            copy(location.href)
 | 
			
		||||
            setTimeout(() => setCopied(false), 1500)
 | 
			
		||||
            setCopied(true)
 | 
			
		||||
          }}
 | 
			
		||||
          width={18}
 | 
			
		||||
          height={18}
 | 
			
		||||
          className='fill-grey'
 | 
			
		||||
        />
 | 
			
		||||
      </a>}
 | 
			
		||||
        <a className={`${styles.headingLink} ${copied ? styles.copied : ''}`} href={`#${id}`}>
 | 
			
		||||
          <Icon
 | 
			
		||||
            onClick={() => {
 | 
			
		||||
              const location = new URL(window.location)
 | 
			
		||||
              location.hash = `${id}`
 | 
			
		||||
              copy(location.href)
 | 
			
		||||
              setTimeout(() => setCopied(false), 1500)
 | 
			
		||||
              setCopied(true)
 | 
			
		||||
            }}
 | 
			
		||||
            width={18}
 | 
			
		||||
            height={18}
 | 
			
		||||
            className='fill-grey'
 | 
			
		||||
          />
 | 
			
		||||
        </a>}
 | 
			
		||||
    </div>
 | 
			
		||||
  )
 | 
			
		||||
}
 | 
			
		||||
@ -66,7 +64,7 @@ export default function Text ({ topLevel, noFragments, nofollow, children }) {
 | 
			
		||||
  // all the reactStringReplace calls are to facilitate search highlighting
 | 
			
		||||
  const slugger = new GithubSlugger()
 | 
			
		||||
 | 
			
		||||
  const HeadingWrapper = (props) => Heading({ topLevel, slugger, noFragments, ...props})
 | 
			
		||||
  const HeadingWrapper = (props) => Heading({ topLevel, slugger, noFragments, ...props })
 | 
			
		||||
 | 
			
		||||
  return (
 | 
			
		||||
    <div className={styles.text}>
 | 
			
		||||
@ -108,10 +106,10 @@ export default function Text ({ topLevel, noFragments, nofollow, children }) {
 | 
			
		||||
            // map: fix any highlighted links
 | 
			
		||||
            children = children?.map(e =>
 | 
			
		||||
              typeof e === 'string'
 | 
			
		||||
              ? reactStringReplace(e, /:high\[([^\]]+)\]/g, (match, i) => {
 | 
			
		||||
                  return <mark key={`mark-${match}-${i}`}>{match}</mark>
 | 
			
		||||
                })
 | 
			
		||||
              : e)
 | 
			
		||||
                ? reactStringReplace(e, /:high\[([^\]]+)\]/g, (match, i) => {
 | 
			
		||||
                    return <mark key={`mark-${match}-${i}`}>{match}</mark>
 | 
			
		||||
                  })
 | 
			
		||||
                : e)
 | 
			
		||||
 | 
			
		||||
            return (
 | 
			
		||||
              /*  eslint-disable-next-line */
 | 
			
		||||
 | 
			
		||||
@ -7,7 +7,7 @@ export const INVOICE = gql`
 | 
			
		||||
    invoice(id: $id) {
 | 
			
		||||
      id
 | 
			
		||||
      bolt11
 | 
			
		||||
      msatsReceived
 | 
			
		||||
      satsReceived
 | 
			
		||||
      cancelled
 | 
			
		||||
      confirmedAt
 | 
			
		||||
      expiresAt
 | 
			
		||||
@ -40,8 +40,8 @@ export const WALLET_HISTORY = gql`
 | 
			
		||||
        factId
 | 
			
		||||
        type
 | 
			
		||||
        createdAt
 | 
			
		||||
        msats
 | 
			
		||||
        msatsFee
 | 
			
		||||
        sats
 | 
			
		||||
        satsFee
 | 
			
		||||
        status
 | 
			
		||||
        type
 | 
			
		||||
        description
 | 
			
		||||
 | 
			
		||||
@ -9,3 +9,10 @@ export const abbrNum = n => {
 | 
			
		||||
export const fixedDecimal = (n, f) => {
 | 
			
		||||
  return Number.parseFloat(n).toFixed(f)
 | 
			
		||||
}
 | 
			
		||||
 | 
			
		||||
export const msatsToSats = msats => {
 | 
			
		||||
  if (msats === null || msats === undefined) {
 | 
			
		||||
    return null
 | 
			
		||||
  }
 | 
			
		||||
  return Number(BigInt(msats) / 1000n)
 | 
			
		||||
}
 | 
			
		||||
 | 
			
		||||
@ -49,10 +49,12 @@ function MyApp ({ Component, pageProps: { session, ...props } }) {
 | 
			
		||||
    // this nodata var will get passed to the server on back/foward and
 | 
			
		||||
    // 1. prevent data from reloading and 2. perserve scroll
 | 
			
		||||
    // (2) is not possible while intercepting nav with beforePopState
 | 
			
		||||
    router.replace({
 | 
			
		||||
      pathname: router.pathname,
 | 
			
		||||
      query: { ...router.query, nodata: true }
 | 
			
		||||
    }, router.asPath, { ...router.options, scroll: false })
 | 
			
		||||
    if (router.isReady) {
 | 
			
		||||
      router.replace({
 | 
			
		||||
        pathname: router.pathname,
 | 
			
		||||
        query: { ...router.query, nodata: true }
 | 
			
		||||
      }, router.asPath, { ...router.options, scroll: false })
 | 
			
		||||
    }
 | 
			
		||||
  }, [router.asPath])
 | 
			
		||||
 | 
			
		||||
  /*
 | 
			
		||||
 | 
			
		||||
@ -19,7 +19,10 @@ function LoadInvoice () {
 | 
			
		||||
    pollInterval: 1000,
 | 
			
		||||
    variables: { id: router.query.id }
 | 
			
		||||
  })
 | 
			
		||||
  if (error) return <div>error</div>
 | 
			
		||||
  if (error) {
 | 
			
		||||
    console.log(error)
 | 
			
		||||
    return <div>error</div>
 | 
			
		||||
  }
 | 
			
		||||
  if (!data || loading) {
 | 
			
		||||
    return <LnQRSkeleton status='loading' />
 | 
			
		||||
  }
 | 
			
		||||
 | 
			
		||||
@ -213,7 +213,7 @@ export default function Satistics ({ data: { me, walletHistory: { facts, cursor
 | 
			
		||||
                    <td className={styles.description}>
 | 
			
		||||
                      <Detail fact={f} />
 | 
			
		||||
                    </td>
 | 
			
		||||
                    <td className={`${styles.sats} ${satusClass(f.status)}`}>{Math.floor(f.msats / 1000)}</td>
 | 
			
		||||
                    <td className={`${styles.sats} ${satusClass(f.status)}`}>{Math.floor(f.sats)}</td>
 | 
			
		||||
                  </tr>
 | 
			
		||||
                </Wrapper>
 | 
			
		||||
              )
 | 
			
		||||
 | 
			
		||||
							
								
								
									
										43
									
								
								prisma/migrations/20221110190205_msats_bigint/migration.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										43
									
								
								prisma/migrations/20221110190205_msats_bigint/migration.sql
									
									
									
									
									
										Normal file
									
								
							@ -0,0 +1,43 @@
 | 
			
		||||
-- AlterTable
 | 
			
		||||
ALTER TABLE "Earn" ALTER COLUMN "msats" SET DATA TYPE BIGINT;
 | 
			
		||||
 | 
			
		||||
-- AlterTable
 | 
			
		||||
ALTER TABLE "Invoice" ALTER COLUMN "msatsRequested" SET DATA TYPE BIGINT,
 | 
			
		||||
ALTER COLUMN "msatsReceived" SET DATA TYPE BIGINT;
 | 
			
		||||
 | 
			
		||||
-- AlterTable
 | 
			
		||||
ALTER TABLE "Item"
 | 
			
		||||
ALTER COLUMN "commentSats" SET DATA TYPE BIGINT,
 | 
			
		||||
ALTER COLUMN "sats" SET DATA TYPE BIGINT;
 | 
			
		||||
 | 
			
		||||
-- AlterTable
 | 
			
		||||
ALTER TABLE "Item" RENAME COLUMN "commentSats" TO "commentMsats";
 | 
			
		||||
ALTER TABLE "Item" RENAME COLUMN "sats" TO "msats";
 | 
			
		||||
 | 
			
		||||
-- update to msats
 | 
			
		||||
UPDATE "Item" SET
 | 
			
		||||
"commentMsats" = "commentMsats" * 1000,
 | 
			
		||||
"msats" = "msats" * 1000;
 | 
			
		||||
 | 
			
		||||
-- AlterTable
 | 
			
		||||
ALTER TABLE "ItemAct"
 | 
			
		||||
ALTER COLUMN "sats" SET DATA TYPE BIGINT;
 | 
			
		||||
 | 
			
		||||
-- AlterTable
 | 
			
		||||
ALTER TABLE "ItemAct" RENAME COLUMN "sats" TO "msats";
 | 
			
		||||
 | 
			
		||||
-- update to msats
 | 
			
		||||
UPDATE "ItemAct" SET
 | 
			
		||||
"msats" = "msats" * 1000;
 | 
			
		||||
 | 
			
		||||
-- AlterTable
 | 
			
		||||
ALTER TABLE "Withdrawl" ALTER COLUMN "msatsPaying" SET DATA TYPE BIGINT,
 | 
			
		||||
ALTER COLUMN "msatsPaid" SET DATA TYPE BIGINT,
 | 
			
		||||
ALTER COLUMN "msatsFeePaying" SET DATA TYPE BIGINT,
 | 
			
		||||
ALTER COLUMN "msatsFeePaid" SET DATA TYPE BIGINT;
 | 
			
		||||
 | 
			
		||||
-- AlterTable
 | 
			
		||||
ALTER TABLE "users" ALTER COLUMN "msats" SET DEFAULT 0,
 | 
			
		||||
ALTER COLUMN "msats" SET DATA TYPE BIGINT,
 | 
			
		||||
ALTER COLUMN "stackedMsats" SET DEFAULT 0,
 | 
			
		||||
ALTER COLUMN "stackedMsats" SET DATA TYPE BIGINT;
 | 
			
		||||
							
								
								
									
										376
									
								
								prisma/migrations/20221110224543_msats_funcs/migration.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										376
									
								
								prisma/migrations/20221110224543_msats_funcs/migration.sql
									
									
									
									
									
										Normal file
									
								
							@ -0,0 +1,376 @@
 | 
			
		||||
-- item_act should take sats but treat them as msats
 | 
			
		||||
CREATE OR REPLACE FUNCTION item_act(item_id INTEGER, user_id INTEGER, act "ItemActType", act_sats INTEGER)
 | 
			
		||||
RETURNS INTEGER
 | 
			
		||||
LANGUAGE plpgsql
 | 
			
		||||
AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
    user_msats BIGINT;
 | 
			
		||||
    act_msats BIGINT;
 | 
			
		||||
BEGIN
 | 
			
		||||
    PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
 | 
			
		||||
    act_msats := act_sats * 1000;
 | 
			
		||||
    SELECT msats INTO user_msats FROM users WHERE id = user_id;
 | 
			
		||||
    IF act_msats > user_msats THEN
 | 
			
		||||
        RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
    -- deduct msats from actor
 | 
			
		||||
    UPDATE users SET msats = msats - act_msats WHERE id = user_id;
 | 
			
		||||
 | 
			
		||||
    IF act = 'VOTE' OR act = 'TIP' THEN
 | 
			
		||||
        -- add sats to actee's balance and stacked count
 | 
			
		||||
        UPDATE users
 | 
			
		||||
        SET msats = msats + act_msats, "stackedMsats" = "stackedMsats" + act_msats
 | 
			
		||||
        WHERE id = (SELECT COALESCE("fwdUserId", "userId") FROM "Item" WHERE id = item_id);
 | 
			
		||||
 | 
			
		||||
        -- if they have already voted, this is a tip
 | 
			
		||||
        IF EXISTS (SELECT 1 FROM "ItemAct" WHERE "itemId" = item_id AND "userId" = user_id AND "ItemAct".act = 'VOTE') THEN
 | 
			
		||||
            INSERT INTO "ItemAct" (msats, "itemId", "userId", act, created_at, updated_at)
 | 
			
		||||
            VALUES (act_msats, item_id, user_id, 'TIP', now_utc(), now_utc());
 | 
			
		||||
        ELSE
 | 
			
		||||
            -- else this is a vote with a possible extra tip
 | 
			
		||||
            INSERT INTO "ItemAct" (msats, "itemId", "userId", act, created_at, updated_at)
 | 
			
		||||
                VALUES (1000, item_id, user_id, 'VOTE', now_utc(), now_utc());
 | 
			
		||||
            act_msats := act_msats - 1000;
 | 
			
		||||
 | 
			
		||||
            -- if we have sats left after vote, leave them as a tip
 | 
			
		||||
            IF act_msats > 0 THEN
 | 
			
		||||
                INSERT INTO "ItemAct" (msats, "itemId", "userId", act, created_at, updated_at)
 | 
			
		||||
                    VALUES (act_msats, item_id, user_id, 'TIP', now_utc(), now_utc());
 | 
			
		||||
            END IF;
 | 
			
		||||
 | 
			
		||||
            RETURN 1;
 | 
			
		||||
        END IF;
 | 
			
		||||
    ELSE -- BOOST, POLL, DONT_LIKE_THIS
 | 
			
		||||
        INSERT INTO "ItemAct" (msats, "itemId", "userId", act, created_at, updated_at)
 | 
			
		||||
        VALUES (act_msats, item_id, user_id, act, now_utc(), now_utc());
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    RETURN 0;
 | 
			
		||||
END;
 | 
			
		||||
$$;
 | 
			
		||||
 | 
			
		||||
-- when creating free item, set freebie flag so can be optionally viewed
 | 
			
		||||
CREATE OR REPLACE FUNCTION create_item(
 | 
			
		||||
    title TEXT, url TEXT, text TEXT, boost INTEGER,
 | 
			
		||||
    parent_id INTEGER, user_id INTEGER, fwd_user_id INTEGER,
 | 
			
		||||
    spam_within INTERVAL)
 | 
			
		||||
RETURNS "Item"
 | 
			
		||||
LANGUAGE plpgsql
 | 
			
		||||
AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
    user_msats BIGINT;
 | 
			
		||||
    cost_msats BIGINT;
 | 
			
		||||
    free_posts INTEGER;
 | 
			
		||||
    free_comments INTEGER;
 | 
			
		||||
    freebie BOOLEAN;
 | 
			
		||||
    item "Item";
 | 
			
		||||
    med_votes FLOAT;
 | 
			
		||||
BEGIN
 | 
			
		||||
    PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
 | 
			
		||||
    SELECT msats, "freePosts", "freeComments"
 | 
			
		||||
    INTO user_msats, free_posts, free_comments
 | 
			
		||||
    FROM users WHERE id = user_id;
 | 
			
		||||
 | 
			
		||||
    cost_msats := 1000 * POWER(10, item_spam(parent_id, user_id, spam_within));
 | 
			
		||||
    -- it's only a freebie if it's a 1 sat cost, they have < 1 sat, boost = 0, and they have freebies left
 | 
			
		||||
    freebie := (cost_msats <= 1000) AND (user_msats < 1000) AND (boost = 0) AND ((parent_id IS NULL AND free_posts > 0) OR (parent_id IS NOT NULL AND free_comments > 0));
 | 
			
		||||
 | 
			
		||||
    IF NOT freebie AND cost_msats > user_msats THEN
 | 
			
		||||
        RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    -- get this user's median item score
 | 
			
		||||
    SELECT COALESCE(percentile_cont(0.5) WITHIN GROUP(ORDER BY "weightedVotes" - "weightedDownVotes"), 0) INTO med_votes FROM "Item" WHERE "userId" = user_id;
 | 
			
		||||
 | 
			
		||||
    -- if their median votes are positive, start at 0
 | 
			
		||||
    -- if the median votes are negative, start their post with that many down votes
 | 
			
		||||
    -- basically: if their median post is bad, presume this post is too
 | 
			
		||||
    IF med_votes >= 0 THEN
 | 
			
		||||
        med_votes := 0;
 | 
			
		||||
    ELSE
 | 
			
		||||
        med_votes := ABS(med_votes);
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    INSERT INTO "Item" (title, url, text, "userId", "parentId", "fwdUserId", freebie, "weightedDownVotes", created_at, updated_at)
 | 
			
		||||
    VALUES (title, url, text, user_id, parent_id, fwd_user_id, freebie, med_votes, now_utc(), now_utc()) RETURNING * INTO item;
 | 
			
		||||
 | 
			
		||||
    IF freebie THEN
 | 
			
		||||
        IF parent_id IS NULL THEN
 | 
			
		||||
            UPDATE users SET "freePosts" = "freePosts" - 1 WHERE id = user_id;
 | 
			
		||||
        ELSE
 | 
			
		||||
            UPDATE users SET "freeComments" = "freeComments" - 1 WHERE id = user_id;
 | 
			
		||||
        END IF;
 | 
			
		||||
    ELSE
 | 
			
		||||
        UPDATE users SET msats = msats - cost_msats WHERE id = user_id;
 | 
			
		||||
 | 
			
		||||
        INSERT INTO "ItemAct" (msats, "itemId", "userId", act, created_at, updated_at)
 | 
			
		||||
        VALUES (cost_msats, item.id, user_id, 'VOTE', now_utc(), now_utc());
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    IF boost > 0 THEN
 | 
			
		||||
        PERFORM item_act(item.id, user_id, 'BOOST', boost);
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    RETURN item;
 | 
			
		||||
END;
 | 
			
		||||
$$;
 | 
			
		||||
 | 
			
		||||
CREATE OR REPLACE FUNCTION run_auction(item_id INTEGER) RETURNS void AS $$
 | 
			
		||||
    DECLARE
 | 
			
		||||
        bid_msats BIGINT;
 | 
			
		||||
        user_msats BIGINT;
 | 
			
		||||
        user_id INTEGER;
 | 
			
		||||
        item_status "Status";
 | 
			
		||||
        status_updated_at timestamp(3);
 | 
			
		||||
    BEGIN
 | 
			
		||||
        PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
 | 
			
		||||
        -- extract data we need
 | 
			
		||||
        SELECT "maxBid" * 1000, "userId", status, "statusUpdatedAt" INTO bid_msats, user_id, item_status, status_updated_at FROM "Item" WHERE id = item_id;
 | 
			
		||||
        SELECT msats INTO user_msats FROM users WHERE id = user_id;
 | 
			
		||||
 | 
			
		||||
        -- 0 bid items expire after 30 days unless updated
 | 
			
		||||
        IF bid_msats = 0 THEN
 | 
			
		||||
            IF item_status <> 'STOPPED' THEN
 | 
			
		||||
                IF status_updated_at < now_utc() - INTERVAL '30 days' THEN
 | 
			
		||||
                    UPDATE "Item" SET status = 'STOPPED', "statusUpdatedAt" = now_utc() WHERE id = item_id;
 | 
			
		||||
                ELSEIF item_status = 'NOSATS' THEN
 | 
			
		||||
                    UPDATE "Item" SET status = 'ACTIVE' WHERE id = item_id;
 | 
			
		||||
                END IF;
 | 
			
		||||
            END IF;
 | 
			
		||||
            RETURN;
 | 
			
		||||
        END IF;
 | 
			
		||||
 | 
			
		||||
        -- check if user wallet has enough sats
 | 
			
		||||
        IF bid_msats > user_msats THEN
 | 
			
		||||
            -- if not, set status = NOSATS and statusUpdatedAt to now_utc if not already set
 | 
			
		||||
            IF item_status <> 'NOSATS' THEN
 | 
			
		||||
                UPDATE "Item" SET status = 'NOSATS', "statusUpdatedAt" = now_utc() WHERE id = item_id;
 | 
			
		||||
            END IF;
 | 
			
		||||
        ELSE
 | 
			
		||||
            -- if so, deduct from user
 | 
			
		||||
            UPDATE users SET msats = msats - bid_msats WHERE id = user_id;
 | 
			
		||||
 | 
			
		||||
            -- create an item act
 | 
			
		||||
            INSERT INTO "ItemAct" (msats, "itemId", "userId", act, created_at, updated_at)
 | 
			
		||||
            VALUES (bid_msats, item_id, user_id, 'STREAM', now_utc(), now_utc());
 | 
			
		||||
 | 
			
		||||
            -- update item status = ACTIVE and statusUpdatedAt = now_utc if NOSATS
 | 
			
		||||
            IF item_status = 'NOSATS' THEN
 | 
			
		||||
                UPDATE "Item" SET status = 'ACTIVE', "statusUpdatedAt" = now_utc() WHERE id = item_id;
 | 
			
		||||
            END IF;
 | 
			
		||||
        END IF;
 | 
			
		||||
    END;
 | 
			
		||||
$$ LANGUAGE plpgsql;
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
-- on item act denormalize sats and comment sats
 | 
			
		||||
CREATE OR REPLACE FUNCTION sats_after_act() RETURNS TRIGGER AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
    item "Item";
 | 
			
		||||
BEGIN
 | 
			
		||||
    SELECT * FROM "Item" WHERE id = NEW."itemId" INTO item;
 | 
			
		||||
    IF item."userId" = NEW."userId" THEN
 | 
			
		||||
        RETURN NEW;
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    UPDATE "Item"
 | 
			
		||||
    SET "msats" = "msats" + NEW.msats
 | 
			
		||||
    WHERE id = item.id;
 | 
			
		||||
 | 
			
		||||
    UPDATE "Item"
 | 
			
		||||
    SET "commentMsats" = "commentMsats" + NEW.msats
 | 
			
		||||
    WHERE id <> item.id and path @> item.path;
 | 
			
		||||
 | 
			
		||||
    RETURN NEW;
 | 
			
		||||
END;
 | 
			
		||||
$$ LANGUAGE plpgsql;
 | 
			
		||||
 | 
			
		||||
DROP TRIGGER IF EXISTS sats_after_act_trigger ON "ItemAct";
 | 
			
		||||
CREATE TRIGGER sats_after_act_trigger
 | 
			
		||||
    AFTER INSERT ON "ItemAct"
 | 
			
		||||
    FOR EACH ROW
 | 
			
		||||
    WHEN (NEW.act = 'VOTE' or NEW.act = 'TIP')
 | 
			
		||||
    EXECUTE PROCEDURE sats_after_act();
 | 
			
		||||
 | 
			
		||||
CREATE OR REPLACE FUNCTION boost_after_act() RETURNS TRIGGER AS $$
 | 
			
		||||
BEGIN
 | 
			
		||||
    -- update item
 | 
			
		||||
    UPDATE "Item" SET boost = boost + FLOOR(NEW.msats / 1000) WHERE id = NEW."itemId";
 | 
			
		||||
    RETURN NEW;
 | 
			
		||||
END;
 | 
			
		||||
$$ LANGUAGE plpgsql;
 | 
			
		||||
 | 
			
		||||
DROP TRIGGER IF EXISTS boost_after_act ON "ItemAct";
 | 
			
		||||
CREATE TRIGGER boost_after_act
 | 
			
		||||
    AFTER INSERT ON "ItemAct"
 | 
			
		||||
    FOR EACH ROW
 | 
			
		||||
    WHEN (NEW.act = 'BOOST')
 | 
			
		||||
    EXECUTE PROCEDURE boost_after_act();
 | 
			
		||||
 | 
			
		||||
DROP FUNCTION IF EXISTS create_invoice(TEXT, TEXT, timestamp(3) without time zone, INTEGER, INTEGER);
 | 
			
		||||
CREATE OR REPLACE FUNCTION create_invoice(hash TEXT, bolt11 TEXT, expires_at timestamp(3) without time zone, msats_req BIGINT, user_id INTEGER)
 | 
			
		||||
RETURNS "Invoice"
 | 
			
		||||
LANGUAGE plpgsql
 | 
			
		||||
AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
    invoice "Invoice";
 | 
			
		||||
    limit_reached BOOLEAN;
 | 
			
		||||
    too_much BOOLEAN;
 | 
			
		||||
BEGIN
 | 
			
		||||
    PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
 | 
			
		||||
    SELECT count(*) >= 10, coalesce(sum("msatsRequested"),0)+coalesce(max(users.msats), 0)+msats_req > 1000000000 INTO limit_reached, too_much
 | 
			
		||||
    FROM "Invoice"
 | 
			
		||||
    JOIN users on "userId" = users.id
 | 
			
		||||
    WHERE "userId" = user_id AND "expiresAt" > now_utc() AND "confirmedAt" is null AND cancelled = false;
 | 
			
		||||
 | 
			
		||||
    -- prevent more than 10 pending invoices
 | 
			
		||||
    IF limit_reached THEN
 | 
			
		||||
        RAISE EXCEPTION 'SN_INV_PENDING_LIMIT';
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    -- prevent pending invoices + msats from exceeding 1,000,000 sats
 | 
			
		||||
    IF too_much THEN
 | 
			
		||||
        RAISE EXCEPTION 'SN_INV_EXCEED_BALANCE';
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    INSERT INTO "Invoice" (hash, bolt11, "expiresAt", "msatsRequested", "userId", created_at, updated_at)
 | 
			
		||||
    VALUES (hash, bolt11, expires_at, msats_req, user_id, now_utc(), now_utc()) RETURNING * INTO invoice;
 | 
			
		||||
 | 
			
		||||
    INSERT INTO pgboss.job (name, data, retrylimit, retrybackoff, startafter)
 | 
			
		||||
    VALUES ('checkInvoice', jsonb_build_object('hash', hash), 21, true, now() + interval '10 seconds');
 | 
			
		||||
 | 
			
		||||
    RETURN invoice;
 | 
			
		||||
END;
 | 
			
		||||
$$;
 | 
			
		||||
 | 
			
		||||
DROP FUNCTION IF EXISTS confirm_invoice(TEXT, INTEGER);
 | 
			
		||||
CREATE OR REPLACE FUNCTION confirm_invoice(lnd_id TEXT, lnd_received BIGINT)
 | 
			
		||||
RETURNS INTEGER
 | 
			
		||||
LANGUAGE plpgsql
 | 
			
		||||
AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
    user_id INTEGER;
 | 
			
		||||
    confirmed_at TIMESTAMP;
 | 
			
		||||
BEGIN
 | 
			
		||||
    PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
 | 
			
		||||
    SELECT "userId", "confirmedAt" INTO user_id, confirmed_at FROM "Invoice" WHERE hash = lnd_id;
 | 
			
		||||
    IF confirmed_at IS NULL THEN
 | 
			
		||||
        UPDATE "Invoice" SET "msatsReceived" = lnd_received, "confirmedAt" = now_utc(), updated_at = now_utc()
 | 
			
		||||
        WHERE hash = lnd_id;
 | 
			
		||||
        UPDATE users SET msats = msats + lnd_received WHERE id = user_id;
 | 
			
		||||
    END IF;
 | 
			
		||||
    RETURN 0;
 | 
			
		||||
END;
 | 
			
		||||
$$;
 | 
			
		||||
 | 
			
		||||
DROP FUNCTION IF EXISTS create_withdrawl(TEXT, TEXT, INTEGER, INTEGER, TEXT);
 | 
			
		||||
CREATE OR REPLACE FUNCTION create_withdrawl(lnd_id TEXT, invoice TEXT, msats_amount BIGINT, msats_max_fee BIGINT, username TEXT)
 | 
			
		||||
RETURNS "Withdrawl"
 | 
			
		||||
LANGUAGE plpgsql
 | 
			
		||||
AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
    user_id INTEGER;
 | 
			
		||||
    user_msats BIGINT;
 | 
			
		||||
    withdrawl "Withdrawl";
 | 
			
		||||
BEGIN
 | 
			
		||||
    PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
 | 
			
		||||
    SELECT msats, id INTO user_msats, user_id FROM users WHERE name = username;
 | 
			
		||||
    IF (msats_amount + msats_max_fee) > user_msats THEN
 | 
			
		||||
        RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    IF EXISTS (SELECT 1 FROM "Withdrawl" WHERE hash = lnd_id AND status IS NULL) THEN
 | 
			
		||||
        RAISE EXCEPTION 'SN_PENDING_WITHDRAWL_EXISTS';
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    IF EXISTS (SELECT 1 FROM "Withdrawl" WHERE hash = lnd_id AND status = 'CONFIRMED') THEN
 | 
			
		||||
        RAISE EXCEPTION 'SN_CONFIRMED_WITHDRAWL_EXISTS';
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    INSERT INTO "Withdrawl" (hash, bolt11, "msatsPaying", "msatsFeePaying", "userId", created_at, updated_at)
 | 
			
		||||
    VALUES (lnd_id, invoice, msats_amount, msats_max_fee, user_id, now_utc(), now_utc()) RETURNING * INTO withdrawl;
 | 
			
		||||
 | 
			
		||||
    UPDATE users SET msats = msats - msats_amount - msats_max_fee WHERE id = user_id;
 | 
			
		||||
 | 
			
		||||
    INSERT INTO pgboss.job (name, data, retrylimit, retrybackoff, startafter)
 | 
			
		||||
    VALUES ('checkWithdrawal', jsonb_build_object('id', withdrawl.id, 'hash', lnd_id), 21, true, now() + interval '10 seconds');
 | 
			
		||||
 | 
			
		||||
    RETURN withdrawl;
 | 
			
		||||
END;
 | 
			
		||||
$$;
 | 
			
		||||
 | 
			
		||||
DROP FUNCTION IF EXISTS confirm_withdrawl(INTEGER, INTEGER, INTEGER);
 | 
			
		||||
CREATE OR REPLACE FUNCTION confirm_withdrawl(wid INTEGER, msats_paid BIGINT, msats_fee_paid BIGINT)
 | 
			
		||||
RETURNS INTEGER
 | 
			
		||||
LANGUAGE plpgsql
 | 
			
		||||
AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
    msats_fee_paying BIGINT;
 | 
			
		||||
    user_id INTEGER;
 | 
			
		||||
BEGIN
 | 
			
		||||
    PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
 | 
			
		||||
    IF EXISTS (SELECT 1 FROM "Withdrawl" WHERE id = wid AND status IS NULL) THEN
 | 
			
		||||
        SELECT "msatsFeePaying", "userId" INTO msats_fee_paying, user_id
 | 
			
		||||
        FROM "Withdrawl" WHERE id = wid AND status IS NULL;
 | 
			
		||||
 | 
			
		||||
        UPDATE "Withdrawl"
 | 
			
		||||
        SET status = 'CONFIRMED', "msatsPaid" = msats_paid,
 | 
			
		||||
        "msatsFeePaid" = msats_fee_paid, updated_at = now_utc()
 | 
			
		||||
        WHERE id = wid AND status IS NULL;
 | 
			
		||||
 | 
			
		||||
        UPDATE users SET msats = msats + (msats_fee_paying - msats_fee_paid) WHERE id = user_id;
 | 
			
		||||
    END IF;
 | 
			
		||||
 | 
			
		||||
    RETURN 0;
 | 
			
		||||
END;
 | 
			
		||||
$$;
 | 
			
		||||
 | 
			
		||||
CREATE OR REPLACE FUNCTION reverse_withdrawl(wid INTEGER, wstatus "WithdrawlStatus")
 | 
			
		||||
RETURNS INTEGER
 | 
			
		||||
LANGUAGE plpgsql
 | 
			
		||||
AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
    msats_fee_paying BIGINT;
 | 
			
		||||
    msats_paying BIGINT;
 | 
			
		||||
    user_id INTEGER;
 | 
			
		||||
BEGIN
 | 
			
		||||
    PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
 | 
			
		||||
    IF EXISTS (SELECT 1 FROM "Withdrawl" WHERE id = wid AND status IS NULL) THEN
 | 
			
		||||
        SELECT "msatsPaying", "msatsFeePaying", "userId" INTO msats_paying, msats_fee_paying, user_id
 | 
			
		||||
        FROM "Withdrawl" WHERE id = wid AND status IS NULL;
 | 
			
		||||
 | 
			
		||||
        UPDATE "Withdrawl" SET status = wstatus, updated_at = now_utc() WHERE id = wid AND status IS NULL;
 | 
			
		||||
 | 
			
		||||
        UPDATE users SET msats = msats + msats_paying + msats_fee_paying WHERE id = user_id;
 | 
			
		||||
    END IF;
 | 
			
		||||
    RETURN 0;
 | 
			
		||||
END;
 | 
			
		||||
$$;
 | 
			
		||||
 | 
			
		||||
DROP FUNCTION IF EXISTS earn(INTEGER, INTEGER, TIMESTAMP(3), "EarnType", INTEGER, INTEGER);
 | 
			
		||||
CREATE OR REPLACE FUNCTION earn(user_id INTEGER, earn_msats BIGINT, created_at TIMESTAMP(3),
 | 
			
		||||
    type "EarnType", type_id INTEGER, rank INTEGER)
 | 
			
		||||
RETURNS void AS $$
 | 
			
		||||
DECLARE
 | 
			
		||||
BEGIN
 | 
			
		||||
    PERFORM ASSERT_SERIALIZED();
 | 
			
		||||
    -- insert into earn
 | 
			
		||||
    INSERT INTO "Earn" (msats, "userId", created_at, type, "typeId", rank)
 | 
			
		||||
    VALUES (earn_msats, user_id, created_at, type, type_id, rank);
 | 
			
		||||
 | 
			
		||||
    -- give the user the sats
 | 
			
		||||
    UPDATE users
 | 
			
		||||
    SET msats = msats + earn_msats, "stackedMsats" = "stackedMsats" + earn_msats
 | 
			
		||||
    WHERE id = user_id;
 | 
			
		||||
END;
 | 
			
		||||
$$ LANGUAGE plpgsql;
 | 
			
		||||
@ -30,8 +30,8 @@ model User {
 | 
			
		||||
  inviteId        String?
 | 
			
		||||
  bio             Item?       @relation(fields: [bioId], references: [id])
 | 
			
		||||
  bioId           Int?
 | 
			
		||||
  msats           Int         @default(0)
 | 
			
		||||
  stackedMsats    Int         @default(0)
 | 
			
		||||
  msats           BigInt      @default(0)
 | 
			
		||||
  stackedMsats    BigInt      @default(0)
 | 
			
		||||
  freeComments    Int         @default(5)
 | 
			
		||||
  freePosts       Int         @default(2)
 | 
			
		||||
  checkedNotesAt  DateTime?
 | 
			
		||||
@ -105,8 +105,8 @@ model Earn {
 | 
			
		||||
  createdAt DateTime @default(now()) @map(name: "created_at")
 | 
			
		||||
  updatedAt DateTime @default(now()) @updatedAt @map(name: "updated_at")
 | 
			
		||||
 | 
			
		||||
  msats  Int
 | 
			
		||||
  user   User @relation(fields: [userId], references: [id])
 | 
			
		||||
  msats  BigInt
 | 
			
		||||
  user   User   @relation(fields: [userId], references: [id])
 | 
			
		||||
  userId Int
 | 
			
		||||
 | 
			
		||||
  type   EarnType?
 | 
			
		||||
@ -192,13 +192,13 @@ model Item {
 | 
			
		||||
  bio     Boolean @default(false)
 | 
			
		||||
 | 
			
		||||
  // denormalized self stats
 | 
			
		||||
  weightedVotes     Float @default(0)
 | 
			
		||||
  weightedDownVotes Float @default(0)
 | 
			
		||||
  sats              Int   @default(0)
 | 
			
		||||
  weightedVotes     Float  @default(0)
 | 
			
		||||
  weightedDownVotes Float  @default(0)
 | 
			
		||||
  msats             BigInt @default(0)
 | 
			
		||||
 | 
			
		||||
  // denormalized comment stats
 | 
			
		||||
  ncomments     Int       @default(0)
 | 
			
		||||
  commentSats   Int       @default(0)
 | 
			
		||||
  commentMsats  BigInt    @default(0)
 | 
			
		||||
  lastCommentAt DateTime?
 | 
			
		||||
 | 
			
		||||
  // if sub is null, this is the main sub
 | 
			
		||||
@ -317,7 +317,7 @@ model ItemAct {
 | 
			
		||||
  id        Int         @id @default(autoincrement())
 | 
			
		||||
  createdAt DateTime    @default(now()) @map(name: "created_at")
 | 
			
		||||
  updatedAt DateTime    @updatedAt @map(name: "updated_at")
 | 
			
		||||
  sats      Int
 | 
			
		||||
  msats     BigInt
 | 
			
		||||
  act       ItemActType
 | 
			
		||||
  item      Item        @relation(fields: [itemId], references: [id])
 | 
			
		||||
  itemId    Int
 | 
			
		||||
@ -356,8 +356,8 @@ model Invoice {
 | 
			
		||||
  bolt11         String
 | 
			
		||||
  expiresAt      DateTime
 | 
			
		||||
  confirmedAt    DateTime?
 | 
			
		||||
  msatsRequested Int
 | 
			
		||||
  msatsReceived  Int?
 | 
			
		||||
  msatsRequested BigInt
 | 
			
		||||
  msatsReceived  BigInt?
 | 
			
		||||
  cancelled      Boolean   @default(false)
 | 
			
		||||
 | 
			
		||||
  @@index([createdAt])
 | 
			
		||||
@ -382,10 +382,10 @@ model Withdrawl {
 | 
			
		||||
 | 
			
		||||
  hash           String
 | 
			
		||||
  bolt11         String
 | 
			
		||||
  msatsPaying    Int
 | 
			
		||||
  msatsPaid      Int?
 | 
			
		||||
  msatsFeePaying Int
 | 
			
		||||
  msatsFeePaid   Int?
 | 
			
		||||
  msatsPaying    BigInt
 | 
			
		||||
  msatsPaid      BigInt?
 | 
			
		||||
  msatsFeePaying BigInt
 | 
			
		||||
  msatsFeePaid   BigInt?
 | 
			
		||||
 | 
			
		||||
  status WithdrawlStatus?
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
@ -10,17 +10,14 @@ function earn ({ models }) {
 | 
			
		||||
    console.log('running', name)
 | 
			
		||||
 | 
			
		||||
    // compute how much sn earned today
 | 
			
		||||
    let [{ sum }] = await models.$queryRaw`
 | 
			
		||||
        SELECT sum("ItemAct".sats)
 | 
			
		||||
    const [{ sum }] = await models.$queryRaw`
 | 
			
		||||
        SELECT sum("ItemAct".msats)
 | 
			
		||||
        FROM "ItemAct"
 | 
			
		||||
        JOIN "Item" on "ItemAct"."itemId" = "Item".id
 | 
			
		||||
        WHERE ("ItemAct".act in ('BOOST', 'STREAM')
 | 
			
		||||
          OR ("ItemAct".act IN ('VOTE','POLL') AND "Item"."userId" = "ItemAct"."userId"))
 | 
			
		||||
          AND "ItemAct".created_at > now_utc() - INTERVAL '1 day'`
 | 
			
		||||
 | 
			
		||||
    // convert to msats
 | 
			
		||||
    sum = sum * 1000
 | 
			
		||||
 | 
			
		||||
    /*
 | 
			
		||||
      How earnings work:
 | 
			
		||||
      1/3: top 21% posts over last 36 hours, scored on a relative basis
 | 
			
		||||
@ -56,7 +53,7 @@ function earn ({ models }) {
 | 
			
		||||
      ),
 | 
			
		||||
      upvoters AS (
 | 
			
		||||
          SELECT "ItemAct"."userId", item_ratios.id, item_ratios.ratio, item_ratios."parentId",
 | 
			
		||||
              sum("ItemAct".sats) as tipped, min("ItemAct".created_at) as acted_at
 | 
			
		||||
              sum("ItemAct".msats) as tipped, min("ItemAct".created_at) as acted_at
 | 
			
		||||
          FROM item_ratios
 | 
			
		||||
          JOIN "ItemAct" on "ItemAct"."itemId" = item_ratios.id
 | 
			
		||||
          WHERE act IN ('VOTE','TIP')
 | 
			
		||||
 | 
			
		||||
		Loading…
	
	
			
			x
			
			
		
	
		Reference in New Issue
	
	Block a user