数据库 
首页 > 数据库 > 浏览文章

MySQL将一个字段中以逗号分隔的取出来形成新的字段实现

(编辑:jimmy 日期: 2024/11/15 浏览:3 次 )

1例如:要把如图1的字段拆分图2

MySQL将一个字段中以逗号分隔的取出来形成新的字段实现

MySQL将一个字段中以逗号分隔的取出来形成新的字段实现

select account_id,
    substring_index(substring_index(a.related_shop_ids,','
    ,b.help_topic_id+1),',',-1) shopid
  from 
    sales_hang_account a
  join
    mysql.help_topic b
    on b.help_topic_id < (length(a.related_shop_ids) -   length(replace(a.related_shop_ids,',',''))+1) 
  order by a.account_id

2:然后和shops表进行连接查询取出我们需要的字段,我这里需要取出name

select s.`name` as shopname,a.account_id from shops s
inner JOIN (

select account_id,
    substring_index(substring_index(a.related_shop_ids,','
    ,b.help_topic_id+1),',',-1) shopid
  from 
    sales_hang_account a
  join
    mysql.help_topic b
    on b.help_topic_id < (length(a.related_shop_ids) -   length(replace(a.related_shop_ids,',',''))+1) 
  order by a.account_id)a on s.shop_id=a.shopid

MySQL将一个字段中以逗号分隔的取出来形成新的字段实现

3:将 account_id相同合并成一行,以逗号隔开

//这两个是网上的例子
select ID,group_concat(NAME) as NAME from table group by ID;

select ID,group_concat(NAME SEPARATOR ';') as NAME from a group by ID;
//借助上面两个参考
select account_id,GROUP_CONCAT(shopname SEPARATOR',')as shopname from (select s.`name` as shopname,a.account_id from shops s
inner JOIN (

select account_id,
    substring_index(substring_index(a.related_shop_ids,','
    ,b.help_topic_id+1),',',-1) shopid
  from 
    sales_hang_account a
  join
    mysql.help_topic b
    on b.help_topic_id < (length(a.related_shop_ids) -   length(replace(a.related_shop_ids,',',''))+1) 
  order by a.account_id)a on s.shop_id=a.shopid) a GROUP BY account_id

效果如下

MySQL将一个字段中以逗号分隔的取出来形成新的字段实现

第二种方法

select g.account_id,g.related_shop_ids,GROUP_CONCAT(s.name)as shopname from sales_hang_account g left join shops s on FIND_IN_SET(s.shop_id , g.related_shop_ids)
GROUP BY g.account_id

MySQL将一个字段中以逗号分隔的取出来形成新的字段实现

SqlServer

 [Product] -- 该字段存储格式为 7,8,9,11,10,12 ,数据类型为nvarchar
select id,ProductName=stuff((select ',' + product_chinaname from base_supplier_product where charindex(','+ltrim(productid)+',',','+ Product + ',') > 0 for xml path('') ), 1, 1, '')
 FROM base_Pre_sale_project

结果

MySQL将一个字段中以逗号分隔的取出来形成新的字段实现

上一篇:mysql 8.0.22 安装配置方法图文教程
下一篇:详解mysql 中的锁结构