Yandex Cloud
Search
Contact UsGet started
  • Blog
  • Pricing
  • Documentation
  • All Services
  • System Status
    • Featured
    • Infrastructure & Network
    • Data Platform
    • Containers
    • Developer tools
    • Serverless
    • Security
    • Monitoring & Resources
    • ML & AI
    • Business tools
  • All Solutions
    • By industry
    • By use case
    • Economics and Pricing
    • Security
    • Technical Support
    • Customer Stories
    • Gateway to Russia
    • Cloud for Startups
    • Education and Science
  • Blog
  • Pricing
  • Documentation
Yandex project
© 2025 Yandex.Cloud LLC
Yandex Managed Service for ClickHouse®
  • Getting started
    • All tutorials
    • Adding data to the database
    • Migrating data to Managed Service for ClickHouse® using ClickHouse®
    • Migrating data to Managed Service for ClickHouse® using Data Transfer
    • Sharding tables
    • Data resharding in a cluster
    • Using a hybrid storage
    • Fetching data from Managed Service for Apache Kafka®
    • Fetching data from RabbitMQ
    • Exchanging data with Yandex Data Processing
    • Configuring Yandex Cloud DNS for cluster access from other cloud networks
    • Analyzing Yandex Object Storage logs in Yandex DataLens
    • Configuring Managed Service for ClickHouse® for Graphite
    • Saving a Yandex Data Streams data stream in Managed Service for ClickHouse®
    • Migrating a database from Google BigQuery
    • Delivering data from Managed Service for Apache Kafka® using Yandex Data Transfer
    • Migrating data from Yandex Direct using Yandex Cloud Functions, Yandex Object Storage, and Yandex Data Transfer
    • Loading data from Yandex Object Storage to Managed Service for ClickHouse® using Yandex Data Transfer
    • Migrating a database from Greenplum® to ClickHouse®
    • Migrating a database from MySQL® to ClickHouse® using Yandex Data Transfer
    • Asynchronously replicating data from PostgreSQL to ClickHouse®
    • Loading data from Yandex Managed Service for YDB to Managed Service for ClickHouse® using Yandex Data Transfer
    • Copying data from Managed Service for OpenSearch to Managed Service for ClickHouse® using Yandex Data Transfer
    • Entering data into storage systems
    • Using parameters
    • Examples of creating QL charts
    • Web analytics with funnels and cohorts calculated based on Yandex Metrica data
    • AppMetrica: direct connection
    • AppMetrica: data export, post-processing, and visualization
    • Loading data from Yandex Metrica to a ClickHouse® data mart
    • Yandex Tracker: data export and visualization
    • Retail chain's dashboard based on a ClickHouse® DB
    • Analyzing sales and locations of pizzerias based on data from the ClickHouse® database and Marketplace
    • Geocoding with the Yandex Maps API for data visualization in DataLens
    • Importing data from Object Storage, processing and exporting to Managed Service for ClickHouse®
    • Working with data using Query
    • Federated data queries using Query
  • Access management
  • Pricing policy
  • Terraform reference
  • Yandex Monitoring metrics
  • Audit Trails events
  • Public materials
  • Release notes

In this article:

  • Required paid resources
  • Getting started
  • Set up your infrastructure
  • Set up the command line tools
  • Optionally, explore the test dataset
  • Create a table
  • Populate the table with data
  • Check data placement in a cluster
  • Run a test query
  • Optionally, monitor the amount of space data in Object Storage takes up
  • Delete the resources you created
  1. Tutorials
  2. Using a hybrid storage

Using hybrid storage in Managed Service for ClickHouse®

Written by
Yandex Cloud
Updated at May 7, 2025
  • Required paid resources
  • Getting started
    • Set up your infrastructure
    • Set up the command line tools
    • Optionally, explore the test dataset
  • Create a table
  • Populate the table with data
  • Check data placement in a cluster
  • Run a test query
  • Optionally, monitor the amount of space data in Object Storage takes up
  • Delete the resources you created

