/
DML

DML

INSERT


insert_stmt:

insert_column_list:

value_list:


set_list:

insert_stmt ::= 'INSERT INTO' table_name ( '(' insert_column_list ')' )? 'METADATA'? 'VALUES' '(' value_list ')' ( 'ON DUPLICATE KEY UPDATE' ( 'SET' set_list )? )?
insert_column_list ::= column_name ( ',' column_name )*
value_list ::= value ( ',' value )*
set_list ::= column_name '=' value ( ',' column_name '=' value )*
create table test (number int,name varchar(20));
Created successfully.
insert into test values (1,"test");
1 row(s) inserted.
insert into test(name,number) values ("test",2);
1 row(s) inserted.


ํŠน์ • ํ…Œ์ด๋ธ”์— ๊ฐ’์„ ์ž…๋ ฅํ•˜๋Š” ๊ตฌ๋ฌธ์ด๋‹ค. ํ•œ ๊ฐ€์ง€ ํŠน์ดํ•œ ์ ์€ Column_List์—์„œ ์ง€์ •๋˜์ง€ ์•Š์€ ์ปฌ๋Ÿผ์—๋Š” ๋ชจ๋‘ NULL ๊ฐ’์œผ๋กœ ์ฑ„์›Œ์ง„๋‹ค๋Š” ๊ฒƒ์ด๋‹ค. ์ด๋Š” ์ž…๋ ฅ์˜ ํŽธ์˜์„ฑ๊ณผ ์ €์žฅ ๊ณต๊ฐ„์˜ ํšจ์œจํ™”๋ฅผ ์œ„ํ•ด ์ฑ„ํƒ๋œ ๋กœ๊ทธ ํŒŒ์ผ์˜ ํŠน์„ฑ์„ ๊ณ ๋ คํ•œ ์ •์ฑ…์ด๋‹ค.

METADATA๋Š” tag table์—๋งŒ ์‚ฌ์šฉ์ด ๊ฐ€๋Šฅํ•˜๋‹ค.

๋ชฉ์ฐจ



INSERT ON DUPLICATE KEY UPDATE

๋งˆํฌ๋ฒ ์ด์Šค๋Š”, ํ”ํžˆ ์•Œ๋ ค์ง„ UPSERT ๊ธฐ๋Šฅ๊ณผ ์œ ์‚ฌํ•œ ๊ตฌ๋ฌธ์„ ์ง€์›ํ•œ๋‹ค.

๊ธฐ๋ณธ ํ‚ค๊ฐ€ ์ง€์ •๋œ Lookup/Volatile ํ…Œ์ด๋ธ”์— ๊ฐ’์„ ์ž…๋ ฅํ•  ๋•Œ ์‚ฌ์šฉํ•  ์ˆ˜ ์žˆ๋Š” ํŠน์ˆ˜ ๊ตฌ๋ฌธ์œผ๋กœ, ๊ธฐ๋ณธ ํ‚ค ๊ฐ’์ด ์ค‘๋ณต๋˜๋Š” ๋ฐ์ดํ„ฐ๊ฐ€ ์ด๋ฏธ ํ…Œ์ด๋ธ”์— ์กด์žฌํ•˜๋Š” ๊ฒฝ์šฐ์—๋Š” ๊ธฐ์กด ๋ฐ์ดํ„ฐ์˜ ๊ฐ’์ด ๋ณ€๊ฒฝ๋œ๋‹ค.
๋ฌผ๋ก , ํ‚ค ๊ฐ’์ด ์ค‘๋ณต๋˜๋Š” ๋ฐ์ดํ„ฐ๊ฐ€ ์กด์žฌํ•˜์ง€ ์•Š๋Š” ๊ฒฝ์šฐ์—๋Š” ์ƒˆ๋กœ์šด ๋ฐ์ดํ„ฐ๋กœ ์‚ฝ์ž…๋œ๋‹ค.

