Group Commit

Group commit load does not introduce a new data import method, but an extension of INSERT INTO tbl VALUS(...), Stream Load and Http Stream. It is a way to improve the write performance of Doris with high-concurrency and small-data writes. Your application can directly use JDBC to do high-concurrency insert operation into Doris, at the same time, combining PreparedStatement can get even higher performance. In logging scenarios, you can also do high-concurrency Stream Load or Http Stream into Doris.

Group Commit Mode

Group Commit provides 3 modes:

  • off_mode

Disable group commit, keep the original behavior for INSERT INTO VALUES, Stream Load and Http Stream.

  • sync_mode

Doris groups multiple loads into one transaction commit based on the group_commit_interval table property. The load is returned after the transaction commit. This mode is suitable for high-concurrency writing scenarios and requires immediate data visibility after the load is finished.

  • async_mode

Doris writes data to the Write Ahead Log (WAL) firstly, then the load is returned. Doris groups multiple loads into one transaction commit based on the group_commit_interval table property, and the data is visible after the commit. To prevent excessive disk space usage by the WAL, it automatically switches to sync_mode. This is suitable for latency-sensitive and high-frequency writing.

Basic operations

If the table schema is:

  1. CREATE TABLE `dt` (
  2. `id` int(11) NOT NULL,
  3. `name` varchar(50) NULL,
  4. `score` int(11) NULL
  5. ) ENGINE=OLAP
  6. DUPLICATE KEY(`id`)
  7. DISTRIBUTED BY HASH(`id`) BUCKETS 1
  8. PROPERTIES (
  9. "replication_num" = "1"
  10. );

Use JDBC

To reduce the CPU cost of SQL parsing and query planning, we provide the PreparedStatement in the FE. When using PreparedStatement, the SQL and its plan will be cached in the session level memory cache and will be reused later on, which reduces the CPU cost of FE. The following is an example of using PreparedStatement in JDBC:

  1. Setup JDBC url and enable server side prepared statement
  1. url = jdbc:mysql://127.0.0.1:9030/db?useServerPrepStmts=true
  1. Set group_commit session variable, there are two ways to do it:
  • Add sessionVariables=group_commit=async_mode in JDBC url
  1. url = jdbc:mysql://127.0.0.1:9030/db?useServerPrepStmts=true&sessionVariables=group_commit=async_mode
  • Use SET group_commit = async_mode; command
  1. try (Statement statement = conn.createStatement()) {
  2. statement.execute("SET group_commit = async_mode;");
  3. }
  1. Using PreparedStatement
  1. private static final String JDBC_DRIVER = "com.mysql.jdbc.Driver";
  2. private static final String URL_PATTERN = "jdbc:mysql://%s:%d/%s?useServerPrepStmts=true";
  3. private static final String HOST = "127.0.0.1";
  4. private static final int PORT = 9087;
  5. private static final String DB = "db";
  6. private static final String TBL = "dt";
  7. private static final String USER = "root";
  8. private static final String PASSWD = "";
  9. private static final int INSERT_BATCH_SIZE = 10;
  10. private static void groupCommitInsert() throws Exception {
  11. Class.forName(JDBC_DRIVER);
  12. try (Connection conn = DriverManager.getConnection(String.format(URL_PATTERN, HOST, PORT, DB), USER, PASSWD)) {
  13. // set session variable 'group_commit'
  14. try (Statement statement = conn.createStatement()) {
  15. statement.execute("SET group_commit = async_mode;");
  16. }
  17. String query = "insert into " + TBL + " values(?, ?, ?)";
  18. try (PreparedStatement stmt = conn.prepareStatement(query)) {
  19. for (int i = 0; i < INSERT_BATCH_SIZE; i++) {
  20. stmt.setInt(1, i);
  21. stmt.setString(2, "name" + i);
  22. stmt.setInt(3, i + 10);
  23. int result = stmt.executeUpdate();
  24. System.out.println("rows: " + result);
  25. }
  26. }
  27. } catch (Exception e) {
  28. e.printStackTrace();
  29. }
  30. }
  31. private static void groupCommitInsertBatch() throws Exception {
  32. Class.forName(JDBC_DRIVER);
  33. // add rewriteBatchedStatements=true and cachePrepStmts=true in JDBC url
  34. // set session variables by sessionVariables=group_commit=async_mode in JDBC url
  35. try (Connection conn = DriverManager.getConnection(
  36. String.format(URL_PATTERN + "&rewriteBatchedStatements=true&cachePrepStmts=true&sessionVariables=group_commit=async_mode", HOST, PORT, DB), USER, PASSWD)) {
  37. String query = "insert into " + TBL + " values(?, ?, ?)";
  38. try (PreparedStatement stmt = conn.prepareStatement(query)) {
  39. for (int j = 0; j < 5; j++) {
  40. // 10 rows per insert
  41. for (int i = 0; i < INSERT_BATCH_SIZE; i++) {
  42. stmt.setInt(1, i);
  43. stmt.setString(2, "name" + i);
  44. stmt.setInt(3, i + 10);
  45. stmt.addBatch();
  46. }
  47. int[] result = stmt.executeBatch();
  48. }
  49. }
  50. } catch (Exception e) {
  51. e.printStackTrace();
  52. }
  53. }