Hybrid storage allows you to store frequently used data on the network disks of the Managed Service for ClickHouse® cluster and rarely used data in Yandex Object Storage. Automatically moving data between these storage tiers is only supported for MergeTree tables. For more information, see Disk types in Managed Service for ClickHouse®.

To use hybrid storage:

  1. Create a table.
  2. Populate the table with data.
  3. Check data placement in a cluster.
  4. Run a test query.

If you no longer need the resources you created, delete them.

Required paid resourcesRequired paid resources

The support cost includes:

  • Managed Service for ClickHouse® cluster fee: Using computing resources allocated to hosts (including ZooKeeper hosts) and disk space (see Managed Service for ClickHouse® pricing).
  • Fee for using public IP addresses if public access is enabled for cluster hosts (see Virtual Private Cloud pricing).

Getting startedGetting started

Set up your infrastructureSet up your infrastructure

Manually
Using Terraform
  1. Create a Managed Service for ClickHouse® cluster:

    • Disk type: Standard (network-hdd), fast (network-ssd), or non-replicated (network-ssd-nonreplicated) network disks.

    • Size: At least 15 GB.

    • User management via SQL: Disabled.

    • DB name: tutorial.

    • Hybrid storage: Enabled.

  2. Configure permissions so that you can execute read and write requests in this database.

  1. If you do not have Terraform yet, install it.

  2. Get the authentication credentials. You can add them to environment variables or specify them later in the provider configuration file.

  3. Configure and initialize a provider. There is no need to create a provider configuration file manually, you can download it.

  4. Place the configuration file in a separate working directory and specify the parameter values. If you did not add the authentication credentials to environment variables, specify them in the configuration file.

  5. Download the clickhouse-hybrid-storage.tf configuration file to the same working directory.

    This file describes:

    • Network.
    • Subnet.
    • Default security group and rules required to connect to the cluster from the internet.
    • Managed Service for ClickHouse® cluster with hybrid storage enabled.
  6. In the clickhouse-hybrid-storage.tf file, specify the username and password to access the Managed Service for ClickHouse® cluster.

  7. Make sure the Terraform configuration files are correct using this command:

    terraform validate
    

    If there are any errors in the configuration files, Terraform will point them out.

  8. Create the required infrastructure:

    1. Run this command to view the planned changes:

      terraform plan
      

      If you described the configuration correctly, the terminal will display a list of the resources to update and their parameters. This is a verification step that does not apply changes to your resources.

    2. If everything looks correct, apply the changes:

      1. Run this command:

        terraform apply
        
      2. Confirm updating the resources.

      3. Wait for the operation to complete.

    All the required resources will be created in the specified folder. You can check resource availability and their settings in the management console.

Set up the command line toolsSet up the command line tools

  1. Install the curl and unxz tools:

    apt-get update && apt-get install curl xz-utils
    
  2. Set up clickhouse-client and use it to connect to the database.

Optionally, explore the test datasetOptionally, explore the test dataset

To demonstrate how hybrid storage works, we are going to use the Yandex Metrica anonymized hit data (hits_v1). This dataset contains information about almost 9 million hits over the week from March 17, 2014, to March 23, 2014.

When creating the tutorial.hits_v1 table, you are going to configure it so that all more recent table data, starting from March 21, 2014, is in network storage, and older data, from March 17, 2014, to March 20, 2014, is in object storage.

Create a tableCreate a table

Create the tutorial.hits_v1 table that uses hybrid storage. To do this, run an SQL query by substituting <schema> with a table schema from the ClickHouse® documentation:

