Yandex Cloud
  • Services
  • Solutions
  • Why Yandex Cloud
  • Pricing
  • Documentation
  • Contact us
Get started
Language / Region
© 2022 Yandex.Cloud LLC
  • Contents
  • Getting started
    • Overview
    • Creating a database
    • Authentication
    • YDB command line interface (CLI)
    • YQL query language
    • YDB SDK
    • Self-deployment
      • Overview
      • Docker
      • Binary file
      • Minikube
    • Useful links
    • Amazon DynamoDB-compatible Document API
      • Setting up AWS tools
      • Working with data from the HTTP interface
      • Working with the AWS CLI
        • Overview
        • Creating a table
        • Adding data to a table
        • Reading data from a table
        • Updating data
        • Data selections
        • Deleting created resources
      • Working with the AWS SDK
        • Overview
        • Creating a table
        • Uploading data to a table
        • Managing records in a table
          • Creating a record
          • Reading a record
          • Updating a record
          • Deleting a record
        • Searching and extracting data
        • Deleting a table
  • Practical guidelines
    • Deploying a web application
    • Developing a Slack bot
    • Connecting to YDB from a Python function in Yandex Cloud Functions
    • Connecting to a YDB database from a Yandex Cloud Functions function in Node.js
    • Converting a video to a GIF in Python
    • Developing a skill for Alice and a website with authorization
  • Concepts
    • Overview
    • Terms and definitions
    • Connecting to and authenticating with a database
    • Data model and schema
    • Serverless and Dedicated operation modes
    • Transactions
    • Secondary indexes
    • Time to Live (TTL)
    • Scan queries
    • Database limits
    • YDB cluster
      • Overview
      • General YDB schema
      • Disk subsystem of a cluster
    • Quotas and limits
  • Step-by-step instructions
    • Overview
    • Renaming
    • Using a query plan and AST
    • Reading and writing data
    • Working with secondary indexes
  • Recommendations
    • Overview
    • Schema design
    • Partitioning tables
    • Secondary indexes
    • Paginated output
    • Loading large data volumes
    • Using timeouts
  • Managing databases
    • Overview
    • Cloud management console
      • Overview
      • Creating, updating, and deleting databases
      • Tables and directories
      • Access management
    • Yandex.Cloud CLI
    • Backup and recovery
    • Diagnostics
      • Overview
      • System views
      • Monitoring
    • Metric reference
  • Pricing policy
    • Overview
    • Serverless mode
      • Pricing policy for serverless mode
      • Query cost for YQL
      • Request cost for the Document API
      • Request cost for special APIs
    • Dedicated mode
  • Amazon DynamoDB-compatible HTTP API
    • All methods
    • Actions
      • BatchGetItem
      • BatchWriteItem
      • CreateTable
      • DeleteItem
      • DeleteTable
      • DescribeTable
      • DescribeTimeToLive
      • GetItem
      • ListTables
      • PutItem
      • Query
      • Scan
      • TransactGetItems
      • TransactWriteItems
      • UpdateItem
      • UpdateTimeToLive
    • Common errors
  • YQL
    • Overview
    • Data types
      • Overview
      • Simple
      • Optional
      • Containers
      • Special
      • Type casting
      • Text representation of data types
      • JSON
    • Syntax
      • Overview
      • Lexical structure
      • Expressions
      • ACTION
      • ALTER TABLE
      • CREATE TABLE
      • DECLARE
      • DELETE
      • DISCARD
      • DROP TABLE
      • GROUP BY
      • FLATTEN
      • INSERT
      • INTO RESULT
      • JOIN
      • PRAGMA
      • REPLACE
      • SELECT
      • UPDATE
      • UPSERT
      • VALUES
      • WINDOW
      • Unsupported statements
    • Built-in functions
      • Overview
      • Basic
      • Aggregate
      • Window
      • For lists
      • For dictionaries
      • For structures
      • For types
      • For JSON
      • C++ libraries
        • Overview
        • Hyperscan
        • Pcre
        • Pire
        • Re2
        • String
        • Unicode
        • DateTime
        • Url
        • Ip
        • Yson
        • Digest
        • Math
        • Histogram
    • YQL tutorial
      • Overview
      • Creating a table
      • Adding data to a table
      • Selecting data from all columns
      • Selecting data from specific columns
      • Sorting and filtering
      • Data aggregation
      • Additional selection criteria
      • Joining tables with JOIN
      • Inserting and updating data with REPLACE
      • Inserting and updating data with UPSERT
      • Inserting data with INSERT
      • Updating data with UPDATE
      • Deleting data
      • Adding and deleting columns
      • Deleting a table
  • Working with the YDB CLI
    • Overview
    • Install
    • Structure of YDB CLI commands
    • Service commands
    • Connecting to and authenticating with a database
    • Global parameters
    • Working with the DB schema
      • List of objects
      • Information about the object
      • Directories
      • Secondary indexes
      • Renaming tables
    • Operations with data
      • Making a DB query
      • Query execution plan
      • Streaming table reads
      • Scan queries
    • Importing and exporting data
      • Overview
      • File structure of data export
      • Exporting data to the file system
      • Importing data from the file system
      • Connecting to and authenticating with S3
      • Exporting data to S3
      • Importing data from S3
    • Managing profiles
      • Overview
      • Creating a profile
      • Using a profile in requests
      • Getting profile information
      • Deleting a profile
      • Activated profile
    • Information services
      • List of endpoints
      • Authentication
    • Load testing
      • Overview
      • Stock load
  • Working with the YDB SDK
    • Overview
    • Install
    • Authentication
    • Test app
      • Overview
      • C++
      • C# (.NET)
      • Go
      • Java
      • Node.js
      • PHP
      • Python
      • Archive
        • Go v1
        • Go v2
    • Handling errors in the API
    • Code recipes
      • Overview
      • Authentication
        • Overview
        • Using a token
        • Anonymous
        • Service account file
        • Metadata service
        • Using environment variables
        • Username and password based
      • Balancing
        • Overview
        • Random choice
        • Prefer the nearest data center
        • Prefer the availability zone
      • Running repeat queries
      • Troubleshooting
        • Overview
        • Enable logging
        • Enable metrics in Prometheus
        • Enable tracing in Jaeger
      • Setting the session pool size
  • Managing a cluster
    • Overview
    • Kubernetes
      • Overview
      • Deploying in Yandex Managed Service for Kubernetes
      • Deploying in AWS Elastic Kubernetes Service
      • Use
    • Manual
      • Overview
      • Local deployment
      • Cluster configuration
      • Production checklist
      • Maintaining a cluster's disk subsystem
        • Overview
        • How to stay within the failure model
        • Disk load balancing
        • Methods to free up space on physical devices
        • Cluster extension
        • Adding storage groups
        • Safe restart and shutdown of nodes
        • Enabling/disabling SelfHeal
        • Enabling/disabling Scrubbing
        • Moving VDisks
        • Updating configurations via CMS
        • Updating configuration of the actor system
    • Embedded UI
      • Overview
      • YDB Monitoring
      • Hive web-viewer
      • Connections overview
      • Logs
      • Charts
    • System views
  • Questions and answers
    • Overview
    • General questions
    • Errors
    • YQL
    • Serverless
    • All questions on one page
  1. Step-by-step instructions
  2. Reading and writing data

