The CSV storage engine stores data in text files using comma-separated values format, allowing easy data exchange with other applications.
The CSV Storage Engine stores data in comma-separated values format text files, making it easy to exchange data with other applications.
The CSV Storage Engine can read and append to files stored in CSV (comma-separated-values) format.
The CSV storage engine is the default storage engine when using logging of SQL queries to tables.
When you create a table using the CSV storage engine, three files are created:
<table_name>.frm
<table_name>.CSV
<table_name>.CSM
The .frm file is the table format file.
The .CSV file is a plain text file. Data you enter into the table is stored as plain text in comma-separated-values format.
The .CSM file stores metadata about the table such as the state and the number of rows in the table.
CSV tables do not support indexing.
CSV tables cannot be partitioned.
Columns in CSV tables must be declared as NOT NULL.
No .
Forgetting to add NOT NULL:
Creating, inserting and selecting:
Viewing in a text editor:
This page is licensed: CC BY-SA / Gnu FDL
mysqld --log-output=tableCREATE TABLE csv_test (x INT, y DATE, z CHAR(10)) ENGINE=CSV;
ERROR 1178 (42000): The storage engine for the table doesn't support nullable columnsCREATE TABLE csv_test (
x INT NOT NULL, y DATE NOT NULL, z CHAR(10) NOT NULL
) ENGINE=CSV;INSERT INTO csv_test VALUES
(1,CURDATE(),'one'),
(2,CURDATE(),'two'),
(3,CURDATE(),'three');SELECT * FROM csv_test;
+---+------------+-------+
| x | y | z |
+---+------------+-------+
| 1 | 2011-11-16 | one |
| 2 | 2011-11-16 | two |
| 3 | 2011-11-16 | three |
+---+------------+-------+$ cat csv_test.CSV
1,"2011-11-16","one"
2,"2011-11-16","two"
3,"2011-11-16","three"Learn how to use CHECK TABLE and REPAIR TABLE to identify and fix corruptions in CSV tables, discarding rows from the first error onwards.
CSV tables support the CHECK TABLE and REPAIR TABLE statements.
CHECK TABLE marks the table as corrupt if it finds a problem, while REPAIR TABLE restores rows until the first corrupted row, discarding the rest.
CREATE TABLE csv_test (
x INT NOT NULL, y DATE NOT NULL, z CHAR(10) NOT NULL
) ENGINE=CSV;
INSERT INTO csv_test VALUES
(1,CURDATE(),'one'),
(2,CURDATE(),'two'),
(3,CURDATE(),'three');SELECT * FROM csv_test;
+---+------------+-------+
| x | y | z |
+---+------------+-------+
| 1 | 2013-07-08 | one |
| 2 | 2013-07-08 | two |
| 3 | 2013-07-08 | three |
+---+------------+-------+Using an editor, the actual file will look as follows
Let's introduce some corruption with an unwanted quote in the 2nd row:
We can repair this, but all rows from the corrupt row onwards are lost:
This page is licensed: CC BY-SA / Gnu FDL
$ cat csv_test.CSV
1,"2013-07-08","one"
2,"2013-07-08","two"
3,"2013-07-08","three"1,"2013-07-08","one"
2","2013-07-08","two"
3,"2013-07-08","three"CHECK TABLE csv_test;
+---------------+-------+----------+----------+
| Table | Op | Msg_type | Msg_text |
+---------------+-------+----------+----------+
| test.csv_test | check | error | Corrupt |
+---------------+-------+----------+----------+REPAIR TABLE csv_test;
+---------------+--------+----------+----------------------------------------+
| Table | Op | Msg_type | Msg_text |
+---------------+--------+----------+----------------------------------------+
| test.csv_test | repair | Warning | Data truncated for column 'x' at row 2 |
| test.csv_test | repair | status | OK |
+---------------+--------+----------+----------------------------------------+
SELECT * FROM csv_test;
+---+------------+-----+
| x | y | z |
+---+------------+-----+
| 1 | 2013-07-08 | one |
+---+------------+-----+