List one row as two rows based on multiple values in one column

I'm a SQL novice. Wondering if following example is possible.

Table1 has two columns: Name, FavoriteColors

Row 1: Name=Joe; FavoriteColor=Red,Blue

I need a SQL command to generate:

Name Favorite Color


Joe Red
Joe Blue

Is this possible? If so, how?
Thank you!

Will it always be comma delimited FavoriteColor column?

I would recommend a different design

hi

please see the following links !!!! hope these help !!

https://database.guide/how-to-convert-a-comma-separated-list-into-rows-in-sql-server/

hi

One Way ...

we can do this with the help of a ... function
i am using function created by JEFF Moden !!! :slight_smile: :slight_smile: ....

please click arrow to the left for DROP Create Data
drop table #data 
go 


create table #data 
(
name varchar(100),
fav_color varchar(100)
)
go 

insert into #data select 'Joe','red,blue'
insert into #data select 'sam','green,yellow,purple'
go

image

please click arrow to the left for FUNCTION ...
DROP FUNCTION [dbo].[DelimitedSplit8K]
go 

CREATE FUNCTION [dbo].[DelimitedSplit8K]
        (@pString VARCHAR(8000), @pDelimiter CHAR(1))
RETURNS TABLE WITH SCHEMABINDING AS
 RETURN
--===== "Inline" CTE Driven "Tally Table" produces values from 0 up to 10,000...
     -- enough to cover NVARCHAR(4000)
  WITH E1(N) AS (
                 SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL 
                 SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL 
                 SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1
                ),                          --10E+1 or 10 rows
       E2(N) AS (SELECT 1 FROM E1 a, E1 b), --10E+2 or 100 rows
       E4(N) AS (SELECT 1 FROM E2 a, E2 b), --10E+4 or 10,000 rows max
 cteTally(N) AS (--==== This provides the "base" CTE and limits the number of rows right up front
                     -- for both a performance gain and prevention of accidental "overruns"
                 SELECT TOP (ISNULL(DATALENGTH(@pString),0)) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4
                ),
cteStart(N1) AS (--==== This returns N+1 (starting position of each "element" just once for each delimiter)
                 SELECT 1 UNION ALL
                 SELECT t.N+1 FROM cteTally t WHERE SUBSTRING(@pString,t.N,1) = @pDelimiter
                ),
cteLen(N1,L1) AS(--==== Return start and length (for use in substring)
                 SELECT s.N1,
                        ISNULL(NULLIF(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000)
                   FROM cteStart s
                )
--===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.
 SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY l.N1),
        Item       = SUBSTRING(@pString, l.N1, l.L1)
   FROM cteLen l
;
GO
select 
        a.name
	  , b.Item  
from 
   #data a 
     cross apply 
   [dbo].[DelimitedSplit8K](fav_color,',') b
go 

image