Reading and writing data

Written by
Yandex Cloud
  • Prerequisites
  • SQL queries in the management console
  • Insert and update data
    • REPLACE
    • UPSERT
    • INSERT
    • UPDATE
    • DELETE
  • Query data using SELECT
  • Make a parameterized query

Queries can be sent to YDB in the following ways:

  • From the management console.
  • from an application written in YDB SDK for Java, Python, Node.js, PHP, or Go.
  • Using the API compatible with Amazon DynamoDB (for document tables).

In this section, we are going to use the management console to execute queries.

Prerequisites

To run queries, you'll need to create a database and a table in it.

SQL queries in the management console

To send an SQL query to a database from the management console:

  1. In the management console, select the folder with the desired DB.
  2. In the list of services, select Managed Service for YDB.
  3. Select the database from the list.
  4. Go to the Navigation tab.
  5. Click SQL query and enter the query text. When making queries, you can use the following templates:
    • To use one of the standard templates, select it from the drop-down list to the right of the SQL query button.
    • To populate a template with data from a specific table, click in the row next to the table and select a template.
  6. Click Run.

Insert and update data

To insert data into YDB, use REPLACE, UPSERT, and INSERT statements.

When executing REPLACE and UPSERT statements, a blind write is performed. With an INSERT statement, data is read before writing. This ensures that the primary key is unique.

We recommend using REPLACE and UPSERT statements to write and modify data.

A single REPLACE, UPSERT, or INSERT query can insert multiple rows into a table.

Warning

The YQL management console includes PRAGMA AutoCommit. This means that COMMIT is automatically executed after each query. For example, if you enter multiple statements (as shown in the example below) and execute the query, COMMIT is run automatically after the query.

REPLACE INTO episodes (series_id, season_id, episode_id, title) VALUES (1, 1, 1, "Yesterday's Jam");
REPLACE INTO episodes (series_id, season_id, episode_id, title) VALUES (1, 1, 2, "Calamity Jen");

REPLACE

Once the series, season, and episodes tables are created, you can insert data into a table using the REPLACE statement. Basic syntax:

REPLACE INTO table_name (column_list) VALUES (list_of_added_values);

Use REPLACE statements to add a new row or change an existing row based on the specified value of the primary key. If a row with the specified primary key value does not exist, it is created. If the row exists already, the column values of the existing row are replaced with the new values. The values of columns not involved in the operation are set to their default values. This is the only way the UPSERT statement is different.

Note

When performing a REPLACE operation, a blind write is performed. For write or change operations, we recommend using REPLACE and UPSERT statements.

Data added using the following code sample will be used later in this section.