์ด ๊ตฌ๋ฌธ์„ ์‚ฌ์šฉํ•˜๊ธฐ ์œ„ํ•ด์„œ, ํœ˜๋ฐœ์„ฑ ํ…Œ์ด๋ธ”์— ๊ธฐ๋ณธ ํ‚ค๊ฐ€ ์ง€์ •๋˜์–ด ์žˆ์–ด์•ผ ํ•œ๋‹ค.

์‚ฝ์ž…๋˜๋Š” ๋ฐ์ดํ„ฐ์˜ ์ปฌ๋Ÿผ ๊ฐ’๊ณผ ๊ฐฑ์‹ ๋˜๋Š” ๋ฐ์ดํ„ฐ์˜ ์ปฌ๋Ÿผ ๊ฐ’์„ ๋‹ค๋ฅด๊ฒŒ ํ•˜๊ณ ์ž ํ•˜๋Š” ๊ฒฝ์šฐ, ๋˜๋Š” ์‚ฝ์ž…๋˜๋Š” ๋ฐ์ดํ„ฐ์˜ ์ปฌ๋Ÿผ ๊ฐ’์ด ์•„๋‹Œ ๋‹ค๋ฅธ ์ปฌ๋Ÿผ ๊ฐ’์„ ๊ฐฑ์‹ ํ•˜๊ณ ์ž ํ•˜๋Š” ๊ฒฝ์šฐ์—๋Š” SET ์ ˆ์„ ์ถ”๊ฐ€๋กœ ์ž…๋ ฅํ•  ์ˆ˜ ์žˆ๋‹ค.

  • SET ์ ˆ์—๋Š”ย '์ปฌ๋Ÿผ=๊ฐ’'์œผ๋กœ ๊ตฌ์„ฑ๋˜๋ฉฐ, ๊ฐ๊ฐ์„ ์ฝค๋งˆ๋กœ ๊ตฌ๋ถ„ํ•ด์•ผ ํ•œ๋‹ค.

  • SET ์ ˆ์—์„œ ๊ธฐ๋ณธ ํ‚ค ๊ฐ’์„ ๋ณ€๊ฒฝํ•ด์„œ๋Š” ์•ˆ ๋œ๋‹ค.


INSERT SELECT


insert_select_stmt:


insert_select_stmt ::= 'INSERT INTO' table_name ( '(' insert_column_list ')' )? select_stmt


ํŠน์ • table์— ๋Œ€ํ•ด์„œ SELECT ๋ฌธ์˜ ์ˆ˜ํ–‰ ๊ฒฐ๊ณผ๋ฅผ ์‚ฝ์ž…ํ•˜๋Š” ๋ฌธ์žฅ์ด๋‹ค. ๊ธฐ๋ณธ์ ์œผ๋กœ๋Š” ๋‹ค๋ฅธ DBMS์™€ ์œ ์‚ฌํ•˜์ง€๋งŒ ๋‹ค์Œ์˜ ์ฐจ์ด์ ์ด ์žˆ๋‹ค.

  1. _ARRIVAL_TIME ์ปฌ๋Ÿผ ๊ฐ’์€ select ๋ฐ INSERT ์ปฌ๋Ÿผ ๋ฆฌ์ŠคํŠธ์—์„œ ์ง€์ •๋˜์ง€ ์•Š์œผ๋ฉด INSERT SELECT ๋ฌธ์ด ์ˆ˜ํ–‰๋˜๋Š” ์‹œ์ ์˜ ์‹œ๊ฐ„ ๊ฐ’์œผ๋กœ ์ž…๋ ฅ๋œ๋‹ค.

  2. VARCHAR ํƒ€์ž…์˜ ์ปฌ๋Ÿผ์— ๋Œ€ํ•ด์„œ ์‚ฝ์ž…๋˜๋Š” ์ž…๋ ฅ๊ฐ’์ด ์ปฌ๋Ÿผ์˜ ์ตœ๋Œ€ ๊ธธ์ด๋ณด๋‹ค ํฐ ๊ฒฝ์šฐ, ์˜ค๋ฅ˜๋ฅผ ๋ฐœ์ƒ์‹œํ‚ค์ง€ ์•Š๊ณ  ํ•ด๋‹น ์ปฌ๋Ÿผ์˜ ์ตœ๋Œ€ ๊ธธ์ด๋งŒํผ ์ž˜๋ผ์„œ ์ž…๋ ฅ๋œ๋‹ค.

  3. ํ˜• ๋ณ€ํ™˜์ด ๊ฐ€๋Šฅํ•œ ๊ฒฝ์šฐ(์ˆซ์žํ˜•->์ˆซ์žํ˜•)์—๋Š” ์ž…๋ ฅ๋˜๋Š” ์ปฌ๋Ÿผ ๊ฐ’์— ๋งž๊ฒŒ ์‚ฝ์ž…๋œ๋‹ค.

  4. ์ˆ˜ํ–‰ ๋„์ค‘ ์˜ค๋ฅ˜๊ฐ€ ๋ฐœ์ƒํ•œ ๊ฒฝ์šฐ ROLLBACK๋˜์ง€ ์•Š๋Š”๋‹ค.

  5. _ARRIVAL_TIME ์ปฌ๋Ÿผ์˜ ๊ฐ’์„ ์ง€์ •ํ•˜์—ฌ ์‚ฝ์ž…ํ•˜๋Š” ๊ฒฝ์šฐ, ์ƒˆ๋กœ ์ž…๋ ฅ๋˜๋Š” ๊ฐ’์ด ๊ธฐ์กด์˜ ๊ฐ’๋ณด๋‹ค ์ด์ „ ์‹œ๊ฐ„์„ ๊ฐ–๊ณ  ์žˆ์œผ๋ฉด ์ž…๋ ฅ๋˜์ง€ ์•Š๋Š”๋‹ค.

