Bookshop Example Application

Bookshop is a virtual online bookstore application through which you can buy books of various categories and rate the books you have read.

To make your reading on the application developer guide more smoothly, we present the example SQL statements based on the table structures and data of the Bookshop application. This document focuses on the methods of importing the table structures and data as well as the definitions of the table structures.

Import table structures and data

For TiDB Cloud, you can skip Method 1: Via tiup demo and import Bookshop table structures via the import feature of TiDB Cloud.

Method 1: Via tiup demo

If your TiDB cluster is deployed using TiUP or you can connect to your TiDB server, you can quickly generate and import sample data for the Bookshop application by running the following command:

tiup demo bookshop prepare

By default, this command enables your application to connect to port 4000 on address 127.0.0.1, enables you to log in as the root user without a password, and creates a table structure in the database named bookshop.

Configure connection information

The following table lists the connection parameters. You can change their default settings to match your environment.

ParameterAbbreviationDefault valueDescription
--password-pNoneDatabase user password
--host-H127.0.0.1Database address
--port-P4000Database port
--db-DbookshopDatabase name
--user-UrootDatabase user

For example, if you want to connect to a database on TiDB Cloud, you can specify the connection information as follows:

tiup demo bookshop prepare -U <username> -H <endpoint> -P 4000 -p <password>

Set the data volume

You can specify the volume of data to be generated in each database table by configuring the following parameters:

ParameterDefault valueDescription
--users10000The number of rows of data to be generated in the users table
--authors20000The number of rows to be generated in the authors table
--books20000The number of rows of data to be generated in the books table
--orders300000The number of rows of data to be generated in the orders table
--ratings300000The number of rows of data to be generated in the ratings table

For example, the following command is executed to generate:

  • 200,000 rows of user information via the --users parameter
  • 500,000 rows of book information via the --books parameter
  • 100,000 rows of author information via the --authors parameter
  • 1,000,000 rows of rating records via the --ratings parameter
  • 1,000,000 rows of order records via the --orders parameter
tiup demo bookshop prepare --users=200000 --books=500000 --authors=100000 --ratings=1000000 --orders=1000000 --drop-tables

You can delete the original table structure through the --drop-tables parameter. For more parameter descriptions, run the tiup demo bookshop --help command.

Method 2: Via TiDB Cloud Import

  1. Open the Import page for your target cluster.

    1. Log in to the TiDB Cloud console and navigate to the Clusters page of your project.

    2. Click the name of your target cluster to go to its overview page, and then click Import in the left navigation pane.

  2. Select Import data from S3.

    If this is your first time using TiDB Cloud Import, select Import From Amazon S3.

  3. On the Import Data from Amazon S3 page, configure the following source data information:

    • Import File Count: select Multiple files.
    • Included Schema Files: select Yes.
    • Data Format: select SQL.
    • Folder URI: enter s3://developer.pingcap.com/bookshop/.
    • Bucket Access: select AWS Role ARN.
    • Role ARN: enter arn:aws:iam::494090988690:role/s3-tidb-cloud-developer-access.

    In this example, the following data is generated in advance:

    • 200,000 rows of user information
    • 500,000 rows of book information
    • 100,000 rows of author information
    • 1,000,000 rows of rating records
    • 1,000,000 rows of order records
  4. Click Connect > Start Import to start the import process and wait for TiDB Cloud to complete the import.

For more information about how to import or migrate data to TiDB Cloud, see TiDB Cloud Migration Overview.

View data import status

After the import is completed, you can view the data volume information of each table by executing the following SQL statement:

SELECT CONCAT(table_schema,'.',table_name) AS 'Table Name', table_rows AS 'Number of Rows', CONCAT(ROUND(data_length/(1024*1024*1024),4),'G') AS 'Data Size', CONCAT(ROUND(index_length/(1024*1024*1024),4),'G') AS 'Index Size', CONCAT(ROUND((data_length+index_length)/(1024*1024*1024),4),'G') AS 'Total' FROM information_schema.TABLES WHERE table_schema LIKE 'bookshop';

The result is as follows:

+-----------------------+----------------+-----------+------------+---------+ | Table Name | Number of Rows | Data Size | Index Size | Total | +-----------------------+----------------+-----------+------------+---------+ | bookshop.orders | 1000000 | 0.0373G | 0.0075G | 0.0447G | | bookshop.book_authors | 1000000 | 0.0149G | 0.0149G | 0.0298G | | bookshop.ratings | 4000000 | 0.1192G | 0.1192G | 0.2384G | | bookshop.authors | 100000 | 0.0043G | 0.0000G | 0.0043G | | bookshop.users | 195348 | 0.0048G | 0.0021G | 0.0069G | | bookshop.books | 1000000 | 0.0546G | 0.0000G | 0.0546G | +-----------------------+----------------+-----------+------------+---------+ 6 rows in set (0.03 sec)