REPLACE INTO series (series_id, title, release_date, series_info)
VALUES
    (
        1,
        "IT Crowd",
        CAST(Date("2006-02-03") AS Uint64),
        "The IT Crowd is a British sitcom produced by Channel 4, written by Graham Linehan, produced by Ash Atalla and starring Chris O'Dowd, Richard Ayoade, Katherine Parkinson, and Matt Berry."
    ),
    (
        2,
        "Silicon Valley",
        CAST(Date("2014-04-06") AS Uint64),
        "Silicon Valley is an American comedy television series created by Mike Judge, John Altschuler and Dave Krinsky. The series focuses on five young men who founded a startup company in Silicon Valley."
    )
    ;

REPLACE INTO seasons (series_id, season_id, title, first_aired, last_aired)
VALUES
    (1, 1, "Season 1", CAST(Date("2006-02-03") AS Uint64), CAST(Date("2006-03-03") AS Uint64)),
    (1, 2, "Season 2", CAST(Date("2007-08-24") AS Uint64), CAST(Date("2007-09-28") AS Uint64)),
    (2, 1, "Season 1", CAST(Date("2014-04-06") AS Uint64), CAST(Date("2014-06-01") AS Uint64)),
    (2, 2, "Season 2", CAST(Date("2015-04-12") AS Uint64), CAST(Date("2015-06-14") AS Uint64))
;

REPLACE INTO episodes (series_id, season_id, episode_id, title, air_date)
VALUES
    (1, 1, 1, "Yesterday's Jam", CAST(Date("2006-02-03") AS Uint64)),
    (1, 1, 2, "Calamity Jen", CAST(Date("2006-02-03") AS Uint64)),
    (2, 1, 1, "Minimum Viable Product", CAST(Date("2014-04-06") AS Uint64)),
    (2, 1, 2, "The Cap Table", CAST(Date("2014-04-13") AS Uint64))
;

UPSERT

Use UPSERT statements to add a new row or change an existing row based on the specified value of the primary key. If a row with the specified primary key value does not exist, it is created. If the row exists already, the column values of the existing row are replaced with the new values. However, the values of columns not involved in the operation are not changed. This is what makes it different from the REPLACE statement.

Note

When making an UPSERT, a blind write is performed. For writing data, we recommend using REPLACE and UPSERT statements.

The code below inserts one row of data into the episodes table.

UPSERT INTO episodes
(
    series_id,
    season_id,
    episode_id,
    title,
    air_date
)
VALUES
(
    2,
    1,
    3,
    "Test Episode",
    CAST(Date("2018-08-27") AS Uint64)
)
;

INSERT

Use INSERT statements to insert one or more rows. If you try to insert a row into a table with an existing primary key value, YDB returns the error message Transaction rolled back due to constraint violation: insert_pk..

Note

When an INSERT operation is executed, the data is read before it is written. This makes it less efficient than REPLACE and UPSERT operations. For writing data, we recommend using REPLACE and UPSERT operations.

The code below inserts one row of data into the episodes table.

INSERT INTO episodes
(
    series_id,
    season_id,
    episode_id,
    title,
    air_date
)
VALUES
(
    2,
    5,
    21,
    "Test 21",
    CAST(Date("2018-08-27") AS Uint64)
)
;

UPDATE

The UPDATE statement changes column values for table row filtered by the WHERE predicate. Basic syntax:

UPDATE table_name SET column1_name=new_column1_value, ... ,columnN_name=new_columnN_value WHERE conditions_for_row_filter;

UPDATE statements can't change primary key values. Enter and execute the following UPDATE statement to change the value of the title column from "Test Episode" to "Test Episode Updated" for the episode with series_id = 2, season_id = 1, and episode_id = 3.

UPDATE episodes
SET title="Test Episode Updated"
WHERE
    series_id = 2
    AND season_id = 1
    AND episode_id = 3
;

DELETE

The DELETE statement deletes table rows filtered by a WHERE predicate. The code below removes an episode with series_id = 2, season_id = 5, and episode_id = 21 from the episodes table.

DELETE
FROM episodes
WHERE
    series_id = 2
    AND season_id = 5
    AND episode_id = 21
;

Query data using SELECT

Use the SELECT statement to read data from a table.

To query data from the series table, execute the code shown below.

SELECT
    series_id,
    title AS series_title,
    CAST (release_date AS Date) AS release_date
FROM series;

You can use an asterisk to select all the columns in a table. To obtain the values of all columns from the series table,
execute the code shown below.

SELECT
    *
FROM series;

Note

For more information about querying data by secondary index, see the YQL documentation.

Make a parameterized query

Use parameterized queries to improve performance by reducing the frequency of compiling and recompiling your queries.

Example

DECLARE $seriesId AS Uint64;
DECLARE $seasonId AS Uint64;

$seriesId = 1;
$seasonId = 2;

SELECT sa.title AS season_title, sr.title AS series_title
FROM seasons AS sa
INNER JOIN series AS sr
ON sa.series_id = sr.series_id
WHERE sa.series_id = $seriesId AND sa.season_id = $seasonId;

Was the article helpful?

Language / Region
© 2022 Yandex.Cloud LLC
In this article:
  • Prerequisites
  • SQL queries in the management console
  • Insert and update data
  • REPLACE
  • UPSERT
  • INSERT
  • UPDATE
  • DELETE
  • Query data using SELECT
  • Make a parameterized query