create table t1 (i1 integer, i2 varchar(60), i3 varchar(5));
Created successfully.

insert into t1 values (1, 'a', 'ddd' );
1 row(s) inserted.
insert into t1 values (2, 'kkkkkkkkkkkkkkkkkkkkk', 'c');
1 row(s) inserted.

insert into t1 select * from t1;
2 row(s) inserted.
create table t2 (i1 integer, i2 varchar(60), i3 varchar(5));

insert into t2 (_arrival_time, i1, i2, i3) select _arrival_time, * from t1;
4 row(s) inserted.


UPDATE


5.5 ๋ถ€ํ„ฐ ์ œ๊ณต๋˜๋Š” ๊ธฐ๋Šฅ์ž…๋‹ˆ๋‹ค.


update_stmt:

update_expr_list:


update_expr:


update_stmt ::= 'UPDATE' table_name ( 'METADATA' )? 'SET' update_expr_list 'WHERE' primary_key_column '=' value
update_expr_list ::= update_expr ( ',' update_expr)*
update_expr ::= column '=' value

INSERT ON DUPLICATE KEY UPDATE ๋ฅผ ํ†ตํ•œ UPSERT ๊ฐ€ ์•„๋‹Œ, UPDATE ๊ตฌ๋ฌธ๋„ ์ œ๊ณต๋œ๋‹ค.

์—ญ์‹œ, ๊ธฐ๋ณธ ํ‚ค (Primary Key) ๊ฐ€ ์ง€์ •๋œ Lookup/Volatile ํ…Œ์ด๋ธ”์— ๊ฐ’์„ ์ž…๋ ฅํ•  ๋•Œ ์‚ฌ์šฉํ•  ์ˆ˜ ์žˆ๋‹ค. WHERE ์ ˆ์—๋Š” ๊ธฐ๋ณธ ํ‚ค์˜ ์ผ์น˜ ์กฐ๊ฑด์‹์„ ์ž‘์„ฑํ•ด์•ผ ํ•œ๋‹ค.

UPDATE METADATA

TAGDATA ํ…Œ์ด๋ธ”์— ํ•œํ•ด์„œ, ๋ฉ”ํƒ€๋ฐ์ดํ„ฐ๋ฅผ ์—…๋ฐ์ดํŠธ ํ•˜๊ณ ์ž ํ•  ๋•Œ ์‚ฌ์šฉํ•œ๋‹ค.

UPDATE TAG METADATA SET ...


