TiDB 和 Golang 的简单 CRUD 应用程序

    注意

    推荐使用 Golang 1.16 以上版本进行 TiDB 的应用程序的编写。

    本节将介绍 TiDB 集群的启动方法。

    • TiDB Cloud
    • 本地集群
    • Gitpod

    你可以部署一个本地测试的 TiDB 集群或正式的 TiDB 集群。详细步骤,请参考:

    基于 Git 的预配置的开发环境:现在就试试

    该环境会自动克隆代码,并通过 TiUP 部署测试集群。

    • 使用 GORM(推荐)
    • 使用 go-sql-driver/mysql

    当前开源比较流行的 Golang ORM 为 GORM,此处将以 v1.23.5 版本进行说明。

    封装一个用于适配 TiDB 事务的工具包 util,编写以下代码备用:

    1. import (
    2. "gorm.io/gorm"
    3. )
    4. // TiDBGormBegin start a TiDB and Gorm transaction as a block. If no error is returned, the transaction will be committed. Otherwise, the transaction will be rolled back.
    5. func TiDBGormBegin(db *gorm.DB, pessimistic bool, fc func(tx *gorm.DB) error) (err error) {
    6. session := db.Session(&gorm.Session{})
    7. if session.Error != nil {
    8. return session.Error
    9. }
    10. if pessimistic {
    11. session = session.Exec("set @@tidb_txn_mode=pessimistic")
    12. } else {
    13. session = session.Exec("set @@tidb_txn_mode=optimistic")
    14. }
    15. if session.Error != nil {
    16. return session.Error
    17. }
    18. return session.Transaction(fc)
    19. }

    进入目录 gorm

    1. cd gorm

    目录结构如下所示:

    1. .
    2. ├── Makefile
    3. ├── go.mod
    4. ├── go.sum
    5. └── gorm.go

    其中,gorm.gogorm 这个示例程序的主体。使用 gorm 时,相较于 go-sql-driver/mysql,gorm 屏蔽了创建数据库连接时,不同数据库差异的细节,其还封装了大量的操作,如 AutoMigrate、基本对象的 CRUD 等,极大的简化了代码量。

    Player 是数据结构体,为数据库表在程序内的映射。Player 的每个属性都对应着 player 表的一个字段。相较于 go-sql-driver/mysql,gorm 的 Player 数据结构体为了给 gorm 提供更多的信息,加入了形如 `gorm:"primaryKey;type:VARCHAR(36);column:id"` 的注解,用来指示映射关系。

    1. package main
    2. import (
    3. "fmt"
    4. "math/rand"
    5. "github.com/google/uuid"
    6. "github.com/pingcap-inc/tidb-example-golang/util"
    7. "gorm.io/driver/mysql"
    8. "gorm.io/gorm"
    9. "gorm.io/gorm/clause"
    10. "gorm.io/gorm/logger"
    11. )
    12. type Player struct {
    13. ID string `gorm:"primaryKey;type:VARCHAR(36);column:id"`
    14. Coins int `gorm:"column:coins"`
    15. Goods int `gorm:"column:goods"`
    16. }
    17. func (*Player) TableName() string {
    18. return "player"
    19. }
    20. func main() {
    21. // 1. Configure the example database connection.
    22. db := createDB()
    23. // AutoMigrate for player table
    24. db.AutoMigrate(&Player{})
    25. // 2. Run some simple examples.
    26. simpleExample(db)
    27. // 3. Explore more.
    28. tradeExample(db)
    29. }
    30. func tradeExample(db *gorm.DB) {
    31. // Player 1: id is "1", has only 100 coins.
    32. // Player 2: id is "2", has 114514 coins, and 20 goods.
    33. player1 := &Player{ID: "1", Coins: 100}
    34. player2 := &Player{ID: "2", Coins: 114514, Goods: 20}
    35. // Create two players "by hand", using the INSERT statement on the backend.
    36. db.Clauses(clause.OnConflict{UpdateAll: true}).Create(player1)
    37. db.Clauses(clause.OnConflict{UpdateAll: true}).Create(player2)
    38. // Player 1 wants to buy 10 goods from player 2.
    39. // It will cost 500 coins, but player 1 cannot afford it.
    40. fmt.Println("\nbuyGoods:\n => this trade will fail")
    41. if err := buyGoods(db, player2.ID, player1.ID, 10, 500); err == nil {
    42. panic("there shouldn't be success")
    43. }
    44. // So player 1 has to reduce the incoming quantity to two.
    45. fmt.Println("\nbuyGoods:\n => this trade will success")
    46. if err := buyGoods(db, player2.ID, player1.ID, 2, 100); err != nil {
    47. panic(err)
    48. }
    49. }
    50. func simpleExample(db *gorm.DB) {
    51. // Create a player, who has a coin and a goods..
    52. if err := db.Clauses(clause.OnConflict{UpdateAll: true}).
    53. Create(&Player{ID: "test", Coins: 1, Goods: 1}).Error; err != nil {
    54. panic(err)
    55. }
    56. // Get a player.
    57. var testPlayer Player
    58. db.Find(&testPlayer, "id = ?", "test")
    59. fmt.Printf("getPlayer: %+v\n", testPlayer)
    60. // Create players with bulk inserts. Insert 1919 players totally, with 114 players per batch.
    61. bulkInsertPlayers := make([]Player, 1919, 1919)
    62. total, batch := 1919, 114
    63. for i := 0; i < total; i++ {
    64. bulkInsertPlayers[i] = Player{
    65. ID: uuid.New().String(),
    66. Coins: rand.Intn(10000),
    67. Goods: rand.Intn(10000),
    68. }
    69. }
    70. if err := db.Session(&gorm.Session{Logger: db.Logger.LogMode(logger.Error)}).
    71. CreateInBatches(bulkInsertPlayers, batch).Error; err != nil {
    72. panic(err)
    73. }
    74. // Count players amount.
    75. playersCount := int64(0)
    76. db.Model(&Player{}).Count(&playersCount)
    77. fmt.Printf("countPlayers: %d\n", playersCount)
    78. // Print 3 players.
    79. threePlayers := make([]Player, 3, 3)
    80. db.Limit(3).Find(&threePlayers)
    81. for index, player := range threePlayers {
    82. fmt.Printf("print %d player: %+v\n", index+1, player)
    83. }
    84. }
    85. func createDB() *gorm.DB {
    86. dsn := "root:@tcp(127.0.0.1:4000)/test?charset=utf8mb4"
    87. db, err := gorm.Open(mysql.Open(dsn), &gorm.Config{
    88. Logger: logger.Default.LogMode(logger.Info),
    89. })
    90. if err != nil {
    91. panic(err)
    92. }
    93. return db
    94. }
    95. func buyGoods(db *gorm.DB, sellID, buyID string, amount, price int) error {
    96. return util.TiDBGormBegin(db, true, func(tx *gorm.DB) error {
    97. var sellPlayer, buyPlayer Player
    98. if err := tx.Clauses(clause.Locking{Strength: "UPDATE"}).
    99. Find(&sellPlayer, "id = ?", sellID).Error; err != nil {
    100. return err
    101. }
    102. if sellPlayer.ID != sellID || sellPlayer.Goods < amount {
    103. return fmt.Errorf("sell player %s goods not enough", sellID)
    104. }
    105. if err := tx.Clauses(clause.Locking{Strength: "UPDATE"}).
    106. Find(&buyPlayer, "id = ?", buyID).Error; err != nil {
    107. return err
    108. }
    109. if buyPlayer.ID != buyID || buyPlayer.Coins < price {
    110. return fmt.Errorf("buy player %s coins not enough", buyID)
    111. }
    112. updateSQL := "UPDATE player set goods = goods + ?, coins = coins + ? WHERE id = ?"
    113. if err := tx.Exec(updateSQL, -amount, price, sellID).Error; err != nil {
    114. return err
    115. }
    116. if err := tx.Exec(updateSQL, amount, -price, buyID).Error; err != nil {
    117. return err
    118. }
    119. fmt.Println("\n[buyGoods]:\n 'trade success'")
    120. return nil
    121. })
    122. }
    1. cd sqldriver

    目录结构如下所示:

    其中,dbinit.sql 为数据表初始化语句:

    1. USE test;
    2. DROP TABLE IF EXISTS player;
    3. CREATE TABLE player (
    4. `id` VARCHAR(36),
    5. `coins` INTEGER,
    6. `goods` INTEGER,
    7. PRIMARY KEY (`id`)
    8. );

    sqldriver.gosqldriver 这个示例程序的主体。因为 TiDB 与 MySQL 协议兼容,因此,需要初始化一个 MySQL 协议的数据源 db, err := sql.Open("mysql", dsn),以此连接到 TiDB。并在其后,调用 dao.go 中的一系列方法,用来管理数据对象,进行增删改查等操作。

    1. import (
    2. "database/sql"
    3. _ "github.com/go-sql-driver/mysql"
    4. )
    5. func main() {
    6. // 1. Configure the example database connection.
    7. dsn := "root:@tcp(127.0.0.1:4000)/test?charset=utf8mb4"
    8. openDB("mysql", dsn, func(db *sql.DB) {
    9. // 2. Run some simple examples.
    10. simpleExample(db)
    11. // 3. Explore more.
    12. tradeExample(db)
    13. })
    14. }
    15. func simpleExample(db *sql.DB) {
    16. // Create a player, who has a coin and a goods.
    17. err := createPlayer(db, Player{ID: "test", Coins: 1, Goods: 1})
    18. if err != nil {
    19. panic(err)
    20. }
    21. // Get a player.
    22. testPlayer, err := getPlayer(db, "test")
    23. if err != nil {
    24. panic(err)
    25. }
    26. fmt.Printf("getPlayer: %+v\n", testPlayer)
    27. // Create players with bulk inserts. Insert 1919 players totally, with 114 players per batch.
    28. err = bulkInsertPlayers(db, randomPlayers(1919), 114)
    29. if err != nil {
    30. panic(err)
    31. }
    32. // Count players amount.
    33. playersCount, err := getCount(db)
    34. if err != nil {
    35. panic(err)
    36. }
    37. fmt.Printf("countPlayers: %d\n", playersCount)
    38. // Print 3 players.
    39. threePlayers, err := getPlayerByLimit(db, 3)
    40. if err != nil {
    41. panic(err)
    42. }
    43. for index, player := range threePlayers {
    44. fmt.Printf("print %d player: %+v\n", index+1, player)
    45. }
    46. }
    47. func tradeExample(db *sql.DB) {
    48. // Player 1: id is "1", has only 100 coins.
    49. // Player 2: id is "2", has 114514 coins, and 20 goods.
    50. player1 := Player{ID: "1", Coins: 100}
    51. player2 := Player{ID: "2", Coins: 114514, Goods: 20}
    52. // Create two players "by hand", using the INSERT statement on the backend.
    53. if err := createPlayer(db, player1); err != nil {
    54. panic(err)
    55. }
    56. if err := createPlayer(db, player2); err != nil {
    57. panic(err)
    58. }
    59. // Player 1 wants to buy 10 goods from player 2.
    60. // It will cost 500 coins, but player 1 cannot afford it.
    61. fmt.Println("\nbuyGoods:\n => this trade will fail")
    62. if err := buyGoods(db, player2.ID, player1.ID, 10, 500); err == nil {
    63. panic("there shouldn't be success")
    64. }
    65. // So player 1 has to reduce the incoming quantity to two.
    66. fmt.Println("\nbuyGoods:\n => this trade will success")
    67. if err := buyGoods(db, player2.ID, player1.ID, 2, 100); err != nil {
    68. panic(err)
    69. }
    70. }
    71. func openDB(driverName, dataSourceName string, runnable func(db *sql.DB)) {
    72. db, err := sql.Open(driverName, dataSourceName)
    73. if err != nil {
    74. panic(err)
    75. }
    76. defer db.Close()
    77. runnable(db)
    78. }

    随后,封装一个用于适配 TiDB 事务的工具包 ,编写以下代码备用:

    1. package util
    2. import (
    3. "context"
    4. "database/sql"
    5. )
    6. type TiDBSqlTx struct {
    7. *sql.Tx
    8. conn *sql.Conn
    9. pessimistic bool
    10. }
    11. func TiDBSqlBegin(db *sql.DB, pessimistic bool) (*TiDBSqlTx, error) {
    12. ctx := context.Background()
    13. conn, err := db.Conn(ctx)
    14. if err != nil {
    15. return nil, err
    16. }
    17. if pessimistic {
    18. _, err = conn.ExecContext(ctx, "set @@tidb_txn_mode=?", "pessimistic")
    19. } else {
    20. _, err = conn.ExecContext(ctx, "set @@tidb_txn_mode=?", "optimistic")
    21. }
    22. if err != nil {
    23. return nil, err
    24. }
    25. tx, err := conn.BeginTx(ctx, nil)
    26. if err != nil {
    27. return nil, err
    28. }
    29. return &TiDBSqlTx{
    30. conn: conn,
    31. Tx: tx,
    32. pessimistic: pessimistic,
    33. }, nil
    34. }
    35. func (tx *TiDBSqlTx) Commit() error {
    36. defer tx.conn.Close()
    37. return tx.Tx.Commit()
    38. }
    39. func (tx *TiDBSqlTx) Rollback() error {
    40. defer tx.conn.Close()
    41. return tx.Tx.Rollback()
    42. }

    dao.go 中定义一系列数据的操作方法,用来对提供数据的写入能力。这也是本例子中和核心部分。

    1. package main
    2. import (
    3. "database/sql"
    4. "fmt"
    5. "math/rand"
    6. "strings"
    7. "github.com/google/uuid"
    8. "github.com/pingcap-inc/tidb-example-golang/util"
    9. )
    10. type Player struct {
    11. ID string
    12. Coins int
    13. Goods int
    14. }
    15. // createPlayer create a player
    16. func createPlayer(db *sql.DB, player Player) error {
    17. _, err := db.Exec(CreatePlayerSQL, player.ID, player.Coins, player.Goods)
    18. return err
    19. }
    20. // getPlayer get a player
    21. func getPlayer(db *sql.DB, id string) (Player, error) {
    22. var player Player
    23. rows, err := db.Query(GetPlayerSQL, id)
    24. if err != nil {
    25. return player, err
    26. }
    27. defer rows.Close()
    28. if rows.Next() {
    29. err = rows.Scan(&player.ID, &player.Coins, &player.Goods)
    30. if err == nil {
    31. return player, nil
    32. } else {
    33. return player, err
    34. }
    35. }
    36. return player, fmt.Errorf("can not found player")
    37. }
    38. // getPlayerByLimit get players by limit
    39. func getPlayerByLimit(db *sql.DB, limit int) ([]Player, error) {
    40. var players []Player
    41. rows, err := db.Query(GetPlayerByLimitSQL, limit)
    42. if err != nil {
    43. return players, err
    44. }
    45. defer rows.Close()
    46. for rows.Next() {
    47. player := Player{}
    48. err = rows.Scan(&player.ID, &player.Coins, &player.Goods)
    49. if err == nil {
    50. players = append(players, player)
    51. } else {
    52. return players, err
    53. }
    54. return players, nil
    55. }
    56. func bulkInsertPlayers(db *sql.DB, players []Player, batchSize int) error {
    57. tx, err := util.TiDBSqlBegin(db, true)
    58. if err != nil {
    59. return err
    60. }
    61. stmt, err := tx.Prepare(buildBulkInsertSQL(batchSize))
    62. if err != nil {
    63. return err
    64. }
    65. defer stmt.Close()
    66. for len(players) > batchSize {
    67. if _, err := stmt.Exec(playerToArgs(players[:batchSize])...); err != nil {
    68. tx.Rollback()
    69. return err
    70. }
    71. players = players[batchSize:]
    72. }
    73. if len(players) != 0 {
    74. if _, err := tx.Exec(buildBulkInsertSQL(len(players)), playerToArgs(players)...); err != nil {
    75. tx.Rollback()
    76. return err
    77. }
    78. }
    79. if err := tx.Commit(); err != nil {
    80. tx.Rollback()
    81. return err
    82. }
    83. return nil
    84. }
    85. func getCount(db *sql.DB) (int, error) {
    86. count := 0
    87. rows, err := db.Query(GetCountSQL)
    88. if err != nil {
    89. return count, err
    90. }
    91. defer rows.Close()
    92. if rows.Next() {
    93. if err := rows.Scan(&count); err != nil {
    94. return count, err
    95. }
    96. }
    97. return count, nil
    98. }
    99. func buyGoods(db *sql.DB, sellID, buyID string, amount, price int) error {
    100. var sellPlayer, buyPlayer Player
    101. tx, err := util.TiDBSqlBegin(db, true)
    102. if err != nil {
    103. return err
    104. }
    105. buyExec := func() error {
    106. stmt, err := tx.Prepare(GetPlayerWithLockSQL)
    107. if err != nil {
    108. return err
    109. }
    110. defer stmt.Close()
    111. sellRows, err := stmt.Query(sellID)
    112. if err != nil {
    113. return err
    114. }
    115. defer sellRows.Close()
    116. if sellRows.Next() {
    117. if err := sellRows.Scan(&sellPlayer.ID, &sellPlayer.Coins, &sellPlayer.Goods); err != nil {
    118. return err
    119. }
    120. }
    121. sellRows.Close()
    122. if sellPlayer.ID != sellID || sellPlayer.Goods < amount {
    123. return fmt.Errorf("sell player %s goods not enough", sellID)
    124. }
    125. buyRows, err := stmt.Query(buyID)
    126. if err != nil {
    127. return err
    128. }
    129. defer buyRows.Close()
    130. if buyRows.Next() {
    131. if err := buyRows.Scan(&buyPlayer.ID, &buyPlayer.Coins, &buyPlayer.Goods); err != nil {
    132. return err
    133. }
    134. }
    135. buyRows.Close()
    136. if buyPlayer.ID != buyID || buyPlayer.Coins < price {
    137. return fmt.Errorf("buy player %s coins not enough", buyID)
    138. }
    139. updateStmt, err := tx.Prepare(UpdatePlayerSQL)
    140. if err != nil {
    141. return err
    142. }
    143. defer updateStmt.Close()
    144. if _, err := updateStmt.Exec(-amount, price, sellID); err != nil {
    145. return err
    146. }
    147. if _, err := updateStmt.Exec(amount, -price, buyID); err != nil {
    148. return err
    149. }
    150. return nil
    151. }
    152. err = buyExec()
    153. if err == nil {
    154. fmt.Println("\n[buyGoods]:\n 'trade success'")
    155. tx.Commit()
    156. } else {
    157. tx.Rollback()
    158. }
    159. return err
    160. }
    161. func playerToArgs(players []Player) []interface{} {
    162. var args []interface{}
    163. for _, player := range players {
    164. args = append(args, player.ID, player.Coins, player.Goods)
    165. }
    166. return args
    167. }
    168. func buildBulkInsertSQL(amount int) string {
    169. return CreatePlayerSQL + strings.Repeat(",(?,?,?)", amount-1)
    170. }
    171. func randomPlayers(amount int) []Player {
    172. players := make([]Player, amount, amount)
    173. for i := 0; i < amount; i++ {
    174. players[i] = Player{
    175. ID: uuid.New().String(),
    176. Coins: rand.Intn(10000),
    177. Goods: rand.Intn(10000),
    178. }
    179. }
    180. return players
    181. }

    sql.go 中存放了 SQL 语句的常量。

    1. package main
    2. const (
    3. CreatePlayerSQL = "INSERT INTO player (id, coins, goods) VALUES (?, ?, ?)"
    4. GetPlayerSQL = "SELECT id, coins, goods FROM player WHERE id = ?"
    5. GetCountSQL = "SELECT count(*) FROM player"
    6. GetPlayerWithLockSQL = GetPlayerSQL + " FOR UPDATE"
    7. UpdatePlayerSQL = "UPDATE player set goods = goods + ?, coins = coins + ? WHERE id = ?"
    8. GetPlayerByLimitSQL = "SELECT id, coins, goods FROM player LIMIT ?"
    9. )

    本节将逐步介绍代码的运行方法。

    • 使用 GORM(推荐)
    • 使用 go-sql-driver/mysql

    Golang - 图2

    注意

    在 Gitpod Playground 中尝试 GORM: 现在就试试

    无需手动初始化表。

    注意

    在 Gitpod Playground 中尝试 go-sql-driver/mysql:

    或直接执行:

    1. mysql --host 127.0.0.1 --port 4000 -u root<sql/dbinit.sql

    若你不使用本地集群,或未安装 mysql-client,请直接登录你的集群,并运行 sql/dbinit.sql 文件内的 SQL 语句。

    • 使用 GORM(推荐)
    • 使用 go-sql-driver/mysql

    若你使用 TiDB Cloud Serverless Tier 集群,更改 gorm.godsn 参数值:

    1. dsn := "root:@tcp(127.0.0.1:4000)/test?charset=utf8mb4"

    若你设定的密码为 123456,而且从 TiDB Cloud Serverless Tier 集群面板中得到的连接信息为:

    • Endpoint: xxx.tidbcloud.com
    • Port: 4000
    • User: 2aEp24QWEDLqRFs.root

    那么此处应将 mysql.RegisterTLSConfigdsn 更改为:

    1. mysql.RegisterTLSConfig("register-tidb-tls", &tls.Config {
    2. MinVersion: tls.VersionTLS12,
    3. ServerName: "xxx.tidbcloud.com",
    4. })
    5. dsn := "2aEp24QWEDLqRFs.root:123456@tcp(xxx.tidbcloud.com:4000)/test?charset=utf8mb4&tls=register-tidb-tls"

    若你使用 TiDB Cloud Serverless Tier 集群,更改 sqldriver.godsn 参数的值:

    1. dsn := "root:@tcp(127.0.0.1:4000)/test?charset=utf8mb4"

    若你设定的密码为 123456,而且从 TiDB Cloud Serverless Tier 集群面板中得到的连接信息为:

    • Endpoint: xxx.tidbcloud.com
    • Port: 4000
    • User: 2aEp24QWEDLqRFs.root

    那么此处应将 mysql.RegisterTLSConfigdsn 更改为:

    1. mysql.RegisterTLSConfig("register-tidb-tls", &tls.Config {
    2. MinVersion: tls.VersionTLS12,
    3. ServerName: "xxx.tidbcloud.com",
    4. })
    5. dsn := "2aEp24QWEDLqRFs.root:123456@tcp(xxx.tidbcloud.com:4000)/test?charset=utf8mb4&tls=register-tidb-tls"
    • 使用 GORM(推荐)
    • 使用 go-sql-driver/mysql

    运行 make all,这是以下两个操作的组合:

    • 构建二进制 (make build):go build -o bin/gorm-example
    • 运行 (make run):./bin/gorm-example

    你也可以单独运行这两个 make 命令或原生命令。

    运行 make all,这是以下三个操作的组合:

    • 创建表 (make mysql):mysql --host 127.0.0.1 --port 4000 -u root<sql/dbinit.sql
    • 构建二进制 (make build): go build -o bin/sql-driver-example
    • 运行 (make run):

    你也可以单独运行这三个 make 命令或原生命令。

    • 使用 go-sql-driver/mysql

    go-sql-driver/mysql 预期输出