Uploaded image for project: 'MariaDB Server'
  1. MariaDB Server
  2. MDEV-38240

Selectivity sampling not performed when the table has no indexed conditions

    XMLWordPrintable

Details

    • Bug
    • Status: In Progress (View Workflow)
    • Major
    • Resolution: Unresolved
    • 11.4
    • 11.4
    • Optimizer
    • None

    Description

      (discovered this while looking at MDEV-35280)

      Let's try to use Selectivity Sampling feature (optimizer_use_condition_selectivity=5).

      create table t1 (a varchar(100), b int); 
      insert into t1 select seq, seq from seq_1_to_10000;
      # No need for ANALYZE TABLE.
      set optimizer_use_condition_selectivity=5;
      

      explain extended 
      select * from t1 where a like '%99%';
      +------+-------------+-------+------+---------------+------+---------+------+-------+----------+-------------+
      | id   | select_type | table | type | possible_keys | key  | key_len | ref  | rows  | filtered | Extra       |
      +------+-------------+-------+------+---------------+------+---------+------+-------+----------+-------------+
      |    1 | SIMPLE      | t1    | ALL  | NULL          | NULL | NULL    | NULL | 10000 |   100.00 | Using where |
      +------+-------------+-------+------+---------------+------+---------+------+-------+----------+-------------+
      

      filtered=100, it didn't work?
      Let's add an irrelevant condition on an indexed column (EDIT: indexed column is not required. We just need a Sargable condition on a column in the table.)

      (range optimizer is able to infer that b is null or b is not null doesn't produce any ranges):

      explain extended 
      select * from t1 where a like '%99%' and (b is null or b is not null);
      +------+-------------+-------+------+---------------+------+---------+------+-------+----------+-------------+
      | id   | select_type | table | type | possible_keys | key  | key_len | ref  | rows  | filtered | Extra       |
      +------+-------------+-------+------+---------------+------+---------+------+-------+----------+-------------+
      |    1 | SIMPLE      | t1    | ALL  | NULL          | NULL | NULL    | NULL | 10000 |     1.00 | Using where |
      +------+-------------+-------+------+---------------+------+---------+------+-------+----------+-------------+
      

      Now, filtered=1%.

      Optimizer Trace shows this:

                  "rows_estimation": [
                    {
                      "selectivity_for_indexes": [],
                      "selectivity_for_columns": [],
                      "cond_selectivity": 0.01
                    },
                    {
                      "table": "t1",
                      "table_scan": {
                        "rows": 10330,
                        "read_cost": 1.3846,
                        "read_and_compare_cost": 1.71516
                      }
                    }
                  ]
      

      Doesn't say explicitly it's from sampling, but selectivity_for_indexes and selectivity_for_columns are empty...

      Attachments

        1. Q2.txt
          3 kB
        2. Q2-CS5.txt
          3 kB
        3. Q2-CS5-with-patch.txt
          3 kB
        4. Q2-json.txt
          37 kB
        5. Q2-json-CS5.txt
          38 kB
        6. Q2-json-CS5-with-patch.txt
          38 kB
        7. Q9.txt
          3 kB
        8. Q9-CS5.txt
          3 kB
        9. Q9-CS5-with-patch.txt
          3 kB
        10. Q9-json.txt
          23 kB
        11. Q9-json-CS5.txt
          23 kB
        12. Q9-json-CS5-with-patch.txt
          22 kB

        Issue Links

          Activity

            People

              psergei Sergei Petrunia
              psergei Sergei Petrunia
              Votes:
              0 Vote for this issue
              Watchers:
              2 Start watching this issue

              Dates

                Created:
                Updated:

                Git Integration

                  Error rendering 'com.xiplink.jira.git.jira_git_plugin:git-issue-webpanel'. Please contact your Jira administrators.