fix: pagination queries

- refactor keyset pagination query to correctly fecth previous page
- remove pagination from token list
- add fetch latest transactions by token
This commit is contained in:
Mohamed Sohail 2022-06-16 12:21:58 +03:00
parent 6f7c6d9718
commit fe0e102a61
Signed by: kamikazechaser
GPG Key ID: 7DD45520C01CD85D
6 changed files with 163 additions and 39 deletions

View File

@ -35,6 +35,8 @@ func InitAdminApi(e *echo.Echo, db *pgxpool.Pool, queries goyesql.Queries, metaC
g.GET("/pin-status", handlePinStatus) g.GET("/pin-status", handlePinStatus)
g.GET("/phone-2-address/:phone", handlePhone2Address) g.GET("/phone-2-address/:phone", handlePhone2Address)
g.GET("/address-2-phone/:address", handleAddress2Phone) g.GET("/address-2-phone/:address", handleAddress2Phone)
g.GET("/latest-transactions/:phone", handleLatestTransactions)
g.GET("/latest-transactions-by-token/:phone/:token", handleLatestTransactionsByToken)
} }
func newApi(db *pgxpool.Pool, queries goyesql.Queries, metaClient *meta.CicMeta, jwtKey string) *api { func newApi(db *pgxpool.Pool, queries goyesql.Queries, metaClient *meta.CicMeta, jwtKey string) *api {

View File

@ -0,0 +1,101 @@
package admin
import (
"cic-dw/pkg/pagination"
"context"
"net/http"
"time"
"github.com/georgysavva/scany/pgxscan"
"github.com/jackc/pgx/v4"
"github.com/labstack/echo/v4"
"github.com/rs/zerolog/log"
)
type userTransactionRes struct {
Id int64 `db:"id" json:"id"`
Date time.Time `db:"date_block" json:"tx_date"`
TxHash string `db:"tx_hash" json:"tx_hash"`
TokenSymbol string `db:"token_symbol" json:"voucher"`
SenderAddress string `db:"sender_address" json:"sender_address"`
RecipeintAddress string `db:"recipient_address" json:"recipient_address"`
TxValue int64 `db:"tx_value" json:"tx_value"`
TxSuccess bool `db:"success" json:"tx_success"`
SenderIdentifier string `db:"sender_identifier" json:"sender_identifier"`
RecipientIdentifier string `db:"recipient_identifier" json:"recipient_identifier"`
}
func handleLatestTransactions(c echo.Context) error {
var (
api = c.Get("api").(*api)
phone = c.Param("phone")
pg = pagination.GetPagination(c.QueryParams())
data []userTransactionRes
rows pgx.Rows
err error
)
log.Info().Msgf("%v", pg)
if pg.FirstPage {
rows, err = api.db.Query(context.Background(), api.q["account-latest-transactions"], phone, pg.PerPage)
if err != nil {
return err
}
} else if pg.Next {
rows, err = api.db.Query(context.Background(), api.q["account-latest-transactions-next"], phone, pg.Cursor, pg.PerPage)
if err != nil {
return err
}
} else {
rows, err = api.db.Query(context.Background(), api.q["account-latest-transactions-previous"], phone, pg.Cursor, pg.PerPage)
if err != nil {
return err
}
}
if err := pgxscan.ScanAll(&data, rows); err != nil {
return err
}
return c.JSON(http.StatusOK, data)
}
func handleLatestTransactionsByToken(c echo.Context) error {
var (
api = c.Get("api").(*api)
phone = c.Param("phone")
token = c.Param("token")
pg = pagination.GetPagination(c.QueryParams())
data []userTransactionRes
rows pgx.Rows
err error
)
log.Info().Msgf("%v", pg)
if pg.FirstPage {
rows, err = api.db.Query(context.Background(), api.q["account-latest-transactions-by-token"], phone, token, pg.PerPage)
if err != nil {
return err
}
} else if pg.Next {
rows, err = api.db.Query(context.Background(), api.q["account-latest-transactions-by-token-next"], phone, token, pg.Cursor, pg.PerPage)
if err != nil {
return err
}
} else {
rows, err = api.db.Query(context.Background(), api.q["account-latest-transactions-by-token-previous"], phone, token, pg.Cursor, pg.PerPage)
if err != nil {
return err
}
}
if err := pgxscan.ScanAll(&data, rows); err != nil {
return err
}
return c.JSON(http.StatusOK, data)
}

View File

@ -2,7 +2,6 @@ package public
import ( import (
"cic-dw/pkg/address" "cic-dw/pkg/address"
"cic-dw/pkg/pagination"
"context" "context"
"net/http" "net/http"
@ -37,19 +36,11 @@ type tokenSummaryRes struct {
func handleTokenListQuery(c echo.Context) error { func handleTokenListQuery(c echo.Context) error {
var ( var (
api = c.Get("api").(*api) api = c.Get("api").(*api)
pg = pagination.GetPagination(c.QueryParams())
res []tokensRes res []tokensRes
q string
) )
if pg.Forward { rows, err := api.db.Query(context.Background(), api.q["list-tokens"])
q = api.q["list-tokens-fwd"]
} else {
q = api.q["list-tokens-bkwd"]
}
rows, err := api.db.Query(context.Background(), q, pg.Cursor, pg.PerPage)
if err != nil { if err != nil {
return err return err
} }

View File

@ -6,29 +6,32 @@ import (
) )
type Pagination struct { type Pagination struct {
PerPage int PerPage int
Cursor int Cursor int
Forward bool Next bool
FirstPage bool
} }
func GetPagination(q url.Values) Pagination { func GetPagination(q url.Values) Pagination {
var ( var (
pp, _ = strconv.Atoi(q.Get("per_page")) pp, _ = strconv.Atoi(q.Get("per_page"))
cursor, _ = strconv.Atoi(q.Get("cursor")) cursor, _ = strconv.Atoi(q.Get("cursor"))
forward, _ = strconv.ParseBool(q.Get("forward")) next, _ = strconv.ParseBool(q.Get("next"))
firstPage = false
) )
if pp > 100 { if pp > 100 {
pp = 100 pp = 100
} }
if !forward && cursor < 1 { if !next && cursor < 1 {
cursor = 1 firstPage = true
} }
return Pagination{ return Pagination{
PerPage: pp, PerPage: pp,
Cursor: cursor, Cursor: cursor,
Forward: forward, Next: next,
FirstPage: firstPage,
} }
} }

View File

@ -17,34 +17,66 @@ SELECT blockchain_address FROM users WHERE phone_number = $1;
-- name: address-2-phone -- name: address-2-phone
SELECT phone_number FROM users WHERE blockchain_address = $1; SELECT phone_number FROM users WHERE blockchain_address = $1;
-- name: account-transactions-fwd -- name: account-latest-transactions
-- Returns a users transactions joining appropriate information across multiple tables -- Returns the first page of a users latest transactions
-- Useful for full history traversal via API
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success, SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier, (SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier (SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
FROM transactions FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address)) INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address INNER JOIN tokens ON transactions.token_address = tokens.token_address
WHERE users.phone_number = $1 AND transactions.id > $2 ORDER BY transactions.id ASC LIMIT $3; WHERE users.phone_number = $1 ORDER BY transactions.id DESC LIMIT $2;
-- name: account-transactions-bkwd -- name: account-latest-transactions-next
-- Returns a users transactions joining appropriate information across multiple tables -- Returns the next page based on a cursor
-- Useful for full history traversal via API
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success, SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier, (SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier (SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
FROM transactions FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address)) INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address INNER JOIN tokens ON transactions.token_address = tokens.token_address
WHERE users.phone_number = $1 AND transactions.id < $2 ORDER BY transactions.id ASC LIMIT $3; WHERE users.phone_number = $1 AND transactions.id < $2 ORDER BY transactions.id DESC LIMIT $3;
-- name: account-transactions-latest-by-token -- name: account-latest-transactions-previous
-- Retrieves latest transactions by a specific token with a limit -- Returns the previous page based on cursor
SELECT * FROM (
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
WHERE users.phone_number = $1 AND transactions.id > $2 ORDER BY transactions.id ASC LIMIT $3
) AS previous_page ORDER BY id DESC;
-- name: account-latest-transactions-by-token
-- Returns the first page of a users latest transactions, filter by token
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success, SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier, (SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier (SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
FROM transactions FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address)) INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address INNER JOIN tokens ON transactions.token_address = tokens.token_address
WHERE users.phone_number = $1 AND tokens.token_symbol = $2 ORDER BY transactions.id DESC LIMIT $3; WHERE users.phone_number = $1 AND tokens.token_symbol = $2 ORDER BY transactions.id DESC LIMIT $3;
-- name: account-latest-transactions-by-token-next
-- Returns the next page based on a cursor, filter by token
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
WHERE users.phone_number = $1 AND tokens.token_symbol = $2 AND transactions.id < $3 ORDER BY transactions.id DESC LIMIT $4;
-- name: account-latest-transactions-by-token-previous
-- Returns the previous page based on cursor, filter by token
SELECT * FROM (
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
WHERE users.phone_number = $1 AND tokens.token_symbol = $2 AND transactions.id > $3 ORDER BY transactions.id ASC LIMIT $4
) AS previous_page ORDER BY id DESC;

View File

@ -6,13 +6,8 @@ WHERE transactions.sender_address = $1
OR transactions.recipient_address = $1; OR transactions.recipient_address = $1;
-- Bidirectional cursor paginators -- Bidirectional cursor paginators
-- name: list-tokens-fwd -- name: list-tokens
SELECT tokens.id, tokens.token_address, tokens.token_name, tokens.token_symbol FROM tokens SELECT tokens.id, tokens.token_address, tokens.token_name, tokens.token_symbol FROM tokens;
WHERE tokens.id > $1 ORDER BY tokens.id ASC LIMIT $2;
-- name: list-tokens-bkwd
SELECT tokens.id, tokens.token_address, tokens.token_name, tokens.token_symbol FROM tokens
WHERE tokens.id < $1 ORDER BY tokens.id ASC LIMIT $2;
-- name: tokens-count -- name: tokens-count
-- Return total record count from individual i= tables/views -- Return total record count from individual i= tables/views