小夥伴想精準查詢自己想看的MySQL文章?喏 → MySQL江湖路專欄目錄 | 點選這裡
前幾篇文章給大家介紹了MySQL中的替換函數(Replace)、切分函數(SubString),今天我們一起來看看MySQL專業拼接「字串」的函數:concat。老規矩,有好的建議和想法,記得寫到評論中,等我上班摸魚時,跟大家一起吃瓜~
concat 函數一般用在SELECT 查詢語法中,用於修改返回欄位內容,例如有張LOL英雄資訊表如下
mysql> select * from `LOL`;
+----+---------------+--------------+-------+
| id | hero_title | hero_name | price |
+----+---------------+--------------+-------+
| 1 | D刀鋒之影 | 泰隆 | 6300 |
| 2 | X迅捷斥候 | 提莫 | 6300 |
| 3 | G光輝女郎 | 拉克絲 | 1350 |
| 4 | F發條魔靈 | 奧莉安娜 | 6300 |
| 5 | Z至高之拳 | 李青 | 6300 |
| 6 | W無極劍聖 | 易 | 450 |
| 7 | J疾風劍豪 | 亞索 | 450 |
+----+---------------+--------------+-------+
7 rows in set (0.00 sec)
我需要返回一列:英雄稱號 - 英雄名稱 的資料,這是就用到了concat函數,如下:
SELECT CONCAT(hero_title,' - ',hero_name) as full_name, price from `LOL`;
mysql> SELECT CONCAT(hero_title,' - ',hero_name) as full_name, price from `LOL`;
+------------------------------+-------+
| full_name | price |
+------------------------------+-------+
| D刀鋒之影 - 泰隆 | 6300 |
| X迅捷斥候 - 提莫 | 6300 |
| G光輝女郎 - 拉克絲 | 1350 |
| F發條魔靈 - 奧莉安娜 | 6300 |
| Z至高之拳 - 李青 | 6300 |
| W無極劍聖 - 易 | 450 |
| J疾風劍豪 - 亞索 | 450 |
+------------------------------+-------+
7 rows in set (0.00 sec)
如果拼接的引數中有NULL,則返回NULL;如下:
SELECT CONCAT(hero_title,NULL,hero_name) as full_name, price from `LOL`;
mysql> SELECT CONCAT(hero_title,'NULL',hero_name) as full_name, price from `LOL`;
+-------------------------------+-------+
| full_name | price |
+-------------------------------+-------+
| D刀鋒之影NULL泰隆 | 6300 |
| X迅捷斥候NULL提莫 | 6300 |
| G光輝女郎NULL拉克絲 | 1350 |
| F發條魔靈NULL奧莉安娜 | 6300 |
| Z至高之拳NULL李青 | 6300 |
| W無極劍聖NULL易 | 450 |
| J疾風劍豪NULL亞索 | 450 |
+-------------------------------+-------+
7 rows in set (0.00 sec)
不好意思,上面是我弟弟寫的,正確的如下:
mysql> SELECT CONCAT(hero_title,NULL,hero_name) as full_name, price from `LOL`;
+-----------+-------+
| full_name | price |
+-----------+-------+
| NULL | 6300 |
| NULL | 6300 |
| NULL | 1350 |
| NULL | 6300 |
| NULL | 6300 |
| NULL | 450 |
| NULL | 450 |
+-----------+-------+
7 rows in set (0.00 sec)
CONCAT_WS() 函數全稱: CONCAT With Separator ,是CONCAT()的特殊形式。第一個引數(separator)是其它引數的分隔符。分隔符的位置在要連線的兩個字串之間。分隔符可以是一個字串,也可以是其它欄位引數。
需要注意的是:
如果分隔符為 NULL,則結果為 NULL;但如果分隔符後面的引數為NULL,只會被直接忽略掉,而不會導致結果為NULL。
好了,我們依舊用上面的LOL表,連線各欄位,以逗號分隔:
select concat_ws(',',hero_title,hero_name,price) as full_name, price from `LOL`;
mysql> select concat_ws(',',hero_title,hero_name,price) as full_name, price from `LOL`;
+---------------------------------+-------+
| full_name | price |
+---------------------------------+-------+
| D刀鋒之影,泰隆,6300 | 6300 |
| X迅捷斥候,提莫,6300 | 6300 |
| G光輝女郎,拉克絲,1350 | 1350 |
| F發條魔靈,奧莉安娜,6300 | 6300 |
| Z至高之拳,李青,6300 | 6300 |
| W無極劍聖,易,450 | 450 |
| J疾風劍豪,亞索,450 | 450 |
+---------------------------------+-------+
7 rows in set (0.00 sec)
分隔符後的拼接引數為NULL時,直接忽略,不會影響整體結果,如下:
select concat_ws(',',hero_title,NULL,hero_name) as full_name, price from `LOL`;
mysql> select concat_ws(',',hero_title,NULL,hero_name) as full_name, price from `LOL`;
+----------------------------+-------+
| full_name | price |
+----------------------------+-------+
| D刀鋒之影,泰隆 | 6300 |
| X迅捷斥候,提莫 | 6300 |
| G光輝女郎,拉克絲 | 1350 |
| F發條魔靈,奧莉安娜 | 6300 |
| Z至高之拳,李青 | 6300 |
| W無極劍聖,易 | 450 |
| J疾風劍豪,亞索 | 450 |
+----------------------------+-------+
7 rows in set (0.00 sec)
分隔符為NULL時,結果返回NULL,如下:
select concat_ws(NULL,hero_title,hero_name,price) as full_name, price from `LOL`;
mysql> select concat_ws(NULL,hero_title,hero_name,price) as full_name, price from `LOL`;
+-----------+-------+
| full_name | price |
+-----------+-------+
| NULL | 6300 |
| NULL | 6300 |
| NULL | 1350 |
| NULL | 6300 |
| NULL | 6300 |
| NULL | 450 |
| NULL | 450 |
+-----------+-------+
7 rows in set (0.00 sec)
group_concat ( [DISTINCT] 欄位名 [order by 排序欄位 ASC/DESC] [Separator ‘分隔符’] )
group_concat函數通常用於有group by的查詢語句,group_concat一般包含在查詢返回結果欄位中。
是不是group_concat函數的公式看著還挺複雜的?我們一起看看,上方公式中 [] 括號是可選項,表示可用可不用;
[DISTINCT]
:對拼接的引數支援去重功能;[Order by]
:拼接的引數支援排序功能;[Separator]
:這個你很熟悉了,支援自定義’分隔符’,如不設定預設為無分隔符;好了,下面讓我們來進入開心的測試環節吧~ 還是用這張LOL表,別問為什麼。或許這就是青春吧!還記的那年通宵五排,大龍團的時候網咖停電了…
又跑題了。。不好意思。
mysql> select * from `LOL`;
+----+---------------+--------------+-------+
| id | hero_title | hero_name | price |
+----+---------------+--------------+-------+
| 1 | D刀鋒之影 | 泰隆 | 6300 |
| 2 | X迅捷斥候 | 提莫 | 6300 |
| 3 | G光輝女郎 | 拉克絲 | 1350 |
| 4 | F發條魔靈 | 奧莉安娜 | 6300 |
| 5 | Z至高之拳 | 李青 | 6300 |
| 6 | W無極劍聖 | 易 | 450 |
| 7 | J疾風劍豪 | 亞索 | 450 |
+----+---------------+--------------+-------+
7 rows in set (0.00 sec)
舉個場景,我們要區分出各個價格段的英雄來,如果不用group_concat的話,或許只能用order by區分了。
select * from `LOL` order by price desc;
mysql> select * from `LOL` order by price desc;
+----+---------------+--------------+-------+
| id | hero_title | hero_name | price |
+----+---------------+--------------+-------+
| 1 | D刀鋒之影 | 泰隆 | 6300 |
| 2 | X迅捷斥候 | 提莫 | 6300 |
| 4 | F發條魔靈 | 奧莉安娜 | 6300 |
| 5 | Z至高之拳 | 李青 | 6300 |
| 3 | G光輝女郎 | 拉克絲 | 1350 |
| 6 | W無極劍聖 | 易 | 450 |
| 7 | J疾風劍豪 | 亞索 | 450 |
+----+---------------+--------------+-------+
7 rows in set (0.00 sec)
但是這樣很不直觀啊,我想一行都看到,怎麼辦?
SELECT GROUP_CONCAT(hero_title,' - ',hero_name Separator ',' ) as full_name, price
from `LOL` GROUP BY price ORDER BY price desc;
這時GROUP_CONCAT函數就輕鬆的幫你解決了這個問題。看,舒服不~
註釋:這裡我是拼接了(hero_title,’ - ‘,hero_name)這三個引數,分隔符設為:’,’,根據價格來分組,根據價格來排的序。效果如下
mysql> SELECT GROUP_CONCAT(hero_title,' - ',hero_name Separator ',' ) as full_name, price from `LOL` GROUP BY price ORDER BY price desc;
+------------------------------------------------------------------------+-------+
| full_name | price |
+------------------------------------------------------------------------+-------+
| D刀鋒之影 - 泰隆,X迅捷斥候 - 提莫,F發條魔靈 - 奧莉安娜,Z至高之拳 - 李青 | 6300 |
| G光輝女郎 - 拉克絲 | 1350 |
| W無極劍聖 - 易,J疾風劍豪 - 亞索 | 450 |
+------------------------------------------------------------------------+-------+
3 rows in set (0.00 sec)
如果按價格(price)從小到大排序,只需控制外層ORDER BY即可,如下:
SELECT GROUP_CONCAT(hero_title,' - ',hero_name Separator ',' ) as full_name, price
from `LOL` GROUP BY price ORDER BY price asc;
mysql> SELECT GROUP_CONCAT(hero_title,' - ',hero_name Separator ',' ) as full_name, price from `LOL` GROUP BY price ORDER BY price asc;
+-------------------------------------------------------------------------+-------+
| full_name | price |
+-------------------------------------------------------------------------+-------+
| W無極劍聖 - 易,J疾風劍豪 - 亞索 | 450 |
| G光輝女郎 - 拉克絲 | 1350 |
| D刀鋒之影 - 泰隆,X迅捷斥候 - 提莫,F發條魔靈 - 奧莉安娜,Z至高之拳 - 李青 | 6300 |
+-------------------------------------------------------------------------+-------+
3 rows in set (0.00 sec)
那麼GROUP_CONCAT函數中的order by 排序怎麼用?是用在了拼接欄位的排序上,如根據hero_title進行排序拼接,如下:
SELECT GROUP_CONCAT(hero_title,' - ',hero_name order by hero_title Separator ',' ) as full_name, price from `LOL` GROUP BY price ORDER BY price asc;
mysql> SELECT GROUP_CONCAT(hero_title,' - ',hero_name order by hero_title Separator ',' ) as full_name, price from `LOL` GROUP BY price ORDER BY price asc;
+-------------------------------------------------------------------------+-------+
| full_name | price |
+-------------------------------------------------------------------------+-------+
| J疾風劍豪 - 亞索,W無極劍聖 - 易 | 450 |
| G光輝女郎 - 拉克絲 | 1350 |
| D刀鋒之影 - 泰隆,F發條魔靈 - 奧莉安娜,X迅捷斥候 - 提莫,Z至高之拳 - 李青 | 6300 |
+-------------------------------------------------------------------------+-------+
3 rows in set (0.00 sec)
好了,可以看出,MySQL中的concat拼接函數還是很好用的,希望你在有類似的需求或困惑時,想到它!或者能找到這篇部落格,幫到你!
我是陳哈哈,一個MySQL渣渣,讓我們一起每天進步一點點。