TAGDATA ํ…Œ์ด๋ธ”์˜ ๋ฉ”ํƒ€๋ฐ์ดํ„ฐ๋Š” INSERT ON DUPLICATE KEY UPDATE ๋ฅผ ํ†ตํ•ด ์ž…๋ ฅ/์ˆ˜์ •ํ•  ์ˆ˜ ์—†๋‹ค.


DELETE


delete_stmt:

time_unit:

delete_stmt ::= 'DELETE FROM' table_name ( 'OLDEST' number 'ROWS' | 'EXCEPT' number ( 'ROWS' | time_unit ) | 'BEFORE' datetime_expression )? 'NO WAIT'?
time_unit ::= 'DURATION' number time_unit ( ( 'BEFORE' | 'AFTER' ) number time_unit )?


๋งˆํฌ๋ฒ ์ด์Šค์—์„œ์˜ DELETE BEFORE ๊ตฌ๋ฌธ์€ ๋กœ๊ทธ ํ…Œ์ด๋ธ”, Tag ํ…Œ์ด๋ธ”, Rollup table์— ๋Œ€ํ•ด์„œ ์ˆ˜ํ–‰ ๊ฐ€๋Šฅํ•˜๋‹ค. ์ค‘๊ฐ„์˜ ์ž„์˜ ์œ„์น˜์— ์žˆ๋Š” ๋ฐ์ดํ„ฐ๋ฅผ ์‚ญ์ œํ•  ์ˆ˜ ์—†์œผ๋ฉฐ, ์ž„์˜์˜ ์œ„์น˜๋ถ€ํ„ฐ ์—ฐ์†์ ์œผ๋กœ ๋งˆ์ง€๋ง‰(๊ฐ€์žฅ ์˜ค๋ž˜๋œ ๋กœ๊ทธ) ๋ ˆ์ฝ”๋“œ๊นŒ์ง€ ์ง€์šธ ์ˆ˜ ์žˆ๋„๋ก ๊ตฌํ˜„๋˜์—ˆ๋‹ค.

์ด๋Š” ๋กœ๊ทธ ๋ฐ์ดํ„ฐ์˜ ํŠน์„ฑ์„ ์‚ด๋ฆฐ ์ •์ฑ…์œผ๋กœ์„œ ํ•œ๋ฒˆ ์ž…๋ ฅ๋˜๋ฉด ์ˆ˜์ •์ด ์—†๊ณ , ๊ณต๊ฐ„ ํ™•๋ณด๋ฅผ ์œ„ํ•ด ํŒŒ์ผ์„ ์‚ญ์ œํ•˜๋Š” ํ–‰์œ„๋ฅผ DB ํ˜•์‹์œผ๋กœ ํ‘œํ˜„ํ•œ ๊ฒƒ์ด๋‹ค.

DURATION, OLDEST, EXCEPT ๊ตฌ๋ฌธ์€ TAG ๋ฐ Rollup ํ…Œ์ด๋ธ”์— ๋Œ€ํ•ด์„œ๋Š” ์‚ฌ์šฉํ•  ์ˆ˜ ์—†๋‹ค.

-- ๋ชจ๋‘ ์‚ญ์ œํ•˜๋ผ.
DELETE FROM devices;

-- ๊ฐ€์žฅ ์˜ค๋ž˜๋œ ๋งˆ์ง€๋ง‰ N๊ฑด์„ ์‚ญ์ œํ•˜๋ผ.
DELETE FROM devices OLDEST N ROWS;

-- ์ตœ๊ทผ N๊ฑด์„ ์ œ์™ธํ•˜๊ณ  ๋ชจ๋‘ ์‚ญ์ œํ•˜๋ผ.
DELETE FROM devices EXCEPT N ROWS;

-- ์ง€๊ธˆ๋ถ€ํ„ฐ N์ผ์น˜๋ฅผ ๋‚จ๊ธฐ๊ณ  ๋ชจ๋‘ ์‚ญ์ œํ•˜๋ผ.
DELETE FROM devices EXCEPT N DAY;

