www.webdeveloper.com
Results 1 to 3 of 3

Thread: [RESOLVED] MySQL product multi filter

  1. #1
    Join Date
    Oct 2005
    Location
    UK
    Posts
    630

    resolved [RESOLVED] MySQL product multi filter

    I have the following 4 tables (simplified for example) for a product filter scenario each product. Each product can have multiple attributes which have multiple values (but only ever one assigned to a product.
    Code:
    CREATE TABLE `products` (
      `id` int(11) NOT NULL auto_increment,
      `name` varchar(150) NOT NULL,
    )
    
    CREATE TABLE `attributes` (
      `id` int(11) NOT NULL auto_increment,
      `name` varchar(20) character set latin1 NOT NULL
    )
    
    CREATE TABLE `attributes_entity` (
      `product_id` int(11) NOT NULL,
      `attribute_id` int(11) NOT NULL,
      `value_id` int(11) NOT NULL,
       FOREIGN KEY (`product_id`) REFERENCES `products` (`id`),
       FOREIGN KEY (`attribute_id`) REFERENCES `attributes` (`id`),
       FOREIGN KEY (`attribute_id`) REFERENCES `attributes` (`id`)
    )
    
    CREATE TABLE `attributes_values` (
      `id` int(11) NOT NULL auto_increment,
      `value` varchar(255) default NULL,
    )
    I want to be able to retrieve a result of all the products that match all the filter values (attributes) passed through.
    Code:
    SELECT
        `p`.`id`
       `p`.`name`, 
    FROM `products` `p
        INNER JOIN `attributes_entity` `ae` ON `p`.`id`=`ae`.`product_id`
        INNER JOIN `attributes` `a` ON `ae`.`attribute_id`=`a`.`id`
    WHERE (`a`.`name`='size' AND `av`.`value`='12mm')
        --this is where it currently creates an "IMPOSSIBLE WHERE"
        AND (`a`.`name`='color' AND `av`.`value`='red')
    It's easy to retrieve a product with a single WHERE cause because the inner joins create a single row relationship for each attributes. However as soon as you add an AND, and try to add a second attribute to filter by no single row meets both criteria but multiple (attribute) rows of the same `product` row will match all the criteria.

    Is this possible with a single query or will I have to look at sub/multiple queries?

  2. #2
    Join Date
    Oct 2005
    Location
    UK
    Posts
    630
    Updated code to add in the missing av.values join:

    Code:
    SELECT
        `p`.`id`,
        `p`.`name`
    FROM `attributes_entity` `ae`
        INNER JOIN `products` `p` ON `ae`.`product_id`=`p`.`id`
        INNER JOIN `attributes` `a` ON `ae`.`attribute_id`=`a`.`id`
        INNER JOIN `attributes_values` `av` ON `ae`.`value_id`=`av`.`id`
    WHERE (`a`.`perma_name`='size' AND `av`.`value`='12mm')
    AND (`a`.`perma_name`='color' AND `av`.`value`='red')
    If I use an OR for the 2nd condition I get half way there to the desired result:
    Code:
    SELECT
        `p`.`name`
    FROM `attributes_entity` `ae`
        INNER JOIN `products` `p` ON `ae`.`product_id`=`p`.`id`
        INNER JOIN `attributes` `a` ON `ae`.`attribute_id`=`a`.`id`
        INNER JOIN `attributes_values` `av` ON `ae`.`value_id`=`av`.`id`
    WHERE `p`.`delete`!='1'
    AND (`a`.`perma_name`='size' AND `av`.`value`='12mm')
    OR (`a`.`perma_name`='color' AND `av`.`value`='red')
    The 2nd query returns the following
    product 1 /* matching size=12mm */
    product 1 /* matching color=red */
    product 2 /* matching size=12mm */

    However I only want it to return results matching both/all of the conditions but at the same not creating an "IMPOSSIBLE WHERE"

  3. #3
    Join Date
    Oct 2005
    Location
    UK
    Posts
    630
    Resolved:
    Code:
    SELECT
        `p`.`name`
    FROM `attributes_entity` `ae`
        INNER JOIN `products` `p` ON `ae`.`product_id`=`p`.`id`
        INNER JOIN `attributes` `a` ON `ae`.`attribute_id`=`a`.`id`
        INNER JOIN `attributes_values` `av` ON `ae`.`value_id`=`av`.`id`
    WHERE `p`.`delete`!='1'
    AND (`a`.`perma_name`='size' AND `av`.`value`='12mm')
    OR (`a`.`perma_name`='color' AND `av`.`value`='red')
    GROUP BY `p`.`id` HAVING COUNT(`a`.`id`)=2

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Posting Permissions

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

"

"

X vBulletin 4.2.2 Debug Information

  • Page Generation 0.09727 seconds
  • Memory Usage 2,857KB
  • Queries Executed 15 (?)
More Information
Template Usage (33):
  • (1)SHOWTHREAD
  • (1)ad_footer_end
  • (1)ad_footer_start
  • (1)ad_global_above_footer
  • (1)ad_global_below_navbar
  • (1)ad_global_header1
  • (1)ad_global_header2
  • (1)ad_navbar_below
  • (1)ad_showthread_firstpost_sig
  • (1)ad_showthread_firstpost_start
  • (1)ad_thread_first_post_content
  • (1)ad_thread_last_post_content
  • (5)bbcode_code
  • (1)footer
  • (1)forumjump
  • (1)forumrules
  • (1)gobutton
  • (1)header
  • (1)headinclude
  • (1)headinclude_bottom
  • (3)memberaction_dropdown
  • (1)navbar
  • (4)navbar_link
  • (1)navbar_moderation
  • (1)navbar_noticebit
  • (1)navbar_tabs
  • (2)option
  • (3)postbit
  • (3)postbit_onlinestatus
  • (3)postbit_wrapper
  • (1)spacer_close
  • (1)spacer_open
  • (1)tagbit_wrapper 

Phrase Groups Available (6):
  • global
  • inlinemod
  • postbit
  • posting
  • reputationlevel
  • showthread
Included Files (26):
  • ./showthread.php
  • ./global.php
  • ./includes/class_bootstrap.php
  • ./includes/init.php
  • ./includes/class_core.php
  • ./includes/config.php
  • ./includes/functions.php
  • ./includes/functions_navigation.php
  • ./includes/class_friendly_url.php
  • ./includes/class_hook.php
  • ./includes/class_bootstrap_framework.php
  • ./vb/vb.php
  • ./vb/phrase.php
  • ./includes/functions_facebook.php
  • ./includes/functions_calendar.php
  • ./includes/functions_bigthree.php
  • ./includes/class_postbit.php
  • ./includes/class_bbcode.php
  • ./includes/functions_reputation.php
  • ./includes/functions_notice.php
  • ./packages/vbattach/attach.php
  • ./vb/types.php
  • ./vb/cache.php
  • ./vb/cache/db.php
  • ./vb/cache/observer/db.php
  • ./vb/cache/observer.php 

Hooks Called (71):
  • init_startup
  • friendlyurl_resolve_class
  • init_startup_session_setup_start
  • database_pre_fetch_array
  • database_post_fetch_array
  • init_startup_session_setup_complete
  • global_bootstrap_init_start
  • global_bootstrap_init_complete
  • cache_permissions
  • fetch_threadinfo_query
  • fetch_threadinfo
  • fetch_foruminfo
  • load_show_variables
  • load_forum_show_variables
  • global_state_check
  • global_bootstrap_complete
  • global_start
  • style_fetch
  • global_setup_complete
  • showthread_start
  • showthread_getinfo
  • strip_bbcode
  • friendlyurl_clean_fragment
  • friendlyurl_geturl
  • forumjump
  • cache_templates
  • cache_templates_process
  • template_register_var
  • template_render_output
  • fetch_template_start
  • fetch_template_complete
  • parse_templates
  • fetch_musername
  • notices_check_start
  • notices_noticebit
  • process_templates_complete
  • friendlyurl_redirect_canonical
  • showthread_post_start
  • showthread_query_postids
  • showthread_query
  • bbcode_fetch_tags
  • bbcode_create
  • showthread_postbit_create
  • postbit_factory
  • postbit_display_start
  • postbit_imicons
  • bbcode_parse_start
  • bbcode_parse_complete_precache
  • bbcode_parse_complete
  • postbit_display_complete
  • memberaction_dropdown
  • tag_fetchbit
  • tag_fetchbit_complete
  • forumrules
  • navbits
  • navbits_complete
  • build_navigation_data
  • build_navigation_array
  • check_navigation_permission
  • process_navigation_links_start
  • process_navigation_links_complete
  • set_navigation_menu_element
  • build_navigation_menudata
  • build_navigation_listdata
  • build_navigation_list
  • set_navigation_tab_main
  • set_navigation_tab_fallback
  • navigation_tab_complete
  • fb_like_button
  • showthread_complete
  • page_templates