CREATE TABLE tutorial.hits_v1
(
   <schema>
)
ENGINE = MergeTree()
PARTITION BY EventDate
ORDER BY (CounterID, EventDate, intHash32(UserID))
SAMPLE BY intHash32(UserID)
TTL EventDate + toIntervalDay(dateDiff('day', toDate('2014-03-20'), now())) TO DISK 'object_storage'
SETTINGS index_granularity = 8192
Query with full schema
CREATE TABLE tutorial.hits_v1
(
    `WatchID` UInt64,
    `JavaEnable` UInt8,
    `Title` String,
    `GoodEvent` Int16,
    `EventTime` DateTime,
    `EventDate` Date,
    `CounterID` UInt32,
    `ClientIP` UInt32,
    `ClientIP6` FixedString(16),
    `RegionID` UInt32,
    `UserID` UInt64,
    `CounterClass` Int8,
    `OS` UInt8,
    `UserAgent` UInt8,
    `URL` String,
    `Referer` String,
    `URLDomain` String,
    `RefererDomain` String,
    `Refresh` UInt8,
    `IsRobot` UInt8,
    `RefererCategories` Array(UInt16),
    `URLCategories` Array(UInt16),
    `URLRegions` Array(UInt32),
    `RefererRegions` Array(UInt32),
    `ResolutionWidth` UInt16,
    `ResolutionHeight` UInt16,
    `ResolutionDepth` UInt8,
    `FlashMajor` UInt8,
    `FlashMinor` UInt8,
    `FlashMinor2` String,
    `NetMajor` UInt8,
    `NetMinor` UInt8,
    `UserAgentMajor` UInt16,
    `UserAgentMinor` FixedString(2),
    `CookieEnable` UInt8,
    `JavascriptEnable` UInt8,
    `IsMobile` UInt8,
    `MobilePhone` UInt8,
    `MobilePhoneModel` String,
    `Params` String,
    `IPNetworkID` UInt32,
    `TraficSourceID` Int8,
    `SearchEngineID` UInt16,
    `SearchPhrase` String,
    `AdvEngineID` UInt8,
    `IsArtifical` UInt8,
    `WindowClientWidth` UInt16,
    `WindowClientHeight` UInt16,
    `ClientTimeZone` Int16,
    `ClientEventTime` DateTime,
    `SilverlightVersion1` UInt8,
    `SilverlightVersion2` UInt8,
    `SilverlightVersion3` UInt32,
    `SilverlightVersion4` UInt16,
    `PageCharset` String,
    `CodeVersion` UInt32,
    `IsLink` UInt8,
    `IsDownload` UInt8,
    `IsNotBounce` UInt8,
    `FUniqID` UInt64,
    `HID` UInt32,
    `IsOldCounter` UInt8,
    `IsEvent` UInt8,
    `IsParameter` UInt8,
    `DontCountHits` UInt8,
    `WithHash` UInt8,
    `HitColor` FixedString(1),
    `UTCEventTime` DateTime,
    `Age` UInt8,
    `Sex` UInt8,
    `Income` UInt8,
    `Interests` UInt16,
    `Robotness` UInt8,
    `GeneralInterests` Array(UInt16),
    `RemoteIP` UInt32,
    `RemoteIP6` FixedString(16),
    `WindowName` Int32,
    `OpenerName` Int32,
    `HistoryLength` Int16,
    `BrowserLanguage` FixedString(2),
    `BrowserCountry` FixedString(2),
    `SocialNetwork` String,
    `SocialAction` String,
    `HTTPError` UInt16,
    `SendTiming` Int32,
    `DNSTiming` Int32,
    `ConnectTiming` Int32,
    `ResponseStartTiming` Int32,
    `ResponseEndTiming` Int32,
    `FetchTiming` Int32,
    `RedirectTiming` Int32,
    `DOMInteractiveTiming` Int32,
    `DOMContentLoadedTiming` Int32,
    `DOMCompleteTiming` Int32,
    `LoadEventStartTiming` Int32,
    `LoadEventEndTiming` Int32,
    `NSToDOMContentLoadedTiming` Int32,
    `FirstPaintTiming` Int32,
    `RedirectCount` Int8,
    `SocialSourceNetworkID` UInt8,
    `SocialSourcePage` String,
    `ParamPrice` Int64,
    `ParamOrderID` String,
    `ParamCurrency` FixedString(3),
    `ParamCurrencyID` UInt16,
    `GoalsReached` Array(UInt32),
    `OpenstatServiceName` String,
    `OpenstatCampaignID` String,
    `OpenstatAdID` String,
    `OpenstatSourceID` String,
    `UTMSource` String,
    `UTMMedium` String,
    `UTMCampaign` String,
    `UTMContent` String,
    `UTMTerm` String,
    `FromTag` String,
    `HasGCLID` UInt8,
    `RefererHash` UInt64,
    `URLHash` UInt64,
    `CLID` UInt32,
    `YCLID` UInt64,
    `ShareService` String,
    `ShareURL` String,
    `ShareTitle` String,
    `ParsedParams` Nested(
        Key1 String,
        Key2 String,
        Key3 String,
        Key4 String,
        Key5 String,
        ValueDouble Float64),
    `IslandID` FixedString(16),
    `RequestNum` UInt32,
    `RequestTry` UInt8
)
ENGINE = MergeTree()
PARTITION BY EventDate
ORDER BY (CounterID, EventDate, intHash32(UserID))
SAMPLE BY intHash32(UserID)
TTL EventDate + toIntervalDay(dateDiff('day', toDate('2014-03-20'), now())) TO DISK 'object_storage'
SETTINGS index_granularity = 8192

