diff --git a/internal/admin/api.go b/internal/admin/api.go index 633a309..c3f0053 100644 --- a/internal/admin/api.go +++ b/internal/admin/api.go @@ -35,6 +35,8 @@ func InitAdminApi(e *echo.Echo, db *pgxpool.Pool, queries goyesql.Queries, metaC g.GET("/pin-status", handlePinStatus) g.GET("/phone-2-address/:phone", handlePhone2Address) 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 { diff --git a/internal/admin/transactions.go b/internal/admin/transactions.go new file mode 100644 index 0000000..623f8f1 --- /dev/null +++ b/internal/admin/transactions.go @@ -0,0 +1,96 @@ +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" +) + +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 + ) + + 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 + ) + + 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) +} diff --git a/internal/public/tokens.go b/internal/public/tokens.go index af97c0d..9af776c 100644 --- a/internal/public/tokens.go +++ b/internal/public/tokens.go @@ -2,7 +2,6 @@ package public import ( "cic-dw/pkg/address" - "cic-dw/pkg/pagination" "context" "net/http" @@ -37,19 +36,11 @@ type tokenSummaryRes struct { func handleTokenListQuery(c echo.Context) error { var ( api = c.Get("api").(*api) - pg = pagination.GetPagination(c.QueryParams()) res []tokensRes - q string ) - if pg.Forward { - 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) + rows, err := api.db.Query(context.Background(), api.q["list-tokens"]) if err != nil { return err } diff --git a/migrations/005_descending_index.sql b/migrations/005_descending_index.sql new file mode 100644 index 0000000..f55d435 --- /dev/null +++ b/migrations/005_descending_index.sql @@ -0,0 +1,5 @@ +CREATE UNIQUE INDEX index_id ON transactions USING btree (ID DESC); + +---- create above / drop below ---- + +DROP INDEX index_id; \ No newline at end of file diff --git a/pkg/pagination/pagination.go b/pkg/pagination/pagination.go index 80a2a95..5499c6f 100644 --- a/pkg/pagination/pagination.go +++ b/pkg/pagination/pagination.go @@ -6,29 +6,32 @@ import ( ) type Pagination struct { - PerPage int - Cursor int - Forward bool + PerPage int + Cursor int + Next bool + FirstPage bool } func GetPagination(q url.Values) Pagination { var ( - pp, _ = strconv.Atoi(q.Get("per_page")) - cursor, _ = strconv.Atoi(q.Get("cursor")) - forward, _ = strconv.ParseBool(q.Get("forward")) + pp, _ = strconv.Atoi(q.Get("per_page")) + cursor, _ = strconv.Atoi(q.Get("cursor")) + next, _ = strconv.ParseBool(q.Get("next")) + firstPage = false ) if pp > 100 { pp = 100 } - if !forward && cursor < 1 { - cursor = 1 + if !next && cursor < 1 { + firstPage = true } return Pagination{ - PerPage: pp, - Cursor: cursor, - Forward: forward, + PerPage: pp, + Cursor: cursor, + Next: next, + FirstPage: firstPage, } } diff --git a/queries/admin.sql b/queries/admin.sql index fbba55a..953d6b9 100644 --- a/queries/admin.sql +++ b/queries/admin.sql @@ -11,8 +11,72 @@ CASE STATUS FROM cic_ussd.account WHERE failed_pin_attempts > 0 OR STATUS = 4; ---name: phone-2-address +-- name: phone-2-address SELECT blockchain_address FROM users WHERE phone_number = $1; ---name: address-2-phone -SELECT phone_number FROM users WHERE blockchain_address = $1; \ No newline at end of file +-- name: address-2-phone +SELECT phone_number FROM users WHERE blockchain_address = $1; + +-- name: account-latest-transactions +-- Returns the first page of a users latest transactions +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 ORDER BY transactions.id DESC LIMIT $2; + +-- name: account-latest-transactions-next +-- Returns the next page based on a cursor +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 DESC LIMIT $3; + +-- name: account-latest-transactions-previous +-- 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 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 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; \ No newline at end of file diff --git a/queries/public.sql b/queries/public.sql index d7b034e..24f1d7a 100644 --- a/queries/public.sql +++ b/queries/public.sql @@ -6,13 +6,8 @@ WHERE transactions.sender_address = $1 OR transactions.recipient_address = $1; -- Bidirectional cursor paginators --- name: list-tokens-fwd -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: list-tokens +SELECT tokens.id, tokens.token_address, tokens.token_name, tokens.token_symbol FROM tokens; -- name: tokens-count -- Return total record count from individual i= tables/views