SitePoint Sponsor

User Tag List

Results 1 to 4 of 4
  1. #1
    SitePoint Member
    Join Date
    Dec 2004
    Location
    Little Rock
    Posts
    24
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    List from pipe delimited MySQL field

    I am working on a real estate site that has 2 MySQL tables: Features and Listings. The Features table has 2 columns: ID and Description. Each row in Listings has a field that contains a pipe delimited set of numbers (3 | 14 | 26 ...) that correspond to the ID column in the Features table. How do I structure a query to generate a list of Features.Description for each row of the Listings table? In other words, each row in Listings has a set of features grouped together in a single field but identified by ID numbers. How do I print a list of the features descriptions for a particular row?

    BTW, data comes in the pipe delimited format from the local MLS... it's not my choice to structure it like that.

    I appreciate any help that can be offered... I'm a MySQL newbie

  2. #2
    SQL Consultant gold trophysilver trophybronze trophy
    r937's Avatar
    Join Date
    Jul 2002
    Location
    Toronto, Canada
    Posts
    39,269
    Mentioned
    60 Post(s)
    Tagged
    3 Thread(s)
    i see spaces around the pipes, so we'll strip them out with REPLACE
    Code:
    select Listings.ID
         , Listings.Name
         , Features.Description
      from Listings
    inner
      join Features
        on concat('|'
                 ,replace(Listings.Features,' ','')
                 ,'|')
      like concat('%|'
                 ,Features.Description
                 ,'|%')
    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL
    "giving out my real stuffs"

  3. #3
    SitePoint Member
    Join Date
    Dec 2004
    Location
    Little Rock
    Posts
    24
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)
    Quote Originally Posted by r937
    i see spaces around the pipes, so we'll strip them out with REPLACE
    Code:
    select Listings.ID
         , Listings.Name
         , Features.Description
      from Listings
    inner
      join Features
        on concat('|'
                 ,replace(Listings.Features,' ','')
                 ,'|')
      like concat('%|'
                 ,Features.Description
                 ,'|%')
    Thanks for your help! Would you mind explaining how the concat statements work? I tried looking it up in the MySQL documentation but it didn't make sense. BTW, I'm going to sign up for the SQL class you're teaching; it looks like exactly what I need!

  4. #4
    SQL Consultant gold trophysilver trophybronze trophy
    r937's Avatar
    Join Date
    Jul 2002
    Location
    Toronto, Canada
    Posts
    39,269
    Mentioned
    60 Post(s)
    Tagged
    3 Thread(s)
    let's say that Listings.Features is 3|5|12|13|15|25

    and let's say that Features.Description is 3

    then you have
    Code:
    inner
      join Features
        on '|3|5|12|13|15|25|' like '%|3|%'
    that's why you have to concatenate the pipes to the front and back of both strings, so that you'll catch the first or last item in the list
    rudy.ca | @rudydotca
    Buy my SitePoint book: Simply SQL
    "giving out my real stuffs"


Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •