Background information
OceanBase Database currently supports three mainstream data import methods: Load Data, obloader, and OMS. All of these methods write data using INSERT statements. However, the INSERT operation involves several processes, such as SQL parsing, transaction processing, and LSM-tree-based storage. Due to OceanBase Database’s LSM-tree-based storage structure, data inserted via INSERT is first written to an in-memory table (MemTable), and then, after multiple rounds of flushing and major compaction, is ultimately stored in the SSTable. This process consumes a large amount of CPU resources, resulting in slow data import speeds.
To address this issue, OceanBase Database introduces direct load technology, which bypasses intermediate processing steps and writes data directly to the underlying major SSTable. This technology not only applies to data import but can also accelerate SQL operations involving extensive writes, such as INSERT INTO SELECT.
ClickBench is an AP benchmark proposed by ClickHouse. This benchmark can be used to test the query performance of OceanBase Database in AP scenarios. Before running this benchmark, data must first be imported, allowing you to experience OceanBase Database’s data import performance. Of course, you can also use direct load technology to prepare data for other AP benchmarks, such as TPCH and TPCDS. This tutorial will guide you through using direct load technology to accelerate large-scale data import and experience the high efficiency of OceanBase Database.
Scenarios
- Data preparation for AP scenarios: For example, ClickHouse Benchmark, TPC-H, and TPC-DS.
- Acceleration of bulk writes: For example, replacing high-throughput write operations such as
INSERT INTO SELECT.
The bypass import technology can significantly improve the data import efficiency, making it suitable for scenarios requiring the rapid loading of large amounts of data.
Technical architecture
Data import can be performed through two paths.
Conventional path: The orange arrows in the figure indicate the conventional path, which involves a series of modules including SQL query, transaction processing, and data storage.
Bypass import path: The green arrows in the figure indicate the bypass import path, which primarily involves type conversion, sorting by primary key (if applicable), and writing the sorted data to the Major SSTable. The bypass import path is shorter and can reduce system resource consumption and accelerate data import.
Prerequisites
Environment preparation
Environment requirements: You have deployed an OceanBase cluster of V4.3 or later and created a tenant in MySQL mode. For more information about how to deploy an OceanBase cluster, see Deployment overview. After the deployment, you can execute the following SQL statements in the sys tenant to view the cluster and tenant information:
-- View cluster information
SELECT * FROM GV$OB_SERVERS;
-- View tenant information
SELECT * FROM oceanbase.DBA_OB_TENANTS;
Privilege requirements: The tenant you created must have the INSERT and SELECT privileges. For more information about the privileges in OceanBase Database in MySQL mode, see Privilege types in MySQL-compatible mode.
Data preparation
Download the test data
Download the hits dataset from ClickHouse.
Decompress the data to a specified path (for example,
/path/to/hits.tsv).
Procedure
Step 1: Create a columnstore table
Execute the following statement to create a columnstore table:
CREATE TABLE hits ( WatchID BIGINT NOT NULL, JavaEnable SMALLINT NOT NULL, Title TEXT NOT NULL, GoodEvent SMALLINT NOT NULL, EventTime TIMESTAMP NOT NULL, EventDate Date NOT NULL, CounterID INTEGER NOT NULL, ClientIP INTEGER NOT NULL, RegionID INTEGER NOT NULL, UserID BIGINT NOT NULL, CounterClass SMALLINT NOT NULL, OS SMALLINT NOT NULL, UserAgent SMALLINT NOT NULL, URL TEXT NOT NULL, Referer TEXT NOT NULL, IsRefresh SMALLINT NOT NULL, RefererCategoryID SMALLINT NOT NULL, RefererRegionID INTEGER NOT NULL, URLCategoryID SMALLINT NOT NULL, URLRegionID INTEGER NOT NULL, ResolutionWidth SMALLINT NOT NULL, ResolutionHeight SMALLINT NOT NULL, ResolutionDepth SMALLINT NOT NULL, FlashMajor SMALLINT NOT NULL, FlashMinor SMALLINT NOT NULL, FlashMinor2 TEXT NOT NULL, NetMajor SMALLINT NOT NULL, NetMinor SMALLINT NOT NULL, UserAgentMajor SMALLINT NOT NULL, UserAgentMinor VARCHAR(255) NOT NULL, CookieEnable SMALLINT NOT NULL, JavascriptEnable SMALLINT NOT NULL, IsMobile SMALLINT NOT NULL, MobilePhone SMALLINT NOT NULL, MobilePhoneModel TEXT NOT NULL, Params TEXT NOT NULL, IPNetworkID INTEGER NOT NULL, TraficSourceID SMALLINT NOT NULL, SearchEngineID SMALLINT NOT NULL, SearchPhrase TEXT NOT NULL, AdvEngineID SMALLINT NOT NULL, IsArtifical SMALLINT NOT NULL, WindowClientWidth SMALLINT NOT NULL, WindowClientHeight SMALLINT NOT NULL, ClientTimeZone SMALLINT NOT NULL, ClientEventTime TIMESTAMP NOT NULL, SilverlightVersion1 SMALLINT NOT NULL, SilverlightVersion2 SMALLINT NOT NULL, SilverlightVersion3 INTEGER NOT NULL, SilverlightVersion4 SMALLINT NOT NULL, PageCharset TEXT NOT NULL, CodeVersion INTEGER NOT NULL, IsLink SMALLINT NOT NULL, IsDownload SMALLINT NOT NULL, IsNotBounce SMALLINT NOT NULL, FUniqID BIGINT NOT NULL, OriginalURL TEXT NOT NULL, HID INTEGER NOT NULL, IsOldCounter SMALLINT NOT NULL, IsEvent SMALLINT NOT NULL, IsParameter SMALLINT NOT NULL, DontCountHits SMALLINT NOT NULL, WithHash SMALLINT NOT NULL, HitColor CHAR NOT NULL, LocalEventTime TIMESTAMP NOT NULL, Age SMALLINT NOT NULL, Sex SMALLINT NOT NULL, Income SMALLINT NOT NULL, Interests SMALLINT NOT NULL, Robotness SMALLINT NOT NULL, RemoteIP INTEGER NOT NULL, WindowName INTEGER NOT NULL, OpenerName INTEGER NOT NULL, HistoryLength SMALLINT NOT NULL, BrowserLanguage TEXT NOT NULL, BrowserCountry TEXT NOT NULL, SocialNetwork TEXT NOT NULL, SocialAction TEXT NOT NULL, HTTPError SMALLINT NOT NULL, SendTiming INTEGER NOT NULL, DNSTiming INTEGER NOT NULL, ConnectTiming INTEGER NOT NULL, ResponseStartTiming INTEGER NOT NULL, ResponseEndTiming INTEGER NOT NULL, FetchTiming INTEGER NOT NULL, SocialSourceNetworkID SMALLINT NOT NULL, SocialSourcePage TEXT NOT NULL, ParamPrice BIGINT NOT NULL, ParamOrderID TEXT NOT NULL, ParamCurrency TEXT NOT NULL, ParamCurrencyID SMALLINT NOT NULL, OpenstatServiceName TEXT NOT NULL, OpenstatCampaignID TEXT NOT NULL, OpenstatAdID TEXT NOT NULL, OpenstatSourceID TEXT NOT NULL, UTMSource TEXT NOT NULL, UTMMedium TEXT NOT NULL, UTMCampaign TEXT NOT NULL, UTMContent TEXT NOT NULL, UTMTerm TEXT NOT NULL, FromTag TEXT NOT NULL, HasGCLID SMALLINT NOT NULL, RefererHash BIGINT NOT NULL, URLHash BIGINT NOT NULL, CLID INTEGER NOT NULL, PRIMARY KEY (CounterID, EventDate, UserID, EventTime, WatchID) ) with column group (each column);
Step 2: Perform direct load
Direct load
LOAD DATA
/*+
query_timeout(10000000000)
parallel(32)
direct(true, 0) -- Enable direct load mode.
*/
INFILE '/path/to/hits.tsv'
INTO TABLE hits
FIELDS TERMINATED BY '\t'
ENCLOSED BY ''
ESCAPED BY '';
After the preceding statement is executed, the execution time for direct load is displayed.
Non-direct load for comparison
LOAD DATA
/*+
query_timeout(10000000000)
parallel(32)
*/
INFILE '/path/to/hits.tsv'
INTO TABLE hits
FIELDS TERMINATED BY '\t'
ENCLOSED BY ''
ESCAPED BY '';
After the preceding statement is executed, the execution time for non-direct load is displayed.
Performance comparison
| Scenario | Execution time (s) |
|---|---|
| Direct load | 249 |
| Non-direct load | 767 |
Note: The execution times may vary due to different execution environments. The execution times in the preceding table are provided for your reference only.
Conclusion: Direct load improves the import efficiency by more than 3 times. It is suitable for large-scale data import scenarios such as test data preparation for TPC-H and TPC-DS benchmarks.