測試環境為 CentOS 7 x86_64 (虛擬機)
如何利用 SQL 的 INSERT 語法將文字檔案的內容自動轉到資料庫裡.
如果是單一檔案內容上傳至單一欄位可以使用 LOAD_FILE 函數,詳細使用請參考 – https://benjr.tw/101779 .
Linux Bash Script – loop 迴圈
如果你的資料是簡單的單行資料需要轉入到 MySQL 的資料庫時,可以透過 Linux Bash Script – Loop 迴圈方式進行轉換,測試資料如下:
[root@localhost ~]# cat /tmp/fruit Apple Banana Cherry
先將資料庫的資料表 (table) 建立好,除了從文字檔案的內容輸入到資料表 name 欄位之外,還多兩個其他欄位.
- id 為 PRIMARY Key 並且是自動產生 AUTO_INCREMENT.
- uptime 為 TIMESTAMP 欄位,預設值為 CURRENT_TIMESTAMP (日期時間函數,功能與 NOW 一樣,都是回傳目前系統的日期時間),ON UPDATE CURRENT_TIMESTAMP 資料更新時,time stamp 也一同更新.
[root@localhost ~]# mysql -u root -p Enter password: Welcome to the MariaDB monitor. Commands end with ; or \g. Your MariaDB connection id is 8 Server version: 5.5.60-MariaDB MariaDB Server Copyright (c) 2000, 2018, Oracle, MariaDB Corporation Ab and others. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. MariaDB [(none)]> CREATE DATABASE dbtest; Query OK, 1 row affected (0.00 sec) MariaDB [(none)]> USE dbtest; Database changed MariaDB [(none)]> CREATE TABLE fruit ( id INT(11) AUTO_INCREMENT PRIMARY KEY , name CHAR(20) , uptime TIMESTAMP); Query OK, 0 rows affected (0.01 sec) MariaDB [dbtest]> DESCRIBE fruit; +--------+-----------+------+-----+-------------------+-----------------------------+ | Field | Type | Null | Key | Default | Extra | +--------+-----------+------+-----+-------------------+-----------------------------+ | id | int(11) | NO | PRI | NULL | auto_increment | | name | char(20) | YES | | NULL | | | uptime | timestamp | NO | | CURRENT_TIMESTAMP | on update CURRENT_TIMESTAMP | +--------+-----------+------+-----+-------------------+-----------------------------+ 3 rows in set (0.00 sec) MariaDB [sbtest]> quit; Bye
現在透過簡單的 Linux bash script 使用 for 迴圈即可依序把資料輸入到資料庫.
[root@localhost ~]# vi textintosql.sh #!/bin/bash for i in $( cat /tmp/fruit ) do echo "INSERT INTO dbtest.fruit (name) values ('$i');" | mysql -u root -p111111; done
[root@localhost ~]# chmod a+x textintosql.sh [root@localhost ~]# ./textintosql.sh
檢視一下剛剛輸入的資料.
[root@localhost ~]# echo "select * from dbtest.fruit;" | mysql -u root -p111111; id name uptime 1 Apple 2019-04-24 20:46:56 2 Banana 2019-04-24 20:46:56 3 Cherry 2019-04-24 20:46:56
SQL 語法 LOAD DATA INFILE (Import)
但資料格式通常沒有這麼簡單,以 Linux 的 /etc/passwd 為範例,這時候可以利用 SQL 語法 LOAD DATA INFILE (Import) 的功能,更多關於 LOAD DATA 請參考 – https://benjr.tw/103012
[root@localhost ~]# mysql -u root -p Enter password: Welcome to the MariaDB monitor. Commands end with ; or \g. Your MariaDB connection id is 8 Server version: 5.5.60-MariaDB MariaDB Server Copyright (c) 2000, 2018, Oracle, MariaDB Corporation Ab and others. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. MariaDB [(none)]> USE dbtest; Database changed
先將資料庫的資料表 (table) 建立好,欄位則是依據 passwd 格式所定 Username , Password , UID , GID , IDInfo , HomeDir , Shell.
MariaDB [dbtest]> CREATE TABLE passwd ( Username CHAR(20) , Password CHAR(20) , UID INT(11) , GID INT(11) , IDInfo CHAR(20) , HomeDir CHAR(20) , Shell CHAR(20) ); Query OK, 0 rows affected (0.05 sec) MariaDB [dbtest]> DESCRIBE passwd; +----------+----------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +----------+----------+------+-----+---------+-------+ | Username | char(20) | YES | | NULL | | | Password | char(20) | YES | | NULL | | | UID | int(11) | YES | | NULL | | | GID | int(11) | YES | | NULL | | | IDInfo | char(20) | YES | | NULL | | | HomeDir | char(20) | YES | | NULL | | | Shell | char(20) | YES | | NULL | | +----------+----------+------+-----+---------+-------+ 7 rows in set (0.00 sec)
現在透過 SQL 語法 LOAD DATA INFILE 把 /etc/passwd 轉入到資料庫.
MariaDB [dbtest]> LOAD DATA INFILE '/etc/passwd' INTO TABLE dbtest.passwd FIELDS TERMINATED BY ':' ENCLOSED BY '"' LINES TERMINATED BY '\n'; Query OK, 46 rows affected, 10 warnings (0.00 sec) Records: 46 Deleted: 0 Skipped: 0 Warnings: 10
如果要指定欄位.
MariaDB [dbtest]> LOAD DATA INFILE '/etc/passwd' INTO TABLE dbtest.passwd FIELDS TERMINATED BY ':' ENCLOSED BY '"' LINES TERMINATED BY '\n' (Username , Password , UID , GID , IDInfo , HomeDir , Shell) ;
指令說明:
- LOAD DATA INFILE ‘/etc/passwd’
指定載入檔案位置,需注意權限問題 (Errcode: 2 – Error reading file) – https://dev.mysql.com/doc/refman/5.6/en/global-error-reference.html , 代表 mysql 使用者無法讀取該檔案,這時要注意存放檔案的目錄需要可以進入 (a+x) 的權限,檔案本身至少需要可供讀取 (a+r) 的權限. - INTO TABLE dbtest.passwd
指定資料要輸入的 資料庫.資料表 - FIELDS TERMINATED BY ‘:’
資料的分隔字元,以 /etc/passwd 來說 : 就是下一個欄位的資料. - ENCLOSED BY ‘”‘
指定包圍欄位資料的符號. - LINES TERMINATED BY ‘\n’
資料的換行字元,代表接下來的資料是新的一筆紀錄 (Record). - IGNORE 1 ROWS;
如果當你的資料第一行為欄位名稱,使用該參數即可忽略第一行的資料.
檢視一下,可以看到剛剛輸入的資料.
MariaDB [dbtest]> SELECT * FROM dbtest.passwd LIMIT 5; +----------+----------+------+------+--------+----------------+---------------+ | Username | Password | UID | GID | IDInfo | HomeDir | Shell | +----------+----------+------+------+--------+----------------+---------------+ | root | x | 0 | 0 | root | /root | /bin/bash | | bin | x | 1 | 1 | bin | /bin | /sbin/nologin | | daemon | x | 2 | 2 | daemon | /sbin | /sbin/nologin | | adm | x | 3 | 4 | adm | /var/adm | /sbin/nologin | | lp | x | 4 | 7 | lp | /var/spool/lpd | /sbin/nologin | +----------+----------+------+------+--------+----------------+---------------+ 5 rows in set (0.00 sec)
這指令一樣可以直接在 Linux command Line 或是 Bash script 來執行 (需注意 ENCLOSED BY ‘”‘ 這個地方,因為 Linux script 無法直接使用 ” 須以 \” 來表示).
[root@localhost ~]# mysql -u root -p111111 -e "LOAD DATA INFILE '/etc/passwd' INTO TABLE dbtest.passwd FIELDS TERMINATED BY ':' ENCLOSED BY '\"' LINES TERMINATED BY '\n';"
資料的確輸入了第二次.
[root@localhost ~]# mysql -u root -p111111 -e "SELECT * FROM dbtest.passwd WHERE username='root';" +----------+----------+------+------+--------+---------+-----------+ | Username | Password | UID | GID | IDInfo | HomeDir | Shell | +----------+----------+------+------+--------+---------+-----------+ | root | x | 0 | 0 | root | /root | /bin/bash | | root | x | 0 | 0 | root | /root | /bin/bash | +----------+----------+------+------+--------+---------+-----------+
如果不想用指令,可以用 PHPMyAdmin (支援多種格式如 OpenDocument Spreadsheet , Microsoft Excel 可另存為這種格式)- https://benjr.tw/97834 來轉換.