-- 2014๋…„ 6์›” 1์ผ ์ด์ „์˜ ๋ฐ์ดํ„ฐ๋ฅผ ๋ชจ๋‘ ์‚ญ์ œํ•˜๋ผ.
DELETE FROM devices BEFORE TO_DATE('2014-06-01', 'YYYY-MM-DD');

-- tag ๋ฐ์ดํ„ฐ์˜ ์‹œ๊ฐ„ ๊ธฐ์ค€ ์‚ญ์ œ
DELETE FROM tag BEFORE TO_DATE('2014-06-01', 'YYYY-MM-DD');

-- tag rollup ๋ฐ์ดํ„ฐ์˜ ์‹œ๊ฐ„ ๊ธฐ์ค€ ์‚ญ์ œ
DELETE FROM tag ROLLUP BEFORE TO_DATE('2014-06-01', 'YYYY-MM-DD');


DELETE WHERE


delete_where_stmt:

delete_where_stmt ::= 'DELETE FROM' table_name 'WHERE' column_name '=' value


create volatile table t1 (i1 int primary key, i2 int);
Created successfully.
insert into t1 values (2,2);
1 row(s) inserted.
delete from t1 where i1 = 2;
1 row(s) deleted.

ํœ˜๋ฐœ์„ฑ ํ…Œ์ด๋ธ”์— ๋Œ€ํ•ด์„œ๋งŒ ์ˆ˜ํ–‰ ๊ฐ€๋Šฅํ•œ ๊ตฌ๋ฌธ์œผ๋กœ,ย WHEREย ์ ˆ์— ์ž‘์„ฑ๋œ ์กฐ๊ฑด์— ์ผ์น˜ํ•˜๋Š” ๋ ˆ์ฝ”๋“œ๋งŒ ์‚ญ์ œํ•  ์ˆ˜ ์žˆ๋‹ค.

  • ๊ธฐ๋ณธ ํ‚ค๊ฐ€ ์ง€์ •๋œ ํœ˜๋ฐœ์„ฑ ํ…Œ์ด๋ธ”์— ๋Œ€ํ•ด์„œ๋งŒ ์ˆ˜ํ–‰ ๊ฐ€๋Šฅํ•˜๋‹ค.

  • WHEREย ์ ˆ์—๋Š” (๊ธฐ๋ณธ ํ‚ค ์ปฌ๋Ÿผ) = (๊ฐ’) ์˜ ์กฐ๊ฑด๋งŒ ํ—ˆ์šฉ๋˜๋ฉฐ, ๋‹ค๋ฅธ ์กฐ๊ฑด๊ณผ ํ•จ๊ป˜ ์ž‘์„ฑํ•  ์ˆ˜ ์—†๋‹ค.

  • ๊ธฐ๋ณธ ํ‚ค ์ปฌ๋Ÿผ์ด ์•„๋‹Œ ๋‹ค๋ฅธ ์ปฌ๋Ÿผ์„ ์กฐ๊ฑด์— ์‚ฌ์šฉํ•  ์ˆ˜ ์—†๋‹ค.


delete_from_tag_where_stmt:

delete_from_tag_where_stmt ::= 'DELETE FROM' table_name 'WHERE' tag_name '=' value ( and tag_time '<' datetime_expression  )?

Tag ํ…Œ์ด๋ธ”์€ ์•„๋ž˜์™€ ๊ฐ™์ด 2๊ฐ€์ง€ ๋ฐฉ์‹์˜ ์‚ญ์ œ์ฟผ๋ฆฌ๊ฐ€, ์ถ”๊ฐ€์ ์œผ๋กœ ์ง€์›๋œ๋‹ค.

  • Tag name ๊ธฐ์ค€ ์‚ญ์ œ
  • Tag name๊ณผ Tag time ๊ธฐ์ค€ ์‚ญ์ œ
-- tag name ๊ธฐ์ค€ ์‚ญ์ œ
DELETE FROM tag where tag_name = 'my_tag_2021'

