diff --git a/driver/json_test.go b/driver/json_test.go index e760403..f5b5c18 100644 --- a/driver/json_test.go +++ b/driver/json_test.go @@ -21,8 +21,8 @@ func Example_json() { CREATE TABLE orders ( cart_id INTEGER PRIMARY KEY, user_id INTEGER NOT NULL, - cart TEXT - ); + cart BLOB -- stored as JSONB + ) STRICT; `) if err != nil { log.Fatal(err) @@ -39,7 +39,8 @@ func Example_json() { Items []CartItem `json:"items"` } - _, err = db.Exec(`INSERT INTO orders (user_id, cart) VALUES (?, ?)`, 123, sqlite3.JSON(Cart{ + // convert to JSONB on insertion + _, err = db.Exec(`INSERT INTO orders (user_id, cart) VALUES (?, jsonb(?))`, 123, sqlite3.JSON(Cart{ []CartItem{ {ItemID: "111", Name: "T-shirt", Quantity: 1, Price: 250}, {ItemID: "222", Name: "Trousers", Quantity: 1, Price: 600}, @@ -60,6 +61,24 @@ func Example_json() { } fmt.Println("total:", total) + + var cart Cart + err = db.QueryRow(` + SELECT json(cart) -- convert to JSON on retrieval + FROM orders + WHERE cart_id = last_insert_rowid() + `).Scan(sqlite3.JSON(&cart)) + if err != nil { + log.Fatal(err) + } + + for _, item := range cart.Items { + fmt.Printf("id: %s, name: %s, quantity: %d, price: %d\n", + item.ItemID, item.Name, item.Quantity, item.Price) + } + // Output: // total: 850 + // id: 111, name: T-shirt, quantity: 1, price: 250 + // id: 222, name: Trousers, quantity: 1, price: 600 } diff --git a/json_test.go b/json_test.go new file mode 100644 index 0000000..8ff089c --- /dev/null +++ b/json_test.go @@ -0,0 +1,112 @@ +package sqlite3_test + +import ( + "fmt" + "log" + + "github.com/ncruces/go-sqlite3" + _ "github.com/ncruces/go-sqlite3/embed" + _ "github.com/ncruces/go-sqlite3/vfs/memdb" +) + +func Example_json() { + db, err := sqlite3.Open("file:/test.db?vfs=memdb") + if err != nil { + log.Fatal(err) + } + defer db.Close() + + err = db.Exec(` + CREATE TABLE orders ( + cart_id INTEGER PRIMARY KEY, + user_id INTEGER NOT NULL, + cart BLOB -- stored as JSONB + ) STRICT; + `) + if err != nil { + log.Fatal(err) + } + + type CartItem struct { + ItemID string `json:"id"` + Name string `json:"name"` + Quantity int `json:"quantity,omitempty"` + Price int `json:"price,omitempty"` + } + + type Cart struct { + Items []CartItem `json:"items"` + } + + // convert to JSONB on insertion + stmt, _, err := db.Prepare(`INSERT INTO orders (user_id, cart) VALUES (?, jsonb(?))`) + if err != nil { + log.Fatal(err) + } + defer stmt.Close() + + if err := stmt.BindInt(1, 123); err != nil { + log.Fatal(err) + } + + if err := stmt.BindJSON(2, Cart{ + []CartItem{ + {ItemID: "111", Name: "T-shirt", Quantity: 1, Price: 250}, + {ItemID: "222", Name: "Trousers", Quantity: 1, Price: 600}, + }, + }); err != nil { + log.Fatal(err) + } + + if err := stmt.Exec(); err != nil { + log.Fatal(err) + } + + sl1, _, err := db.Prepare(` + SELECT total(json_each.value -> 'price') + FROM orders, json_each(cart -> 'items') + WHERE cart_id = last_insert_rowid() + `) + if err != nil { + log.Fatal(err) + } + defer sl1.Close() + + for sl1.Step() { + fmt.Println("total:", sl1.ColumnInt(0)) + } + + if err := sl1.Err(); err != nil { + log.Fatal(err) + } + + sl2, _, err := db.Prepare(` + SELECT json(cart) -- convert to JSON on retrieval + FROM orders + WHERE cart_id = last_insert_rowid() + `) + if err != nil { + log.Fatal(err) + } + defer sl2.Close() + + for sl2.Step() { + var cart Cart + if err := sl2.ColumnJSON(0, &cart); err != nil { + log.Fatal(err) + } + for _, item := range cart.Items { + fmt.Printf("id: %s, name: %s, quantity: %d, price: %d\n", + item.ItemID, item.Name, item.Quantity, item.Price) + } + } + + if err := sl2.Err(); err != nil { + log.Fatal(err) + } + + // Output: + // total: 850 + // id: 111, name: T-shirt, quantity: 1, price: 250 + // id: 222, name: Trousers, quantity: 1, price: 600 +}