Description of the tables

This section describes the database tables of the Bookshop application in detail.

books table

This table stores the basic information of books.

Field nameTypeDescription
idbigint(20)Unique ID of a book
titlevarchar(100)Title of a book
typeenumType of a book (for example, magazine, animation, or teaching aids)
stockbigint(20)Stock
pricedecimal(15,2)Price
published_atdatetimeDate of publish

authors table

This table stores basic information of authors.

Field nameTypeDescription
idbigint(20)Unique ID of an author
namevarchar(100)Name of an author
gendertinyint(1)Biological gender (0: female, 1: male, NULL: unknown)
birth_yearsmallint(6)Year of birth
death_yearsmallint(6)Year of death

users table

This table stores information of Bookshop users.

Field nameTypeDescription
idbigint(20)Unique ID of a user
balancedecimal(15,2)Balance
nicknamevarchar(100)Nickname

ratings table

This table stores records of user ratings on books.

Field nameTypeDescription
book_idbigintUnique ID of a book (linked to books)
user_idbigintUser's unique identifier (linked to users)
scoretinyintUser rating (1-5)
rated_atdatetimeRating time

book_authors table

An author may write multiple books, and a book may involve more than one author. This table stores the correspondence between books and authors.

Field nameTypeDescription
book_idbigint(20)Unique ID of a book (linked to books)
author_idbigint(20)Unique ID of an author(Link to authors

orders table

This table stores user purchase information.

Field nameTypeDescription
idbigint(20)Unique ID of an order
book_idbigint(20)Unique ID of a book (linked to books)
user_idbigint(20)User unique identifier (associated with users)
quantitytinyint(4)Purchase quantity
ordered_atdatetimePurchase time

Database initialization script dbinit.sql

If you want to manually create database table structures in the Bookshop application, run the following SQL statements:

CREATE DATABASE IF NOT EXISTS `bookshop`; DROP TABLE IF EXISTS `bookshop`.`books`; CREATE TABLE `bookshop`.`books` ( `id` bigint(20) AUTO_RANDOM NOT NULL, `title` varchar(100) NOT NULL, `type` enum('Magazine', 'Novel', 'Life', 'Arts', 'Comics', 'Education & Reference', 'Humanities & Social Sciences', 'Science & Technology', 'Kids', 'Sports') NOT NULL, `published_at` datetime NOT NULL, `stock` int(11) DEFAULT '0', `price` decimal(15,2) DEFAULT '0.0', PRIMARY KEY (`id`) CLUSTERED ) DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; DROP TABLE IF EXISTS `bookshop`.`authors`; CREATE TABLE `bookshop`.`authors` ( `id` bigint(20) AUTO_RANDOM NOT NULL, `name` varchar(100) NOT NULL, `gender` tinyint(1) DEFAULT NULL, `birth_year` smallint(6) DEFAULT NULL, `death_year` smallint(6) DEFAULT NULL, PRIMARY KEY (`id`) CLUSTERED ) DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; DROP TABLE IF EXISTS `bookshop`.`book_authors`; CREATE TABLE `bookshop`.`book_authors` ( `book_id` bigint(20) NOT NULL, `author_id` bigint(20) NOT NULL, PRIMARY KEY (`book_id`,`author_id`) CLUSTERED ) DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; DROP TABLE IF EXISTS `bookshop`.`ratings`; CREATE TABLE `bookshop`.`ratings` ( `book_id` bigint NOT NULL, `user_id` bigint NOT NULL, `score` tinyint NOT NULL, `rated_at` datetime NOT NULL DEFAULT NOW() ON UPDATE NOW(), PRIMARY KEY (`book_id`,`user_id`) CLUSTERED, UNIQUE KEY `uniq_book_user_idx` (`book_id`,`user_id`) ) DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; ALTER TABLE `bookshop`.`ratings` SET TIFLASH REPLICA 1; DROP TABLE IF EXISTS `bookshop`.`users`; CREATE TABLE `bookshop`.`users` ( `id` bigint AUTO_RANDOM NOT NULL, `balance` decimal(15,2) DEFAULT '0.0', `nickname` varchar(100) UNIQUE NOT NULL, PRIMARY KEY (`id`) ) DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin; DROP TABLE IF EXISTS `bookshop`.`orders`; CREATE TABLE `bookshop`.`orders` ( `id` bigint(20) AUTO_RANDOM NOT NULL, `book_id` bigint(20) NOT NULL, `user_id` bigint(20) NOT NULL, `quality` tinyint(4) NOT NULL, `ordered_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, PRIMARY KEY (`id`) CLUSTERED, KEY `orders_book_id_idx` (`book_id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin

Need help?

Ask questions on TiDB Community.

Was this page helpful?