See Synchronize Data Using Insert Method for more details about JDBC.

INSERT INTO VALUES

  • async_mode
  1. # Config session variable to enable the async group commit, the default value is off_mode
  2. mysql> set group_commit = async_mode;
  3. # The retured label is start with 'group_commit', which is the label of the real load job
  4. mysql> insert into dt values(1, 'Bob', 90), (2, 'Alice', 99);
  5. Query OK, 2 rows affected (0.05 sec)
  6. {'label':'group_commit_a145ce07f1c972fc-bd2c54597052a9ad', 'status':'PREPARE', 'txnId':'181508'}
  7. # The returned label and txn_id are the same as the above, which means they are handled in on load job
  8. mysql> insert into dt(id, name) values(3, 'John');
  9. Query OK, 1 row affected (0.01 sec)
  10. {'label':'group_commit_a145ce07f1c972fc-bd2c54597052a9ad', 'status':'PREPARE', 'txnId':'181508'}
  11. # The data is not visible
  12. mysql> select * from dt;
  13. Empty set (0.01 sec)
  14. # After about 10 seconds, the data is visible
  15. mysql> select * from dt;
  16. +------+-------+-------+
  17. | id | name | score |
  18. +------+-------+-------+
  19. | 1 | Bob | 90 |
  20. | 2 | Alice | 99 |
  21. | 3 | John | NULL |
  22. +------+-------+-------+
  23. 3 rows in set (0.02 sec)
  • sync_mode
  1. # Config session variable to enable the sync group commit
  2. mysql> set group_commit = sync_mode;
  3. # The retured label is start with 'group_commit', which is the label of the real load job.
  4. # The insert costs at least the group_commit_interval_ms of table property.
  5. mysql> insert into dt values(4, 'Bob', 90), (5, 'Alice', 99);
  6. Query OK, 2 rows affected (10.06 sec)
  7. {'label':'group_commit_d84ab96c09b60587_ec455a33cb0e9e87', 'status':'PREPARE', 'txnId':'3007', 'query_id':'fc6b94085d704a94-a69bfc9a202e66e2'}
  8. # The data is visible after the insert is returned
  9. mysql> select * from dt;
  10. +------+-------+-------+
  11. | id | name | score |
  12. +------+-------+-------+
  13. | 1 | Bob | 90 |
  14. | 2 | Alice | 99 |
  15. | 3 | John | NULL |
  16. | 4 | Bob | 90 |
  17. | 5 | Alice | 99 |
  18. +------+-------+-------+
  19. 5 rows in set (0.03 sec)
  • off_mode
  1. mysql> set group_commit = off_mode;

Stream Load

If the content of data.csv is:

  1. 6,Amy,60
  2. 7,Ross,98
  • async_mode
  1. # Add 'group_commit:async_mode' configuration in the http header
  2. curl --location-trusted -u {user}:{passwd} -T data.csv -H "group_commit:async_mode" -H "column_separator:," http://{fe_host}:{http_port}/api/db/dt/_stream_load
  3. {
  4. "TxnId": 7009,
  5. "Label": "group_commit_c84d2099208436ab_96e33fda01eddba8",
  6. "Comment": "",
  7. "GroupCommit": true,
  8. "Status": "Success",
  9. "Message": "OK",
  10. "NumberTotalRows": 2,
  11. "NumberLoadedRows": 2,
  12. "NumberFilteredRows": 0,
  13. "NumberUnselectedRows": 0,
  14. "LoadBytes": 19,
  15. "LoadTimeMs": 35,
  16. "StreamLoadPutTimeMs": 5,
  17. "ReadDataTimeMs": 0,
  18. "WriteDataTimeMs": 26
  19. }
  20. # The returned 'GroupCommit' is 'true', which means this is a group commit load
  21. # The retured label is start with 'group_commit', which is the label of the real load job
  • sync_mode
  1. # Add 'group_commit:sync_mode' configuration in the http header
  2. curl --location-trusted -u {user}:{passwd} -T data.csv -H "group_commit:sync_mode" -H "column_separator:," http://{fe_host}:{http_port}/api/db/dt/_stream_load
  3. {
  4. "TxnId": 3009,
  5. "Label": "group_commit_d941bf17f6efcc80_ccf4afdde9881293",
  6. "Comment": "",
  7. "GroupCommit": true,
  8. "Status": "Success",
  9. "Message": "OK",
  10. "NumberTotalRows": 2,
  11. "NumberLoadedRows": 2,
  12. "NumberFilteredRows": 0,
  13. "NumberUnselectedRows": 0,
  14. "LoadBytes": 19,
  15. "LoadTimeMs": 10044,
  16. "StreamLoadPutTimeMs": 4,
  17. "ReadDataTimeMs": 0,
  18. "WriteDataTimeMs": 10038
  19. }
  20. # The returned 'GroupCommit' is 'true', which means this is a group commit load
  21. # The retured label is start with 'group_commit', which is the label of the real load job

