diff --git a/README.md b/README.md index 6a9facc..b9bfd2a 100644 --- a/README.md +++ b/README.md @@ -190,6 +190,54 @@ Default options used by paginator when not specified: - `Order`: `paginator.DESC` +- `TupleCmp`: `paginator.DISABLED` + +When cursor uses more than one key/rule, paginator instances by default generate SQL that is compatible with almost all database management systems. But this query can be very inefficient and can result in a lot of database scans even when proper indices are in place. By enabling the `TupleCmp` option, paginator will emit a slightly different SQL query when all cursor keys are ordered in the same way. + +For example, let us assume we have the following code: + +```go +paginator.New( + paginator.WithKeys([]string{"CreatedAt", "ID"}), + paginate.WithAfter(after), + paginate.WithLimit(3), +).Paginate(db, &result) +``` + +The query that hits our database in this case would look something like this: + +```sql + SELECT * + FROM orders + WHERE orders.created_at > $1 + OR orders.created_at = $2 AND orders.id > $3 +ORDER BY orders.created_at ASC, orders.id ASC + LIMIT 4 +``` + +Even if we index our table on `(created_at, id)` columns, some database engines will still perform at least full index scan to get to the items we need. And this is the primary use case for tuple comparison optimization. If we enable optimization, our code would look something like this: + +```go +paginator.New( + paginator.WithKeys([]string{"CreatedAt", "ID"}), + paginate.WithAfter(after), + paginate.WithLimit(3), + paginate.WithTupleCmp(paginate.ENABLED), +).Paginate(db, &result) +``` + +The query that hits our database now looks something like this: + +```sql + SELECT * + FROM orders + WHERE (orders.created_at, orders.id) > ($1, $2) +ORDER BY orders.created_at ASC, orders.id ASC + LIMIT 4 +``` + +In this case, if we have index on `(created_at, id)` columns, most DB angines will know how to optimize this query into a simple initial index lookup + scan, making cursor overhead neglible. + ### paginator.Rule - `Key`: Field name in target model struct. diff --git a/docker-compose.yml b/docker-compose.yml index 13fd6fb..38f59f4 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -3,9 +3,12 @@ version: "3" services: postgres: image: postgres:11-alpine + command: + - -c + - log_statement=all ports: - 8765:5432 environment: POSTGRES_DB: test POSTGRES_USER: test - POSTGRES_PASSWORD: test \ No newline at end of file + POSTGRES_PASSWORD: test diff --git a/paginator/option.go b/paginator/option.go index 2bd021b..dafe2d7 100644 --- a/paginator/option.go +++ b/paginator/option.go @@ -1,9 +1,17 @@ package paginator +type Flag string + +const ( + ENABLED Flag = "ENABLED" + DISABLED Flag = "DISABLED" +) + var defaultConfig = Config{ - Keys: []string{"ID"}, - Limit: 10, - Order: DESC, + Keys: []string{"ID"}, + Limit: 10, + Order: DESC, + TupleCmp: DISABLED, } // Option for paginator @@ -13,12 +21,13 @@ type Option interface { // Config for paginator type Config struct { - Rules []Rule - Keys []string - Limit int - Order Order - After string - Before string + Rules []Rule + Keys []string + Limit int + Order Order + After string + Before string + TupleCmp Flag } // Apply applies config to paginator @@ -42,6 +51,9 @@ func (c *Config) Apply(p *Paginator) { if c.Before != "" { p.SetBeforeCursor(c.Before) } + if c.TupleCmp != "" { + p.SetAllowTupleCmp(c.TupleCmp == ENABLED) + } } // WithRules configures rules for paginator @@ -85,3 +97,10 @@ func WithBefore(c string) Option { Before: c, } } + +// WithAllowTupleCmp enables tuple comparison optimization +func WithTupleCmp(flag Flag) Option { + return &Config{ + TupleCmp: flag, + } +} diff --git a/paginator/paginator.go b/paginator/paginator.go index fc97f3e..2eef3c0 100644 --- a/paginator/paginator.go +++ b/paginator/paginator.go @@ -22,10 +22,11 @@ func New(opts ...Option) *Paginator { // Paginator a builder doing pagination type Paginator struct { - cursor Cursor - rules []Rule - limit int - order Order + cursor Cursor + rules []Rule + limit int + order Order + allowTupleCmp bool } // SetRules sets paging rules @@ -65,6 +66,11 @@ func (p *Paginator) SetBeforeCursor(beforeCursor string) { p.cursor.Before = &beforeCursor } +// SetAllowTupleCmp enables or disables tuple comparison optimization +func (p *Paginator) SetAllowTupleCmp(allow bool) { + p.allowTupleCmp = allow +} + // Paginate paginates data func (p *Paginator) Paginate(db *gorm.DB, dest interface{}) (result *gorm.DB, c Cursor, err error) { if err = p.validate(db, dest); err != nil { @@ -221,13 +227,19 @@ func (p *Paginator) appendPagingQuery(db *gorm.DB, fields []interface{}) *gorm.D stmt := db stmt = stmt.Limit(p.limit + 1) stmt = stmt.Order(p.buildOrderSQL()) - if len(fields) > 0 { - stmt = stmt.Where( - p.buildCursorSQLQuery(), - p.buildCursorSQLQueryArgs(fields)..., - ) + + if len(fields) == 0 { + return stmt } - return stmt + + if p.allowTupleCmp && p.canOptimizePagingQuery() { + return stmt.Where(p.buildOptimizedCursorSQLQuery(), fields) + } + + return stmt.Where( + p.buildCursorSQLQuery(), + p.buildCursorSQLQueryArgs(fields)..., + ) } func (p *Paginator) buildOrderSQL() string { @@ -246,11 +258,7 @@ func (p *Paginator) buildCursorSQLQuery() string { queries := make([]string, len(p.rules)) query := "" for i, rule := range p.rules { - operator := "<" - if (p.isForward() && rule.Order == ASC) || - (p.isBackward() && rule.Order == DESC) { - operator = ">" - } + operator := p.getCmpOperator(rule.Order) queries[i] = fmt.Sprintf("%s%s %s ?", query, rule.SQLRepr, operator) query = fmt.Sprintf("%s%s = ? AND ", query, rule.SQLRepr) } @@ -259,6 +267,43 @@ func (p *Paginator) buildCursorSQLQuery() string { return strings.Join(queries, " OR ") } +// We can only optimize paging query if sorting orders are consistent across +// all columns used in cursor. This is a prerequisite for tuple comparison that +// optimized queries use. +func (p *Paginator) canOptimizePagingQuery() bool { + order := p.rules[0].Order + + for _, rule := range p.rules { + if order != rule.Order { + return false + } + } + + return true +} + +func (p *Paginator) getCmpOperator(order Order) string { + if (p.isForward() && order == ASC) || (p.isBackward() && order == DESC) { + return ">" + } + + return "<" +} + +func (p *Paginator) buildOptimizedCursorSQLQuery() string { + names := make([]string, len(p.rules)) + + for i, rule := range p.rules { + names[i] = rule.SQLRepr + } + + return fmt.Sprintf( + "(%s) %s ?", + strings.Join(names, ", "), + p.getCmpOperator(p.rules[0].Order), + ) +} + func (p *Paginator) buildCursorSQLQueryArgs(fields []interface{}) (args []interface{}) { for i := 1; i <= len(fields); i++ { args = append(args, fields[:i]...) diff --git a/paginator/paginator_paginate_test.go b/paginator/paginator_paginate_test.go index 377080d..79ad69e 100644 --- a/paginator/paginator_paginate_test.go +++ b/paginator/paginator_paginate_test.go @@ -15,6 +15,7 @@ func (s *paginatorSuite) TestPaginateDefaultOptions() { // * Key: ID // * Limit: 10 // * Order: DESC + // * TupleCmp: DISABLED var p1 []order _, c, _ := New().Paginate(s.db, &p1) @@ -215,6 +216,43 @@ func (s *paginatorSuite) TestPaginateMultipleKeys() { s.assertForwardOnly(c) } +func (s *paginatorSuite) TestPaginateMultipleKeysTupleCmp() { + now := time.Now() + // ordered by (CreatedAt desc, ID desc) -> 2, 3, 1 + s.givenOrders([]order{ + {ID: 1, CreatedAt: now}, + {ID: 2, CreatedAt: now.Add(1 * time.Hour)}, + {ID: 3, CreatedAt: now}, + }) + + cfg := Config{ + Keys: []string{"CreatedAt", "ID"}, + Limit: 2, + TupleCmp: ENABLED, + } + + var p1 []order + _, c, _ := New(&cfg).Paginate(s.db, &p1) + s.assertIDs(p1, 2, 3) + s.assertForwardOnly(c) + + var p2 []order + _, c, _ = New( + &cfg, + WithAfter(*c.After), + ).Paginate(s.db, &p2) + s.assertIDs(p2, 1) + s.assertBackwardOnly(c) + + var p3 []order + _, c, _ = New( + &cfg, + WithBefore(*c.Before), + ).Paginate(s.db, &p3) + s.assertIDs(p3, 2, 3) + s.assertForwardOnly(c) +} + func (s *paginatorSuite) TestPaginatePointerKey() { s.givenOrders([]order{ {ID: 1, Remark: ptrStr("3")},