在酷學園看到有人問到排序的問題,有兩欄位.
http://phorum.study-area.org/index.php/topic,62396.msg315492.html#new
推測是讀取儀表獲得的數據,要進行後續處理.若這類的需求只是偶爾,其實用試算表就很方便.但若是常態性需求,用程式是比較方便,排序/分組這些是資料庫的強項.
問題在於處理文字檔的方法,一般人較少知道.思考時就被侷限了,另外MySQL的文件
或是很多網站上的例子,輸入檔及輸出檔的檔名都是手動輸入固定的,顯得就是手工
作業. MySQL 的LOAD DATA指令不能在Stored Procedure,也不能prepare,彈性
受到限制,但是我們可以利用Shell Script.以下就是連grant privilege都有說明的範例,我也一併發到酷學園供發問者參考.
MySQL 讀取及輸出文字檔
===============================
1. 基本環境建立與初始測試
1.1 用 roo登入 mysql,建立作業用的資料庫與使用者,並賦予相關權限.
root@[(none)]>create database sorter;
root@[(none)]>grant all on sorter.* to 'sorter'@'%' identified by 'sorter';
root@[(none)]>grant file on *.* to 'sorter'@'%';
1.2 在OS中建立目錄供MySQL存取,並建立預備輸入的文字檔
ps. 目錄必須設定讓mysql有權限讀寫,不一定是讓mysql當owner
# cd /
# mkdir myimpexp
# chown mysql:mysql myimpexp
# cd myimpexp
# vim raw-2010-09-02
# cat raw-2010-09-02
10.2 25.2
10.2 50.4
10.2 100.8
20.4 25.2
20.4 50.4
20.4 100.8
ps. txt file裡面用tab隔開
1.3 用sorter登入並建立table
sorter@[sorter]>create table sortforge (
col1 decimal(8,2),
col2 decimal(8,2)
);
1.4 輸入文字檔
sorter@[sorter]>LOAD DATA INFILE '/myimpexp/raw-2010-09-02' INTO TABLE sortforge
FIELDS TERMINATED BY '\t' LINES TERMINATED BY '\n';
sorter@[sorter]>select * from sortforge;
+-------+--------+
| col1 | col2 |
+-------+--------+
| 10.20 | 25.20 |
| 10.20 | 50.40 |
| 10.20 | 100.80 |
| 20.40 | 25.20 |
| 20.40 | 50.40 |
| 20.40 | 100.80 |
+-------+--------+
sorter@[sorter]>select *
-> from sortforge
-> order by col2,col1 desc;
+-------+--------+
| col1 | col2 |
+-------+--------+
| 20.40 | 25.20 |
| 10.20 | 25.20 |
| 20.40 | 50.40 |
| 10.20 | 50.40 |
| 20.40 | 100.80 |
| 10.20 | 100.80 |
+-------+--------+
1.5 排序後輸出為文字檔
sorter@[sorter]>SET @OutfileCmd := concat("SELECT col1,col2 FROM sortforge ORDER BY col2,col1 DESC INTO OUTFILE '/myimpexp/sort-", DATE_FORMAT(now(),'%Y-%m-%d_%H%i%s'), ".txt' FIELDS TERMINATED BY '\t' ESCAPED BY '\"' LINES TERMINATED BY '\n';");
Query OK, 0 rows affected (0.00 sec)
sorter@[sorter]>PREPARE statement FROM @OutfileCmd;
Query OK, 0 rows affected (0.00 sec)
Statement prepared
sorter@[sorter]>EXECUTE statement;
Query OK, 6 rows affected (0.00 sec)
# cat sort-2010-09-02_063030.txt
20.40 25.20
10.20 25.20
20.40 50.40
10.20 50.40
20.40 100.80
10.20 100.80
2. 使用Shell Script 呼叫 處理
將上面的操作方式改用Shell Script並配合使用date.如欲排序之原始檔為儀器等輸出,
可以將檔案改名為raw-yyyy-mm-dd格式,並可將Shell Script配合cron進行自動化處理.
程式碼如下:
-------- script start ----------
#!/bin/bash
# ---- Basic info set up ----
MYSQL_PATH="/opt/mysql554/bin/mysql"
MYSQL_USER="sorter"
MYSQL_PASS="sorter"
MYSQL_DB="sorter"
# ---- Chnage the basic info for your environment
# Query MySQL database function
query() {
echo "$1" | ${MYSQL_PATH} -s --user=${MYSQL_USER} --password=${MYSQL_PASS} ${MYSQL_DB}
}
today=$( date +%F )
in_file="'/myimpexp/raw-$today'"
moment=$( date +%F_%H%M%S )
out_file="'/myimpexp/sort-$moment'"
sql="truncate sortforge; LOAD DATA INFILE $in_file INTO TABLE sortforge FIELDS TERMINATED BY '\t' ESCAPED BY '\"' LINES TERMINATED BY '\n'; SELECT col1,col2 FROM sortforge ORDER BY col2,col1 DESC INTO OUTFILE $out_file FIELDS TERMINATED BY '\t' ESCAPED BY '\"' LINES TERMINATED BY '\n';"
RESULT=$(query "${sql}")
----------script end ----------------
# ./sh1.sh
# cat sort-2010-09-02_064313
20.40 25.20
10.20 25.20
20.40 50.40
10.20 50.40
20.40 100.80
10.20 100.80
得到排序後的輸出
沒有留言:
張貼留言