See Stream Load for more detailed syntax used by Stream Load.

Http Stream

  • async_mode
  1. # Add 'group_commit:async_mode' configuration in the http header
  2. curl --location-trusted -u {user}:{passwd} -T data.csv -H "group_commit:async_mode" -H "sql:insert into db.dt select * from http_stream('column_separator'=',', 'format' = 'CSV')" http://{fe_host}:{http_port}/api/_http_stream
  3. {
  4. "TxnId": 7011,
  5. "Label": "group_commit_3b45c5750d5f15e5_703428e462e1ebb0",
  6. "Comment": "",
  7. "GroupCommit": true,
  8. "Status": "Success",
  9. "Message": "OK",
  10. "NumberTotalRows": 2,
  11. "NumberLoadedRows": 2,
  12. "NumberFilteredRows": 0,
  13. "NumberUnselectedRows": 0,
  14. "LoadBytes": 19,
  15. "LoadTimeMs": 65,
  16. "StreamLoadPutTimeMs": 41,
  17. "ReadDataTimeMs": 47,
  18. "WriteDataTimeMs": 23
  19. }
  20. # The returned 'GroupCommit' is 'true', which means this is a group commit load
  21. # The retured label is start with 'group_commit', which is the label of the real load job
  • sync_mode
  1. # Add 'group_commit:sync_mode' configuration in the http header
  2. curl --location-trusted -u {user}:{passwd} -T data.csv -H "group_commit:sync_mode" -H "sql:insert into db.dt select * from http_stream('column_separator'=',', 'format' = 'CSV')" http://{fe_host}:{http_port}/api/_http_stream
  3. {
  4. "TxnId": 3011,
  5. "Label": "group_commit_fe470e6752aadbe6_a8f3ac328b02ea91",
  6. "Comment": "",
  7. "GroupCommit": true,
  8. "Status": "Success",
  9. "Message": "OK",
  10. "NumberTotalRows": 2,
  11. "NumberLoadedRows": 2,
  12. "NumberFilteredRows": 0,
  13. "NumberUnselectedRows": 0,
  14. "LoadBytes": 19,
  15. "LoadTimeMs": 10066,
  16. "StreamLoadPutTimeMs": 31,
  17. "ReadDataTimeMs": 32,
  18. "WriteDataTimeMs": 10034
  19. }
  20. # The returned 'GroupCommit' is 'true', which means this is a group commit load
  21. # The retured label is start with 'group_commit', which is the label of the real load job

See Stream Load for more detailed syntax used by Http Stream.

Group commit condition

The data will be automatically committed either when the time interval (default is 10 seconds) or the data size (default is 64 MB) conditions meet.

Modify the time interval condition

The default group commit interval is 10 seconds. Users can modify the configuration of the table:

  1. # Modify the group commit interval to 2 seconds
  2. ALTER TABLE dt SET ("group_commit_interval_ms" = "2000");

Modify the data size condition

The default group commit data size is 64 MB. Users can modify the configuration of the table:

  1. # Modify the group commit data size to 128MB
  2. ALTER TABLE dt SET ("group_commit_data_bytes" = "134217728");