-- tag name ์™€ tag time ๊ธฐ์ค€ ์‚ญ์ œ
DELETE FROM tag where tag_name = 'my_tag_2021' and tag_time < TO_DATE('2021-07-01', 'YYYY-MM-DD');
  • ์‚ญ์ œ ์ฟผ๋ฆฌ๊ฐ€ ์‹คํ–‰๋œ ํ›„์—, ์‚ญ์ œ๋œ row๊ฐ€ ์ €์žฅ๊ณต๊ฐ„์—์„œ ๋ฌผ๋ฆฌ์ ์œผ๋กœ ์‚ญ์ œ๋˜๊ธฐ ๊นŒ์ง€ ๊ฑธ๋ฆฌ๋Š” ์‹œ๊ฐ„์€, DBMS์˜ ๋™์ž‘์ƒํ™ฉ์— ๋”ฐ๋ผ์„œ ๋‹ค๋ฅผ ์ˆ˜ ์žˆ๋‹ค.

LOAD DATA INFILE


load_data_infile_stmt:

load_data_infile_stmt: 'LOAD DATA INFILE' file_name 'INTO TABLE' table_name ( 'TABLESPACE' tbs_name )? ( 'AUTO' ( 'BULKLOAD' | 'HEADUSE' | 'HEADUSE_ESCAPE' ) )? ( ( 'FIELDS' | 'COLUMNS' ) ( 'TERMINATED BY' char )? ( 'ENCLOSED BY' char )? )? ( 'TRIM' ( 'ON' | 'OFF' ) )? ( 'IGNORE' number ( 'LINES' | 'ROWS' ) )? ( 'MAX_LINE_LENGTH' number )? ( 'ENCODED BY' coding_name )? ( 'ON ERROR' ( 'STOP' | 'IGNORE' ) )?


CSV ํฌ๋งท์˜ ๋ฐ์ดํ„ฐ ํŒŒ์ผ์„ ์„œ๋ฒ„์—์„œ ์ง์ ‘ ์ฝ์–ด์„œ, ์˜ต์…˜์— ๋”ฐ๋ผ ์„œ๋ฒ„์—์„œ ์ง์ ‘ ํ…Œ์ด๋ธ” ๋ฐ ์ปฌ๋Ÿผ๋“ค์„ ์ƒ์„ฑํ•˜์—ฌ ์ด๋ฅผ ์ž…๋ ฅํ•˜๋Š” ๊ธฐ๋Šฅ์ด๋‹ค.

๊ฐ ์˜ต์…˜์— ๋Œ€ํ•ด์„œ ์„ค๋ช…ํ•˜๋ฉด ๋‹ค์Œ๊ณผ ๊ฐ™๋‹ค.

์˜ต์…˜

์„ค๋ช…

AUTO mode_string

mode_string =

(BULKLOAD | HEADUSE | HEADUSE_ESCAPE)

ํ•ด๋‹น ํ…Œ์ด๋ธ”์„ ์ƒ์„ฑํ•˜๊ณ  ์ปฌ๋Ÿผ ํƒ€์ž…(์ž๋™ ์ƒ์„ฑ์‹œ varchar type) ๋ฐ ์ปฌ๋Ÿผ๋ช…์„ ์ž๋™์œผ๋กœ ์ƒ์„ฑํ•œ๋‹ค.

BULKLOAD: ๋ฐ์ดํ„ฐ ํ•œ ๊ฐœ์˜ row๋ฅผ ํ•˜๋‚˜์˜ ์ปฌ๋Ÿผ์œผ๋กœ ์ž…๋ ฅํ•œ๋‹ค. ์ปฌ๋Ÿผ์œผ๋กœ ๊ตฌ๋ถ„ํ•  ์ˆ˜ ์—†๋Š” ๋ฐ์ดํ„ฐ์— ๋Œ€ํ•ด์„œ ์‚ฌ์šฉํ•œ๋‹ค.

