Thread: Unable to match same value in field.
Hello, I using postgresql 9.5.1 and I have problem to match value in one field. Both tables are text: =# \d list_cards_tbl; Column | Type | Modifiers -----------+---------+-------------------------------------------------------------- recid | integer | not null default nextval('list_cards_tbl_recid_seq'::regclass) imsi | text | Indexes: "imsi_list_cards_tbl" btree (imsi) =# \d list_newcard_tbl; Column | Type | Modifiers ------------+---------+--------------------------------------------------------------- recid | integer | not null default nextval('list_newcard_tbl_recid_seq'::regclass) serial | text | imsi | text | Indexes: "list_newcard_tbl_pkey" PRIMARY KEY, btree (recid) "list_newcard_ser_idx" btree (serial) =# select imsi, md5(imsi), bit_length(imsi) from list_newcards_tbl where imsi = '284110000123315'; imsi | md5 | bit_length -----------------+----------------------------------+------------ 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 (1 row) So far so good, value of table list_newcard_tbl is fine, problem is in table list_cards_tbl =# select imsi from list_cards_tbl where imsi = '284110000123315'; imsi ------ (0 rows) No value, lets change to LIKE =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi like '284110000123315%'; imsi | md5 | bit_length -----------------+----------------------------------+------------ 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 (1 row) Both have the same MD5 sum, also bit length. With EXPLAIN: =# explain analyse select imsi from list_cards_tbl where imsi = '284110000123315'; QUERY PLAN -------------------------------------------------------------------------------------------------------------------------------------- Index Only Scan using imsi_list_card_tbl on list_cards_tbl (cost=0.28..4.30 rows=1 width=16) (actual time=0.021..0.021 rows=0 loops=1) Index Cond: (imsi = '284110000123315'::text) Heap Fetches: 0 Planning time: 0.080 ms Execution time: 0.045 ms (5 rows) I see only index scan, so I do: =# reindex table list_cards_tbl; REINDEX =# vacuum list_cards_tbl; VACUUM =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi = '284110000123315'; imsi | md5 | bit_length ------+-----+------------ (0 rows) Still cant find value. Some settings: enable_bitmapscan | on | Enables the planner's use of bitmap-scan plans. enable_hashagg | on | Enables the planner's use of hashed aggregation plans. enable_hashjoin | on | Enables the planner's use of hash join plans. enable_indexonlyscan | on | Enables the planner's use of index-only-scan plans. enable_indexscan | on | Enables the planner's use of index-scan plans. enable_material | on | Enables the planner's use of materialization. enable_mergejoin | on | Enables the planner's use of merge join plans. enable_nestloop | on | Enables the planner's use of nested-loop join plans. enable_seqscan | on | Enables the planner's use of sequential-scan plans. enable_sort | on | Enables the planner's use of explicit sort steps. enable_tidscan | on | Enables the planner's use of TID scan plans. client_encoding | UTF8 | Sets the client's character set encoding. lc_collate | bg_BG.utf8 | Shows the collation order locale. lc_ctype | bg_BG.utf8 | Shows the character classification and case conversion locale. lc_messages | bg_BG.utf8 | Sets the language in which messages are displayed. lc_monetary | bg_BG.utf8 | Sets the locale for formatting monetary amounts. lc_numeric | bg_BG.utf8 | Sets the locale for formatting numbers. lc_time | bg_BG.utf8 | Sets the locale for formatting date and time values. server_encoding | UTF8 | Sets the server (database) character set encoding. server_version | 9.5.1 | Shows the server version. server_version_num | 90501 | Shows the server version as an integer. Can some one point me what can be the problem with this value and how to resolve it ? I think probably index problem but I reindex that table and problem is not resolved or some broken utf8 char but md5 and bit_length should not to be equal. Regards, HS
On Thu, Mar 10, 2016 at 11:09:00AM +0200, Condor wrote: > Can some one point me what can be the problem with this value and how to > resolve it ? I think probably index problem but I reindex that table and > problem is not resolved For the fun of it try dropping all indexes on the table and rerun the query. Karsten -- GPG key ID E4071346 @ eu.pool.sks-keyservers.net E167 67FD A291 2BEA 73BD 4537 78B9 A9F9 E407 1346
On 03/10/2016 01:09 AM, Condor wrote: > > Hello, > > I using postgresql 9.5.1 and I have problem to match value in one field. > Both tables are text: > > =# \d list_cards_tbl; > > Column | Type | Modifiers > -----------+---------+-------------------------------------------------------------- > > recid | integer | not null default > nextval('list_cards_tbl_recid_seq'::regclass) > imsi | text | > Indexes: > "imsi_list_cards_tbl" btree (imsi) > > > =# \d list_newcard_tbl; > Column | Type | Modifiers > ------------+---------+--------------------------------------------------------------- > > recid | integer | not null default > nextval('list_newcard_tbl_recid_seq'::regclass) > serial | text | > imsi | text | > Indexes: > "list_newcard_tbl_pkey" PRIMARY KEY, btree (recid) > "list_newcard_ser_idx" btree (serial) > > > > =# select imsi, md5(imsi), bit_length(imsi) from list_newcards_tbl where > imsi = '284110000123315'; > imsi | md5 | bit_length > -----------------+----------------------------------+------------ > 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 > (1 row) > > > > So far so good, value of table list_newcard_tbl is fine, problem is in > table list_cards_tbl > > =# select imsi from list_cards_tbl where imsi = '284110000123315'; > imsi > ------ > (0 rows) > > No value, lets change to LIKE > > =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where > imsi like '284110000123315%'; > imsi | md5 | bit_length > -----------------+----------------------------------+------------ > 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 > (1 row) > > > Both have the same MD5 sum, also bit length. > > With EXPLAIN: > > =# explain analyse select imsi from list_cards_tbl where imsi = > '284110000123315'; > QUERY PLAN > -------------------------------------------------------------------------------------------------------------------------------------- > > Index Only Scan using imsi_list_card_tbl on list_cards_tbl > (cost=0.28..4.30 rows=1 width=16) (actual time=0.021..0.021 rows=0 loops=1) > Index Cond: (imsi = '284110000123315'::text) > Heap Fetches: 0 > Planning time: 0.080 ms > Execution time: 0.045 ms > (5 rows) > > I see only index scan, so I do: > > =# reindex table list_cards_tbl; > REINDEX > =# vacuum list_cards_tbl; > VACUUM > =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where > imsi = '284110000123315'; > imsi | md5 | bit_length > ------+-----+------------ > (0 rows) > > > Still cant find value. > So is the above the only value that is hidden? What happens if for a session you do?: SET enable_indexonlyscan=OFF; Basically a variation of Karsten's idea Is the same process populating both tables? Where is the data coming from? Lastly, what happens if you populate the field in list_cards_tbl with the data from list_newcards_tbl? -- Adrian Klaver adrian.klaver@aklaver.com
On 10-03-2016 15:37, Adrian Klaver wrote: > On 03/10/2016 01:09 AM, Condor wrote: >> >> Hello, >> >> I using postgresql 9.5.1 and I have problem to match value in one >> field. >> Both tables are text: >> >> =# \d list_cards_tbl; >> >> Column | Type | Modifiers >> -----------+---------+-------------------------------------------------------------- >> >> recid | integer | not null default >> nextval('list_cards_tbl_recid_seq'::regclass) >> imsi | text | >> Indexes: >> "imsi_list_cards_tbl" btree (imsi) >> >> >> =# \d list_newcard_tbl; >> Column | Type | Modifiers >> ------------+---------+--------------------------------------------------------------- >> >> recid | integer | not null default >> nextval('list_newcard_tbl_recid_seq'::regclass) >> serial | text | >> imsi | text | >> Indexes: >> "list_newcard_tbl_pkey" PRIMARY KEY, btree (recid) >> "list_newcard_ser_idx" btree (serial) >> >> >> >> =# select imsi, md5(imsi), bit_length(imsi) from list_newcards_tbl >> where >> imsi = '284110000123315'; >> imsi | md5 | bit_length >> -----------------+----------------------------------+------------ >> 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 >> (1 row) >> >> >> >> So far so good, value of table list_newcard_tbl is fine, problem is in >> table list_cards_tbl >> >> =# select imsi from list_cards_tbl where imsi = '284110000123315'; >> imsi >> ------ >> (0 rows) >> >> No value, lets change to LIKE >> >> =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where >> imsi like '284110000123315%'; >> imsi | md5 | bit_length >> -----------------+----------------------------------+------------ >> 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 >> (1 row) >> >> >> Both have the same MD5 sum, also bit length. >> >> With EXPLAIN: >> >> =# explain analyse select imsi from list_cards_tbl where imsi = >> '284110000123315'; >> QUERY >> PLAN >> -------------------------------------------------------------------------------------------------------------------------------------- >> >> Index Only Scan using imsi_list_card_tbl on list_cards_tbl >> (cost=0.28..4.30 rows=1 width=16) (actual time=0.021..0.021 rows=0 >> loops=1) >> Index Cond: (imsi = '284110000123315'::text) >> Heap Fetches: 0 >> Planning time: 0.080 ms >> Execution time: 0.045 ms >> (5 rows) >> >> I see only index scan, so I do: >> >> =# reindex table list_cards_tbl; >> REINDEX >> =# vacuum list_cards_tbl; >> VACUUM >> =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where >> imsi = '284110000123315'; >> imsi | md5 | bit_length >> ------+-----+------------ >> (0 rows) >> >> >> Still cant find value. >> > > So is the above the only value that is hidden? > > What happens if for a session you do?: > > SET enable_indexonlyscan=OFF; > > Basically a variation of Karsten's idea > > Is the same process populating both tables? > > Where is the data coming from? > > Lastly, what happens if you populate the field in list_cards_tbl with > the data from list_newcards_tbl? > > > -- > Adrian Klaver > adrian.klaver@aklaver.com =# SET enable_indexonlyscan=OFF; SET =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi = '284110000123315'; imsi | md5 | bit_length ------+-----+------------ (0 rows) =# explain analyse select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi = '284110000123315'; QUERY PLAN --------------------------------------------------------------------------------------------------------------------------------- Index Scan using imsi_list_cards_tbl on list_cards_tbl (cost=0.28..8.30 rows=1 width=16) (actual time=0.015..0.015 rows=0 loops=1) Index Cond: (imsi = '284110000123315'::text) Planning time: 0.106 ms Execution time: 0.040 ms (4 rows) Same result. =# SET enable_indexscan = off; SET =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi = '284110000123315'; imsi | md5 | bit_length ------+-----+------------ (0 rows) =# explain analyse select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi = '284110000123315'; QUERY PLAN -------------------------------------------------------------------------------------------------------------------------- Bitmap Heap Scan on list_cards_tbl (cost=4.29..8.31 rows=1 width=16) (actual time=0.016..0.016 rows=0 loops=1) Recheck Cond: (imsi = '284110000123315'::text) -> Bitmap Index Scan on imsi_list_cards_tbl (cost=0.00..4.29 rows=1 width=0) (actual time=0.015..0.015 rows=0 loops=1) Index Cond: (imsi = '284110000123315'::text) Planning time: 0.109 ms Execution time: 0.046 ms (6 rows) Finally. =# SET enable_bitmapscan = off SET =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi = '284110000123315'; imsi | md5 | bit_length -----------------+----------------------------------+------------ 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 (1 row) =# explain analyse select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi = '284110000123315'; QUERY PLAN -------------------------------------------------------------------------------------------------------- Seq Scan on list_cards_tbl (cost=0.00..78.08 rows=1 width=16) (actual time=0.053..0.502 rows=1 loops=1) Filter: (imsi = '284110000123315'::text) Rows Removed by Filter: 2485 Planning time: 0.127 ms Execution time: 0.533 ms (5 rows) I will drop index and will create them again but after rebuild I think if there are mistakes after rebuild they should be fixed ? Process that populate them isnt the same but data is coming from database not from user input filed. Any ideas ? HS
On 03/11/2016 12:19 AM, Condor wrote: > On 10-03-2016 15:37, Adrian Klaver wrote: >> On 03/10/2016 01:09 AM, Condor wrote: >>> >>> Hello, >>> >>> I using postgresql 9.5.1 and I have problem to match value in one field. >>> Both tables are text: >>> >>> =# \d list_cards_tbl; >>> >>> Column | Type | Modifiers >>> -----------+---------+-------------------------------------------------------------- >>> >>> >>> recid | integer | not null default >>> nextval('list_cards_tbl_recid_seq'::regclass) >>> imsi | text | >>> Indexes: >>> "imsi_list_cards_tbl" btree (imsi) >>> >>> >>> =# \d list_newcard_tbl; >>> Column | Type | Modifiers >>> ------------+---------+--------------------------------------------------------------- >>> >>> >>> recid | integer | not null default >>> nextval('list_newcard_tbl_recid_seq'::regclass) >>> serial | text | >>> imsi | text | >>> Indexes: >>> "list_newcard_tbl_pkey" PRIMARY KEY, btree (recid) >>> "list_newcard_ser_idx" btree (serial) >>> >>> >>> >>> =# select imsi, md5(imsi), bit_length(imsi) from list_newcards_tbl where >>> imsi = '284110000123315'; >>> imsi | md5 | bit_length >>> -----------------+----------------------------------+------------ >>> 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 >>> (1 row) >>> >>> >>> >>> So far so good, value of table list_newcard_tbl is fine, problem is in >>> table list_cards_tbl >>> >>> =# select imsi from list_cards_tbl where imsi = '284110000123315'; >>> imsi >>> ------ >>> (0 rows) >>> >>> No value, lets change to LIKE >>> >>> =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where >>> imsi like '284110000123315%'; >>> imsi | md5 | bit_length >>> -----------------+----------------------------------+------------ >>> 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 >>> (1 row) >>> >>> >>> Both have the same MD5 sum, also bit length. >>> >>> With EXPLAIN: >>> >>> =# explain analyse select imsi from list_cards_tbl where imsi = >>> '284110000123315'; >>> QUERY >>> PLAN >>> -------------------------------------------------------------------------------------------------------------------------------------- >>> >>> >>> Index Only Scan using imsi_list_card_tbl on list_cards_tbl >>> (cost=0.28..4.30 rows=1 width=16) (actual time=0.021..0.021 rows=0 >>> loops=1) >>> Index Cond: (imsi = '284110000123315'::text) >>> Heap Fetches: 0 >>> Planning time: 0.080 ms >>> Execution time: 0.045 ms >>> (5 rows) >>> >>> I see only index scan, so I do: >>> >>> =# reindex table list_cards_tbl; >>> REINDEX >>> =# vacuum list_cards_tbl; >>> VACUUM >>> =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where >>> imsi = '284110000123315'; >>> imsi | md5 | bit_length >>> ------+-----+------------ >>> (0 rows) >>> >>> >>> Still cant find value. >>> >> >> So is the above the only value that is hidden? >> >> What happens if for a session you do?: >> >> SET enable_indexonlyscan=OFF; >> >> Basically a variation of Karsten's idea >> >> Is the same process populating both tables? >> >> Where is the data coming from? >> >> Lastly, what happens if you populate the field in list_cards_tbl with >> the data from list_newcards_tbl? >> >> >> -- >> Adrian Klaver >> adrian.klaver@aklaver.com > > > =# SET enable_indexonlyscan=OFF; > SET > =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where > imsi = '284110000123315'; > imsi | md5 | bit_length > ------+-----+------------ > (0 rows) > > > =# explain analyse select imsi, md5(imsi), bit_length(imsi) from > list_cards_tbl where imsi = '284110000123315'; > QUERY PLAN > --------------------------------------------------------------------------------------------------------------------------------- > > Index Scan using imsi_list_cards_tbl on list_cards_tbl > (cost=0.28..8.30 rows=1 width=16) (actual time=0.015..0.015 rows=0 loops=1) > Index Cond: (imsi = '284110000123315'::text) > Planning time: 0.106 ms > Execution time: 0.040 ms > (4 rows) > > > Same result. > > =# SET enable_indexscan = off; > SET > =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where > imsi = '284110000123315'; > imsi | md5 | bit_length > ------+-----+------------ > (0 rows) > > =# explain analyse select imsi, md5(imsi), bit_length(imsi) from > list_cards_tbl where imsi = '284110000123315'; > QUERY PLAN > -------------------------------------------------------------------------------------------------------------------------- > > Bitmap Heap Scan on list_cards_tbl (cost=4.29..8.31 rows=1 width=16) > (actual time=0.016..0.016 rows=0 loops=1) > Recheck Cond: (imsi = '284110000123315'::text) > -> Bitmap Index Scan on imsi_list_cards_tbl (cost=0.00..4.29 > rows=1 width=0) (actual time=0.015..0.015 rows=0 loops=1) > Index Cond: (imsi = '284110000123315'::text) > Planning time: 0.109 ms > Execution time: 0.046 ms > (6 rows) > > > Finally. > > > =# SET enable_bitmapscan = off > SET > =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where > imsi = '284110000123315'; > imsi | md5 | bit_length > -----------------+----------------------------------+------------ > 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 > (1 row) > > =# explain analyse select imsi, md5(imsi), bit_length(imsi) from > list_cards_tbl where imsi = '284110000123315'; > QUERY PLAN > -------------------------------------------------------------------------------------------------------- > > Seq Scan on list_cards_tbl (cost=0.00..78.08 rows=1 width=16) (actual > time=0.053..0.502 rows=1 loops=1) > Filter: (imsi = '284110000123315'::text) > Rows Removed by Filter: 2485 > Planning time: 0.127 ms > Execution time: 0.533 ms > (5 rows) > > > > I will drop index and will create them again but after rebuild I think > if there are mistakes after rebuild they should be fixed ? Yes that seems to be confirmed here: http://www.postgresql.org/docs/9.5/interactive/sql-reindex.html "REINDEX is similar to a drop and recreate of the index in that the index contents are rebuilt from scratch. ... " > Process that populate them isnt the same but data is coming from > database not from user input filed. > > Any ideas ? Not at the moment, but some unanswered questions: Is '284110000123315' the only value you are having issues with? What happens if you populate the field in list_cards_tbl with the data from list_newcards_tbl? > > > HS > > > -- Adrian Klaver adrian.klaver@aklaver.com
On 03/12/2016 08:11 AM, Condor wrote: Ccing list >>>> On 03/10/2016 01:09 AM, Condor wrote: >> >>> Process that populate them isnt the same but data is coming from >>> database not from user input filed. >>> >>> Any ideas ? >> >> Not at the moment, but some unanswered questions: >> >> Is '284110000123315' the only value you are having issues with? > > Yes, I now make some tests, it's seems that is the only value that make > troubles. > >> >> What happens if you populate the field in list_cards_tbl with >> the data from list_newcards_tbl? >> > > Everything is work. I update value with '284110000123315' manual (I just > select value with like and update it) and then rerun query and server > now found that data. > Yes, I can do that in first moment but was very strange for me why after > rebuild value still cant be find when md5 and bit_length prove that is > the same string. I do not know, that is why I Cced list, maybe someone else has an idea. > > Any way, problem solved. > > HS > > > > -- Adrian Klaver adrian.klaver@aklaver.com
On 2016-03-10 11:09:00 +0200, Condor wrote: > I using postgresql 9.5.1 and I have problem to match value in one field. > Both tables are text: [...] > =# select imsi from list_cards_tbl where imsi = '284110000123315'; > imsi > ------ > (0 rows) > > No value, lets change to LIKE > > =# select imsi, md5(imsi), bit_length(imsi) from list_cards_tbl where imsi > like '284110000123315%'; > imsi | md5 | bit_length > -----------------+----------------------------------+------------ > 284110000123315 | b438e984c97483bb942eaaed5c0147f3 | 120 > (1 row) That looks familiar. I think I've seen something similar recently. That was on 9.5beta1 (I haven't gotten around to upgrade to 9.5.1 yet). > =# reindex table list_cards_tbl; > REINDEX [...] > Still cant find value. Dropping and recreating the index helped in my case. Still, I find it worrying if a value which obviously is in the table can't be found using the index. hp -- _ | Peter J. Holzer | I want to forget all about both belts and |_|_) | | suspenders; instead, I want to buy pants | | | hjp@hjp.at | that actually fit. __/ | http://www.hjp.at/ | -- http://noncombatant.org/