Note

This table uses the default storage policy.

The TTL ... expression sets a policy for handling expiring data:

  1. TTL sets the lifetime of a table row. In our case, it is the number of days from the current date to March 20, 2014.
  2. For the table data, the system checks the EventDate value:
    • If the number of days from the current date to EventDate is less than the TTL value (i.e., the lifetime has not expired yet), this data is kept in network disk storage.
    • If the number of days from the current date to EventDate is greater than or equal to the TTL value (that is, the lifetime has already expired), this data will be placed in object storage under the TO DISK 'object_storage' policy.

You do not need to specify TTL for hybrid storage, but this allows you to explicitly manage which data will be in Object Storage. If you do not specify TTL, data will only be placed in object storage when you run out of space in your network disk storage. For more information, see Disk types in Managed Service for ClickHouse®.

Note

The expression for TTL in the example above is complex due to the selected test dataset. You must split fixed data collected long ago into parts for placing it at various storage levels. For most tables constantly updated with new data, you can use a simpler TTL expression, such asEventDate + INTERVAL 5 DAY, which moves data older than 5 days to object storage.

Data is moved between storage on network disks and object storage in parts, not line by line. Make sure to choose the TTL expression and partitioning key so that the TTL matches for all rows in the data part. Otherwise, you may have problems moving data into object storage as TTL expires if one data part contains data intended for various storage levels. At the most basic level, the TTL expression should use the same columns as in the partitioning key, like in the example above featuring the EventDate column.

For more information on setting up TTL, see the ClickHouse® documentation.

Populate the table with dataPopulate the table with data

  1. Disconnect from the database.

  2. Download the test dataset:

    curl https://storage.yandexcloud.net/doc-files/managed-clickhouse/hits_v1.tsv.xz | unxz --threads=`nproc` > hits_v1.tsv
    

    The downloaded dataset is about 10 GB large.

  3. Insert data from this dataset into ClickHouse® using clickhouse-client:

    clickhouse-client \
        --host <ClickHouse®_host_FQDN> \
        --secure \
        --user <username> \
        --database tutorial \
        --port 9440 \
        --ask-password \
        --query "INSERT INTO tutorial.hits_v1 FORMAT TSV" \
        --max_insert_block_size=100000 < hits_v1.tsv
    

    You can get the host FQDN with a list of hosts in the cluster.

  4. Wait for the operation to complete, as data insertion may take some time.

For more information, see the relevant ClickHouse® documentation.