HEADUSE: ๋ฐ์ดํ„ฐ ํŒŒ์ผ์˜ ์ฒซ ๋ฒˆ์งธ ๋ผ์ธ์— ๊ธฐ์ˆ ๋˜์–ด ์žˆ๋Š” ์ปฌ๋Ÿผ ๋ช…์„ ํ…Œ์ด๋ธ”์˜ ์ปฌ๋Ÿผ๋ช…์œผ๋กœ ์‚ฌ์šฉํ•˜๊ณ , ๊ทธ ๋ผ์ธ์— ๊ธฐ์ˆ ๋œ ์ˆ˜ ๋งŒํผ์˜ ์ปฌ๋Ÿผ์„ ์ƒ์„ฑํ•œ๋‹ค.

HEADUSE_ESCAPE: HEADUSE ์˜ต์…˜๊ณผ ์œ ์‚ฌํ•˜์ง€๋งŒ, ์ปฌ๋Ÿผ๋ช…์ด DB์˜ ์˜ˆ์•ฝ์–ด์™€ ๊ฐ™์„ ๊ฒฝ์šฐ ๋ฐœ์ƒํ•  ์ˆ˜ ์žˆ๋Š” ์˜ค๋ฅ˜๋ฅผ ํšŒํ”ผํ•˜๊ธฐ ์œ„ํ•ด ์ปฌ๋Ÿผ๋ช…์˜ ์•ž๋’ค๋กœ '_' ๋ฌธ์ž๋ฅผ ๋ง๋ถ™์ด๊ณ , ์ปฌ๋Ÿผ๋ช…์— ํŠน์ˆ˜๋ฌธ์ž๊ฐ€ ์กด์žฌํ•˜๋ฉด ๊ทธ ๋ฌธ์ž๋ฅผ '_' ๋ฌธ์ž๋กœ ๋ณ€๊ฒฝํ•œ๋‹ค.

(FIELDS|COLUMNS) TERMINATED BY 'term_char'

ESCAPED BY 'escape_char'

๋ฐ์ดํ„ฐ ๋ผ์ธ์„ ํŒŒ์‹ฑํ•˜๊ธฐ ์œ„ํ•œ ๊ตฌ๋ถ„ ๋ฌธ์ž(term_char)์™€ ์ด์Šค์ผ€์ดํ”„ ๋ฌธ์ž(escape_char)๋ฅผ ์ง€์ •ํ•œ๋‹ค. ์ผ๋ฐ˜์ ์ธ CSV ํŒŒ์ผ์˜ ๊ฒฝ์šฐ ๊ตฌ๋ถ„ ๋ฌธ์ž๋Š” , ์ด๋ฉฐ ์ด์Šค์ผ€์ดํ”„ ๋ฌธ์ž๋Š” '์ด๋‹ค.

ENCODED BY coding_name

coding_name =

{ UTF8(default) | MS949 | KSC5601 | EUCJP | SHIFTJIS | BIG5 | GB231280 }

๋ฐ์ดํ„ฐ ํŒŒ์ผ์˜ ์ธ์ฝ”๋”ฉ ์˜ต์…˜์„ ์ง€์ •ํ•œ๋‹ค. ๊ธฐ๋ณธ ๊ฐ’์€ UTF-8์ด๋‹ค.

TRIM (ON | OFF)

์ปฌ๋Ÿผ์˜ ๋นˆ ๊ณต๊ฐ„์„ ์ œ๊ฑฐํ•˜๊ฑฐ๋‚˜ ์œ ์ง€ํ•œ๋‹ค. ๊ธฐ๋ณธ๊ฐ’์€ ON์ด๋‹ค.

IGNORE number (LINES | ROWS)

์ˆซ์ž๋กœ ์ง€์ •๋œ ๋ผ์ธ ๋˜๋Š” ํ–‰ ๋งŒํผ์˜ ๋ฐ์ดํ„ฐ๋ฅผ ๋ฌด์‹œํ•œ๋‹ค. CSV ํฌ๋งท ํŒŒ์ผ์˜ ํ—ค๋” ๋“ฑ์„ ๋ฌด์‹œํ•˜๊ฑฐ๋‚˜ VCF ํ—ค๋”๋ฅผ ๋ฌด์‹œํ•˜๊ธฐ ์œ„ํ•ด์„œ ์‚ฌ์šฉํ•œ๋‹ค.