Limitations

  • When the group commit is enabled, some INSERT INTO VALUES sqls are not executed in the group commit way if they meet the following conditions:

    • Transaction insert, such as BEGIN, INSERT INTO VALUES, COMMIT

    • Specify the label, such as INSERT INTO dt WITH LABEL {label} VALUES

    • Expressions within VALUES, such as INSERT INTO dt VALUES (1 + 100)

    • Column update

    • Tables that do not support light schema changes

  • When the group commit is enabled, some Stream Load and Http Stream are not executed in the group commit way if they meet the following conditions:

    • Two phase commit

    • Specify the label by set header -H "label:my_label"

    • Column update

    • Tables that do not support light schema changes

  • For unique table, because the group commit can not guarantee the commit order, users can use sequence column to ensure the data consistency.

  • The limit of max_filter_ratio

    • For non group commit load, filter_ratio is calculated by the failed rows and total rows when load is finished. If the filter_ratio does not match, the transaction will not commit

    • In the group commit mode, multiple user loads are executed by one internal load. The internal load will commit all user loads.

    • Currently, group commit supports a certain degree of max_filter_ratio semantics. When the total number of rows does not exceed group_commit_memory_rows_for_max_filter_ratio (configured in be.conf, defaulting to 10000 rows), max_filter_ratio will work.

  • The limit of WAL

    • For async_mode group commit, data is written to the Write Ahead Log (WAL). If the internal load succeeds, the WAL is immediately deleted. If the internal load fails, data is recovery by importing the WAL.

    • Currently, WAL files are stored only on one disk of one BE. If the BE’s disk is damaged or the file is mistakenly deleted, it may result in data loss.

    • When decommissioning a BE node, please use the DECOMMISSION command to safely decommission the node. This prevents potential data loss if the WAL files are not processed before the node is taken offline.

    • For async_mode group commit writes, to protect disk space, it switches to sync_mode under the following conditions:

      • For an import with large amount of data: exceeding 80% of the disk space of a WAL directory.

      • Chunked stream loads with an unknown data amount.

      • Insufficient disk space, even with it is an import with small amount of data.

    • During hard weight schema changes (adding or dropping columns, modifying varchar length, and renaming columns are lightweight schema changes, others are hard weight), to ensure WAL file is compatibility with the table’s schema, the final stage of metadata modification in FE will reject group commit writes. Clients get insert table ${table_name} is blocked on schema change exception and can retry the import.

Relevant system configuration

BE configuration

group_commit_wal_path

  • The WAL directory of group commit.
  • Default: A directory named wal is created under each directory of the storage_root_path. Configuration examples:

    1. group_commit_wal_path=/data1/storage/wal;/data2/storage/wal;/data3/storage/wal

group_commit_memory_rows_for_max_filter_ratio

  • Description: The max_filter_ratio limit can only work if the total rows of group commit is less than this value.
  • Default: 10000

Performance

We have separately tested the write performance of group commit in high-concurrency scenarios with small data volumes using Stream Load and JDBC (in async mode).

Stream Load

Environment

  • 1 FE: 8-core CPU, 16 GB RAM, 1 200 GB SSD disk
  • 3 BE: 16-core CPU, 64 GB RAM, 1 2 TB SSD disk
  • 1 Client: 8-core CPU, 64 GB RAM, 1 100 GB SSD disk

DataSet

  • httplogs, 31 GB, 247249096 (247 million) rows

Test Tool

Test Method

  • Setting different single-concurrency data size and concurrency num between non group_commit and group_commit modes.

Test Result

Load WaySingle-concurrency Data SizeConcurrencyCost SecondsRows / SecondsMB / Seconds
group_commit10 KB10370766,6978.56
group_commit10 KB30338573,0429.38
group_commit100 KB10473522,72567.11
group_commit100 KB30390633,97281.39
group_commit500 KB10323765,47798.28
group_commit500 KB30309800,158102.56
group_commit1 MB10304813,319104.24
group_commit1 MB30286864,507110.88
group_commit10 MB10290852,583109.28
non group_commit1 MB10-235 error
non group_commit10 MB10519476,39561.12
non group_commit10 MB30-235 error

In the above test, the CPU usage of BE fluctuates between 10-40%.

The group_commit effectively enhances import performance while reducing the number of versions, thereby alleviating the pressure on compaction.

JDBC

Environment

  • 1 FE: 8-core CPU, 16 GB RAM, 1 200 GB SSD disk
  • 1 BE: 16-core CPU, 64 GB RAM, 1 2 TB SSD disk
  • 1 Client: 16-core CPU, 64 GB RAM, 1 100 GB SSD disk

DataSet

  • The data of tpch sf10 lineitem table, 20 files, 14 GB, 120 million rows

Test Method

Test Method

  • Use txtfilereader wtite data to mysqlwriter, config different concurrenncy and rows for per INSERT sql.

Test Result

Rows per insertConcurrencyRows / SecondMB / Second
1002010693111.46

In the above test, the CPU usage of BE fluctuates between 10-20%, FE fluctuates between 60-70%.