Check data placement in a clusterCheck data placement in a cluster

  1. Connect to the database.

  2. Check where the table rows are placed:

    SELECT
        table,
        partition,
        name,
        rows,
        disk_name
    FROM system.parts
    WHERE active AND (table = 'hits_v1') AND (database = 'tutorial')
    

    Table partitions for which the EventDate value is outside the given TTL should reside on the disk named object_storage, i.e., in object storage. All other partitions should reside on the default disk:

    ┌─table───┬─partition──┬─name───────────────┬───rows─┬─disk_name──────┐
    │ hits_v1 │ 2014-03-17 │ 20140317_6_80_2    │ 571657 │ object_storage │
    │ hits_v1 │ 2014-03-17 │ 20140317_86_125_1  │ 287545 │ object_storage │
    │ ...                                                                 │
    │ hits_v1 │ 2014-03-20 │ 20140320_109_145_1 │ 250484 │ object_storage │
    │ hits_v1 │ 2014-03-20 │ 20140320_149_200_1 │ 420081 │ object_storage │
    │ hits_v1 │ 2014-03-21 │ 20140321_3_57_1    │ 612616 │ default        │
    │ hits_v1 │ 2014-03-21 │ 20140321_65_65_0   │  53382 │ default        │
    │ ...                                                                 │
    │ hits_v1 │ 2014-03-23 │ 20140323_191_191_0 │  11145 │ default        │
    │ hits_v1 │ 2014-03-23 │ 20140323_197_197_0 │  98910 │ default        │
    └─────────┴────────────┴────────────────────┴────────┴────────────────┘
    
  3. Check the number of rows at each of the storage levels:

    SELECT
     sum(rows),
     disk_name
    FROM system.parts
    WHERE active AND (database = 'tutorial') AND (table = 'hits_v1')
    GROUP BY disk_name
    

    As a result, you will see the distribution of table rows for the storage levels:

    ┌─sum(rows)─┬─disk_name──────┐
    │   2711246 │ default        │
    │   6162652 │ object_storage │
    └───────────┴────────────────┘
    

As you can see from the SQL command results, the data in the table was successfully distributed in hybrid storage between different storage levels.

Run a test queryRun a test query

Run a test query to the tutorial.hits_v1 table that engages with data at multiple storage levels at once:

SELECT
    URLDomain AS Domain,
    AVG(SendTiming) AS AvgSendTiming
FROM tutorial.hits_v1
WHERE (EventDate >= '2014-03-19') AND (EventDate <= '2014-03-22')
GROUP BY Domain
ORDER BY AvgSendTiming DESC
LIMIT 10

Result:

┌─Domain──────────────────────────────┬──────AvgSendTiming─┐
│ realty.ru.msn.com.travel            │ 101166.85714285714 │
│ podbor.ru.msn.com.uazbukatusprosima │  76429.16666666667 │
│ club.metalia-woman                  │ 64872.333333333336 │
│ avito.rusfootki                     │              51099 │
│ papas.drimmirkvart                  │ 50325.642857142855 │
│ apps.oyunuoyna.com.uazbukadelight   │ 32761.666666666668 │
│ voyeurhit                           │          31501.625 │
│ yandex.ru.com.travesti.net          │            31427.5 │
│ sozcu.com.ua.alm.slands             │              29439 │
│ hasters.ru                          │ 18365.666666666668 │
└─────────────────────────────────────┴────────────────────┘

As you can see from the SQL request result, the user sees the table as a single entity: ClickHouse® successfully queries this table regardless of where the data is actually located in it.

Optionally, monitor the amount of space data in Object Storage takes upOptionally, monitor the amount of space data in Object Storage takes up

To monitor the amount of space MergeTree table chunks in Object Storage take up, use the ch_s3_disk_parts_size metric in Yandex Monitoring:

  1. In the management console, select Monitoring.

  2. Navigate to Metric Explorer.

  3. Run this request:

    "ch_s3_disk_parts_size"{service="managed-clickhouse", resource_type="cluster", node="by_host", resource_id="<cluster_ID>", subcluster_name="clickhouse_subcluster"}
    

Delete the resources you createdDelete the resources you created

Delete the resources you no longer need to avoid paying for them:

Manually
Terraform

Delete the Managed Service for ClickHouse® cluster.

  1. In the terminal window, go to the directory containing the infrastructure plan.

    Warning

    Make sure the directory has no Terraform manifests with the resources you want to keep. Terraform deletes all resources that were created using the manifests in the current directory.

  2. Delete resources:

    1. Run this command:

      terraform destroy
      
    2. Confirm deleting the resources and wait for the operation to complete.

    All the resources described in the Terraform manifests will be deleted.

ClickHouse® is a registered trademark of ClickHouse, Inc.

Was the article helpful?

Previous
Data resharding in a cluster
Next
Fetching data from Managed Service for Apache Kafka®
Yandex project
© 2025 Yandex.Cloud LLC