MAX_LINE_LENGTH

ํ•œ ๋ผ์ธ์˜ ์ตœ๋Œ€ ๊ธธ์ด๋ฅผ ์ง€์ •ํ•œ๋‹ค. ๊ธฐ๋ณธ๊ฐ’์€ 512K์ด๋ฉฐ, ๋ฐ์ดํ„ฐ๊ฐ€ ๋” ํฐ ๊ฒฝ์šฐ์—๋Š” ๋” ํฐ ๊ฐ’์„ ์ง€์ •ํ•  ์ˆ˜ ์žˆ๋‹ค.

ON ERROR (STOP | IGNORE)

์ž…๋ ฅ ๋„์ค‘ ์—๋Ÿฌ๊ฐ€ ๋ฐœ์ƒํ•  ๊ฒฝ์šฐ ์ˆ˜ํ–‰ํ•  ๋™์ž‘์„ ์ง€์ •ํ•œ๋‹ค. STOP์ธ ๊ฒฝ์šฐ ์ž…๋ ฅ์„ ์ค‘๋‹จํ•˜๊ณ  IGNORE์ธ ๊ฒฝ์šฐ ์—๋Ÿฌ๊ฐ€ ๋ฐœ์ƒํ•œ ๋ผ์ธ์„ ๊ฑด๋„ˆ๋›ฐ๊ณ  ๊ณ„์† ์ž…๋ ฅํ•œ๋‹ค.

๊ธฐ๋ณธ๊ฐ’์€ IGNORE์ด๋‹ค.

-- default field delimiter(,)  field encloser (") ๋ฅผ ์‚ฌ์šฉํ•˜์—ฌ ๋ฐ์ดํ„ฐ๋ฅผ ์ž…๋ ฅํ•œ๋‹ค.
LOAD DATA INFILE '/tmp/aaa.csv' INTO TABLE Sample_data ; 

-- ํ•˜๋‚˜์˜ ์ปฌ๋Ÿผ์„ ๊ฐ–๋Š” NEWTABLE์„ ์ƒ์„ฑํ•ด์„œ ํ•œ ๋ผ์ธ์„ ํ•œ ์ปฌ๋Ÿผ์œผ๋กœ ์ž…๋ ฅํ•œ๋‹ค. 
LOAD DATA INFILE '/tmp/bbb.csv' INTO TABLE NEWTABLE AUTO BULKLOAD; 

-- csv์˜ ์ฒซ๋ฒˆ์งธ ๋ผ์ธ์„ ์ปฌ๋Ÿผ ์ •๋ณด๋กœ ์ด์šฉํ•˜์—ฌ NEWTABLE์„ ์ƒ์„ฑํ•˜๊ณ , ์ด๋ฅผ ๊ทธ ํ…Œ์ด๋ธ”์— ์ž…๋ ฅํ•œ๋‹ค. 
LOAD DATA INFILE '/tmp/bbb.csv' INTO TABLE NEWTABLE AUTO HEADUSE; 
 
-- ์ฒซ๋ฒˆ์งธ ๋ผ์ธ์€ ๋ฌด์‹œํ•˜๊ณ  ํ•„๋“œ ๊ตฌ๋ถ„์ž๋Š” ; enclosing ๋ฌธ์ž๋Š” ' ๋กœ ์ง€์ •ํ•ด์„œ ์ž…๋ ฅํ•œ๋‹ค. 
LOAD DATA INFILE '/tmp/ccc.csv' INTO TABLE Sample_data FIELDS TERMINATED BY ';' ENCLOSED BY '\''  IGNORE 1 LINES ON ERROR IGNORE;


AUTO ์˜ต์…˜์„ ์‚ฌ์šฉํ•˜์ง€ ์•Š๋Š” ๊ฒฝ์šฐ ํ…Œ์ด๋ธ”์˜ ๋ชจ๋“  ์ปฌ๋Ÿผ์€ VARCHAR ๋˜๋Š” TEXT ํƒ€์ž…์œผ๋กœ ์ƒ์„ฑํ•ด์•ผ ํ•œ๋‹ค.

Related content