2020-04-03 13:23:32 +00:00
---
2022-08-28 14:53:34 +00:00
slug: /en/sql-reference/table-functions/file
2023-06-23 13:16:22 +00:00
sidebar_position: 60
2022-04-09 13:29:05 +00:00
sidebar_label: file
2020-04-03 13:23:32 +00:00
---
2022-06-02 10:55:18 +00:00
# file
2018-05-14 19:58:49 +00:00
2023-04-19 15:14:39 +00:00
Provides a table-like interface to SELECT from and INSERT to files. This table function is similar to the [s3 ](/docs/en/sql-reference/table-functions/url.md ) table function. Use file() when working with local files, and s3() when working with buckets in S3, GCS, or MinIO.
2021-01-19 22:39:12 +00:00
2023-04-19 15:14:39 +00:00
The `file` function can be used in `SELECT` and `INSERT` queries to read from or write to files.
2021-01-19 22:39:12 +00:00
**Syntax**
2018-05-14 19:58:49 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2023-05-29 20:34:19 +00:00
file([path_to_archive ::] path [,format] [,structure] [,compression])
2018-10-19 11:25:22 +00:00
```
2021-02-14 11:14:39 +00:00
**Parameters**
2018-10-19 11:25:22 +00:00
2023-04-19 15:55:29 +00:00
- `path` — The relative path to the file from [user_files_path ](/docs/en/operations/server-configuration-parameters/settings.md#server_configuration_parameters-user_files_path ). Path to file support following globs in read-only mode: `*` , `?` , `{abc,def}` and `{N..M}` where `N` , `M` — numbers, `'abc', 'def'` — strings.
2023-07-28 13:00:35 +00:00
- `path_to_archive` - The relative path to zip/tar/7z archive. Path to archive support the same globs as `path` .
2023-04-19 15:55:29 +00:00
- `format` — The [format ](/docs/en/interfaces/formats.md#formats ) of the file.
- `structure` — Structure of the table. Format: `'column1_name column1_type, column2_name column2_type, ...'` .
- `compression` — The existing compression type when used in a `SELECT` query, or the desired compression type when used in an `INSERT` query. The supported compression types are `gz` , `br` , `xz` , `zst` , `lz4` , and `bz2` .
2023-05-29 17:36:34 +00:00
2018-05-14 19:58:49 +00:00
2018-10-19 11:25:22 +00:00
**Returned value**
2018-05-14 19:58:49 +00:00
2018-10-19 11:25:22 +00:00
A table with the specified structure for reading or writing data in the specified file.
2018-05-14 19:58:49 +00:00
2023-04-19 15:14:39 +00:00
## File Write Examples
### Write to a TSV file
```sql
INSERT INTO TABLE FUNCTION
file('test.tsv', 'TSV', 'column1 UInt32, column2 UInt32, column3 UInt32')
VALUES (1, 2, 3), (3, 2, 1), (1, 3, 2)
```
As a result, the data is written into the file `test.tsv` :
```bash
2023-05-25 20:10:02 +00:00
# cat /var/lib/clickhouse/user_files/test.tsv
2023-04-19 15:14:39 +00:00
1 2 3
3 2 1
1 3 2
```
### Partitioned Write to multiple TSV files
If you specify `PARTITION BY` expression when inserting data into a file() function, a separate file is created for each partition value. Splitting the data into separate files helps to improve reading operations efficiency.
```sql
INSERT INTO TABLE FUNCTION
file('test_{_partition_id}.tsv', 'TSV', 'column1 UInt32, column2 UInt32, column3 UInt32')
PARTITION BY column3
VALUES (1, 2, 3), (3, 2, 1), (1, 3, 2)
```
As a result, the data is written into three files: `test_1.tsv` , `test_2.tsv` , and `test_3.tsv` .
```bash
# cat /var/lib/clickhouse/user_files/test_1.tsv
3 2 1
# cat /var/lib/clickhouse/user_files/test_2.tsv
1 3 2
# cat /var/lib/clickhouse/user_files/test_3.tsv
1 2 3
```
## File Read Examples
### SELECT from a CSV file
2018-05-14 19:58:49 +00:00
2018-10-19 11:25:22 +00:00
Setting `user_files_path` and the contents of the file `test.csv` :
2020-03-20 10:10:48 +00:00
``` bash
2018-10-19 11:25:22 +00:00
$ grep user_files_path /etc/clickhouse-server/config.xml
< user_files_path > /var/lib/clickhouse/user_files/< / user_files_path >
$ cat /var/lib/clickhouse/user_files/test.csv
1,2,3
3,2,1
78,43,45
```
2021-02-14 11:14:39 +00:00
Getting data from a table in `test.csv` and selecting the first two rows from it:
2018-10-19 11:25:22 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2023-04-19 15:14:39 +00:00
SELECT * FROM
file('test.csv', 'CSV', 'column1 UInt32, column2 UInt32, column3 UInt32')
LIMIT 2;
2018-10-19 11:25:22 +00:00
```
2020-03-20 10:10:48 +00:00
``` text
2018-10-19 11:25:22 +00:00
┌─column1─┬─column2─┬─column3─┐
│ 1 │ 2 │ 3 │
│ 3 │ 2 │ 1 │
└─────────┴─────────┴─────────┘
```
2021-02-14 11:14:39 +00:00
2023-03-03 13:21:02 +00:00
Getting the first 10 lines of a table that contains 3 columns of [UInt32 ](/docs/en/sql-reference/data-types/int-uint.md ) type from a CSV file:
2018-10-19 11:25:22 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2023-04-19 15:14:39 +00:00
SELECT * FROM
file('test.csv', 'CSV', 'column1 UInt32, column2 UInt32, column3 UInt32')
LIMIT 10;
2021-01-19 22:39:12 +00:00
```
2023-04-19 15:14:39 +00:00
### Inserting data from a file into a table:
2021-01-19 22:39:12 +00:00
``` sql
2023-04-19 15:14:39 +00:00
INSERT INTO FUNCTION
file('test.csv', 'CSV', 'column1 UInt32, column2 UInt32, column3 UInt32')
VALUES (1, 2, 3), (3, 2, 1);
```
```sql
SELECT * FROM
file('test.csv', 'CSV', 'column1 UInt32, column2 UInt32, column3 UInt32');
2018-05-14 19:58:49 +00:00
```
2018-10-16 10:47:17 +00:00
2021-01-19 22:39:12 +00:00
``` text
┌─column1─┬─column2─┬─column3─┐
│ 1 │ 2 │ 3 │
│ 3 │ 2 │ 1 │
└─────────┴─────────┴─────────┘
```
2023-07-28 13:00:35 +00:00
Getting data from table in table.csv, located in archive1.zip or/and archive2.zip
2023-05-29 17:36:34 +00:00
``` sql
SELECT * FROM file('user_files/archives/archive{1..2}.zip :: table.csv');
```
2023-08-11 13:53:17 +00:00
## Globs in Path {#globs_in_path}
2019-09-04 11:11:30 +00:00
2021-02-18 18:42:38 +00:00
Multiple path components can have globs. For being processed file must exist and match to the whole path pattern (not only suffix or prefix).
2019-09-04 11:11:30 +00:00
2023-04-19 15:55:29 +00:00
- `*` — Substitutes any number of any characters except `/` including empty string.
- `?` — Substitutes any single character.
2023-09-20 22:16:17 +00:00
- `{some_string,another_string,yet_another_one}` — Substitutes any of strings `'some_string', 'another_string', 'yet_another_one'` . The strings can contain the `/` symbol.
2023-04-19 15:55:29 +00:00
- `{N..M}` — Substitutes any number in range from N to M including both borders.
- `**` - Fetches all files inside the folder recursively.
2019-09-20 11:26:00 +00:00
2021-02-14 11:14:39 +00:00
Constructions with `{}` are similar to the [remote ](remote.md ) table function.
2019-09-20 11:26:00 +00:00
**Example**
2021-01-19 23:02:46 +00:00
Suppose we have several files with the following relative paths:
2020-03-20 10:10:48 +00:00
2023-04-19 15:55:29 +00:00
- 'some_dir/some_file_1'
- 'some_dir/some_file_2'
- 'some_dir/some_file_3'
- 'another_dir/some_file_1'
- 'another_dir/some_file_2'
- 'another_dir/some_file_3'
2019-09-20 11:26:00 +00:00
2021-02-14 11:14:39 +00:00
Query the number of rows in these files:
2019-09-20 11:26:00 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2021-01-19 23:02:46 +00:00
SELECT count(*) FROM file('{some,another}_dir/some_file_{1..3}', 'TSV', 'name String, value UInt32');
2019-09-20 11:26:00 +00:00
```
2021-02-14 11:14:39 +00:00
Query the number of rows in all files of these two directories:
2020-03-20 10:10:48 +00:00
``` sql
2021-01-19 23:02:46 +00:00
SELECT count(*) FROM file('{some,another}_dir/*', 'TSV', 'name String, value UInt32');
2019-09-20 11:26:00 +00:00
```
2020-03-20 10:10:48 +00:00
2023-05-25 20:10:02 +00:00
:::note
2022-04-09 13:29:05 +00:00
If your listing of files contains number ranges with leading zeros, use the construction with braces for each digit separately or use `?` .
:::
2019-09-04 11:11:30 +00:00
2019-09-20 11:26:00 +00:00
**Example**
2020-03-20 10:10:48 +00:00
Query the data from files named `file000` , `file001` , … , `file999` :
2019-09-20 11:26:00 +00:00
2020-03-20 10:10:48 +00:00
``` sql
2021-01-19 23:02:46 +00:00
SELECT count(*) FROM file('big_dir/file{0..9}{0..9}{0..9}', 'CSV', 'name String, value UInt32');
2019-09-20 11:26:00 +00:00
```
2019-09-04 11:11:30 +00:00
2022-10-18 12:08:26 +00:00
**Example**
Query the data from all files inside `big_dir` directory recursively:
``` sql
SELECT count(*) FROM file('big_dir/**', 'CSV', 'name String, value UInt32');
```
**Example**
Query the data from all `file002` files from any folder inside `big_dir` directory recursively:
``` sql
SELECT count(*) FROM file('big_dir/**/file002', 'CSV', 'name String, value UInt32');
```
2022-06-02 10:55:18 +00:00
## Virtual Columns
2020-01-15 07:52:45 +00:00
2023-04-19 15:55:29 +00:00
- `_path` — Path to the file.
- `_file` — Name of the file.
2020-01-15 07:52:45 +00:00
2023-05-31 17:52:29 +00:00
## Settings
- [engine_file_empty_if_not_exists ](/docs/en/operations/settings/settings.md#engine-file-emptyif-not-exists ) - allows to select empty data from a file that doesn't exist. Disabled by default.
- [engine_file_truncate_on_insert ](/docs/en/operations/settings/settings.md#engine-file-truncate-on-insert ) - allows to truncate file before insert into it. Disabled by default.
- [engine_file_allow_create_multiple_files ](/docs/en/operations/settings/settings.md#engine_file_allow_create_multiple_files ) - allows to create a new file on each insert if format has suffix. Disabled by default.
- [engine_file_skip_empty_files ](/docs/en/operations/settings/settings.md#engine_file_skip_empty_files ) - allows to skip empty files while reading. Disabled by default.
- [storage_file_read_method ](/docs/en/operations/settings/settings.md#engine-file-emptyif-not-exists ) - method of reading data from storage file, one of: read, pread, mmap (only for clickhouse-local). Default value: `pread` for clickhouse-server, `mmap` for clickhouse-local.
2020-01-15 07:52:45 +00:00
**See Also**
2023-04-19 15:55:29 +00:00
- [Virtual columns ](/docs/en/engines/table-engines/index.md#table_engines-virtual_columns )
2023-05-25 20:10:02 +00:00
- [Rename files after processing ](/docs/en/operations/settings/settings.md#rename_files_after_processing )