db-derby-dev mailing list archives

Site index · List index
Message view « Date » · « Thread »
Top « Date » · « Thread »
From "Tony Brusseau (JIRA)" <j...@apache.org>
Subject [jira] [Commented] (DERBY-6045) Can't bulk load rows by primary key efficiently on tables with >256 rows
Date Fri, 18 Jan 2013 22:54:12 GMT

    [ https://issues.apache.org/jira/browse/DERBY-6045?page=com.atlassian.jira.plugin.system.issuetabpanels:comment-tabpanel&focusedCommentId=13557713#comment-13557713
] 

Tony Brusseau commented on DERBY-6045:
--------------------------------------

I just tried it with regular integers, starting from 1 and the only indexing being the primary
key. Still get the same issue. If I make a table with 64 rows, then it does fast b-tree scans
using the IN query. If the table has 256 or more rows, it does slow heap scans over every
row in the table when using the IN query. It looks like maybe there is a logic-po in the code.
Doing full table scans over small tables might be faster than multi-probing, but instead it
is doing it on large tables. This is just a wild guess.

Here is the SQL:

DROP TABLE VARIABLE_TERM;

CREATE TABLE VARIABLE_TERM
(
        term_id                  INTEGER NOT NULL,
        var_name              VARCHAR(1024) NOT NULL,
        var_type                SMALLINT NOT NULL,     
        kb_status              INTEGER NOT NULL        
);

ALTER TABLE variable_term ADD CONSTRAINT kb_variable_term_term_id_pk PRIMARY KEY (term_id);

INSERT INTO VARIABLE_TERM VALUES (1, '?var0', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (2, '?var1', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (3, '?var2', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (4, '?var3', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (5, '?var4', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (6, '?var5', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (7, '?var6', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (8, '?var7', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (9, '?var8', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (10, '?var9', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (11, '?var10', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (12, '?var11', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (13, '?var12', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (14, '?var13', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (15, '?var14', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (16, '?var15', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (17, '?var16', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (18, '?var17', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (19, '?var18', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (20, '?var19', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (21, '?var20', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (22, '?var21', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (23, '?var22', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (24, '?var23', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (25, '?var24', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (26, '?var25', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (27, '?var26', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (28, '?var27', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (29, '?var28', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (30, '?var29', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (31, '?var30', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (32, '?var31', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (33, '?var32', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (34, '?var33', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (35, '?var34', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (36, '?var35', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (37, '?var36', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (38, '?var37', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (39, '?var38', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (40, '?var39', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (41, '?var40', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (42, '?var41', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (43, '?var42', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (44, '?var43', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (45, '?var44', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (46, '?var45', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (47, '?var46', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (48, '?var47', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (49, '?var48', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (50, '?var49', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (51, '?var50', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (52, '?var51', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (53, '?var52', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (54, '?var53', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (55, '?var54', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (56, '?var55', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (57, '?var56', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (58, '?var57', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (59, '?var58', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (60, '?var59', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (61, '?var60', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (62, '?var61', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (63, '?var62', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (64, '?var63', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (65, '?var64', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (66, '?var65', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (67, '?var66', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (68, '?var67', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (69, '?var68', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (70, '?var69', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (71, '?var70', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (72, '?var71', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (73, '?var72', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (74, '?var73', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (75, '?var74', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (76, '?var75', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (77, '?var76', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (78, '?var77', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (79, '?var78', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (80, '?var79', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (81, '?var80', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (82, '?var81', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (83, '?var82', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (84, '?var83', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (85, '?var84', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (86, '?var85', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (87, '?var86', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (88, '?var87', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (89, '?var88', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (90, '?var89', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (91, '?var90', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (92, '?var91', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (93, '?var92', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (94, '?var93', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (95, '?var94', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (96, '?var95', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (97, '?var96', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (98, '?var97', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (99, '?var98', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (100, '?var99', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (101, '?var100', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (102, '?var101', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (103, '?var102', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (104, '?var103', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (105, '?var104', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (106, '?var105', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (107, '?var106', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (108, '?var107', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (109, '?var108', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (110, '?var109', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (111, '?var110', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (112, '?var111', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (113, '?var112', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (114, '?var113', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (115, '?var114', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (116, '?var115', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (117, '?var116', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (118, '?var117', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (119, '?var118', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (120, '?var119', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (121, '?var120', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (122, '?var121', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (123, '?var122', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (124, '?var123', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (125, '?var124', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (126, '?var125', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (127, '?var126', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (128, '?var127', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (129, '?var128', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (130, '?var129', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (131, '?var130', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (132, '?var131', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (133, '?var132', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (134, '?var133', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (135, '?var134', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (136, '?var135', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (137, '?var136', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (138, '?var137', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (139, '?var138', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (140, '?var139', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (141, '?var140', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (142, '?var141', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (143, '?var142', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (144, '?var143', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (145, '?var144', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (146, '?var145', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (147, '?var146', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (148, '?var147', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (149, '?var148', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (150, '?var149', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (151, '?var150', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (152, '?var151', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (153, '?var152', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (154, '?var153', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (155, '?var154', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (156, '?var155', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (157, '?var156', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (158, '?var157', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (159, '?var158', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (160, '?var159', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (161, '?var160', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (162, '?var161', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (163, '?var162', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (164, '?var163', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (165, '?var164', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (166, '?var165', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (167, '?var166', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (168, '?var167', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (169, '?var168', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (170, '?var169', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (171, '?var170', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (172, '?var171', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (173, '?var172', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (174, '?var173', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (175, '?var174', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (176, '?var175', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (177, '?var176', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (178, '?var177', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (179, '?var178', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (180, '?var179', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (181, '?var180', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (182, '?var181', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (183, '?var182', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (184, '?var183', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (185, '?var184', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (186, '?var185', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (187, '?var186', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (188, '?var187', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (189, '?var188', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (190, '?var189', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (191, '?var190', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (192, '?var191', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (193, '?var192', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (194, '?var193', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (195, '?var194', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (196, '?var195', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (197, '?var196', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (198, '?var197', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (199, '?var198', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (200, '?var199', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (201, '?var200', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (202, '?var201', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (203, '?var202', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (204, '?var203', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (205, '?var204', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (206, '?var205', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (207, '?var206', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (208, '?var207', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (209, '?var208', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (210, '?var209', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (211, '?var210', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (212, '?var211', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (213, '?var212', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (214, '?var213', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (215, '?var214', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (216, '?var215', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (217, '?var216', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (218, '?var217', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (219, '?var218', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (220, '?var219', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (221, '?var220', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (222, '?var221', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (223, '?var222', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (224, '?var223', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (225, '?var224', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (226, '?var225', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (227, '?var226', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (228, '?var227', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (229, '?var228', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (230, '?var229', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (231, '?var230', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (232, '?var231', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (233, '?var232', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (234, '?var233', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (235, '?var234', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (236, '?var235', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (237, '?var236', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (238, '?var237', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (239, '?var238', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (240, '?var239', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (241, '?var240', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (242, '?var241', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (243, '?var242', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (244, '?var243', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (245, '?var244', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (246, '?var245', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (247, '?var246', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (248, '?var247', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (249, '?var248', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (250, '?var249', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (251, '?var250', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (252, '?var251', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (253, '?var252', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (254, '?var253', 4, 1);
INSERT INTO VARIABLE_TERM VALUES (255, '?var254', 1, 1);
INSERT INTO VARIABLE_TERM VALUES (256, '?var255', 4, 1);

CALL SYSCS_UTIL.SYSCS_UPDATE_STATISTICS('APP', 'VARIABLE_TERM', null);

SELECT * FROM VARIABLE_TERM WHERE TERM_ID = 11;
SELECT * FROM VARIABLE_TERM WHERE (TERM_ID = 11) OR (TERM_ID =21) OR (TERM_ID = 31);
SELECT * FROM VARIABLE_TERM WHERE (TERM_ID  IN (11, 21, 31));
                
> Can't bulk load rows by primary key efficiently on tables with >256 rows
> ------------------------------------------------------------------------
>
>                 Key: DERBY-6045
>                 URL: https://issues.apache.org/jira/browse/DERBY-6045
>             Project: Derby
>          Issue Type: Bug
>          Components: Store
>    Affects Versions: 10.9.1.0
>         Environment: Linux Debian 6.0.5
>            Reporter: Tony Brusseau
>            Priority: Critical
>
> I have a table with a long integer primary key field and 11 million rows. I seem to be
unable to load large chunks of rows via id in a reasonably efficient manner.
>   1. If I do individual lookups via the primary key, then a fast indexed lookup occurs.
However, if I do large numbers of such queries, then the time is overwhelmed by round-trip
overhead which makes everything incredibly slow.
>   2. If I use a single query with a disjunction of the primary keys of interest,  then
a table scan is performed (even if the clause only contains 1-3 items), which walks over 11
million rows...incredibly inefficient.
>   3. If I use an IN clause, then a table scan is performed (even if the clause only contains
1-3 items), which walks over 11 million rows...incredibly inefficient.
> I'm guessing that this might have something to do with the fact that I'm using large
integers and really big numbers that don't start anywhere at or about 1 for my keys. Could
this possibly be confusing the optimizer?
> Here are the unlimited query plans for the 3 cases that I enumerated:
> *********************************************************************************************
> [EL Fine]: 2013-01-17 11:09:53.384--ServerSession(582235416)--Connection(1430986883)--Thread(Thread["Initial
Lisp Listener",5,SubL Thread Group])--SELECT TERM_ID, ARG0, ARG1, ARG2, ARG3, FORMULA_HASH,
FORMULA_LENGTH, FORMULA_TYPE, KB_STATUS FROM KB.FORMULA_TERM WHERE (TERM_ID = ?)
> 	bind => [2251799814033500]
> Thu Jan 17 11:09:53 CST 2013 Thread["Initial Lisp Listener",5,SubL Thread Group] (XID
= 4711079), (SESSIONID = 3), SELECT TERM_ID, ARG0, ARG1, ARG2, ARG3, FORMULA_HASH, FORMULA_LENGTH,
FORMULA_TYPE, KB_STATUS FROM KB.FORMULA_TERM WHERE (TERM_ID = ?) ******* Project-Restrict
ResultSet (3):
> Number of opens = 1
> Rows seen = 1
> Rows filtered = 0
> restriction = false
> projection = true
> 	constructor time (milliseconds) = 0
> 	open time (milliseconds) = 0
> 	next time (milliseconds) = 0
> 	close time (milliseconds) = 0
> 	restriction time (milliseconds) = 0
> 	projection time (milliseconds) = 0
> 	optimizer estimated row count: 1.00
> 	optimizer estimated cost: 6.59
> Source result set:
> 	Index Row to Base Row ResultSet for FORMULA_TERM:
> 	Number of opens = 1
> 	Rows seen = 1
> 	Columns accessed from heap = {1, 2, 3, 4, 5, 6, 7, 8}
> 		constructor time (milliseconds) = 0
> 		open time (milliseconds) = 0
> 		next time (milliseconds) = 0
> 		close time (milliseconds) = 0
> 		optimizer estimated row count: 1.00
> 		optimizer estimated cost: 6.59
> 		Index Scan ResultSet for FORMULA_TERM using constraint KB_FORMULA_TERM_TERM_ID_PK at
read committed isolation level using share row locking chosen by the optimizer
> 		Number of opens = 1
> 		Rows seen = 1
> 		Rows filtered = 0
> 		Fetch Size = 1
> 			constructor time (milliseconds) = 0
> 			open time (milliseconds) = 0
> 			next time (milliseconds) = 0
> 			close time (milliseconds) = 0
> 			next time in milliseconds/row = 0
> 		scan information:
> 			Bit set of columns fetched=All
> 			Number of columns fetched=2
> 			Number of deleted rows visited=0
> 			Number of pages visited=3
> 			Number of rows qualified=1
> 			Number of rows visited=1
> 			Scan type=btree
> 			Tree height=-1
> 			start position:
> 				>= on first 1 column(s).
> 				Ordered null semantics on the following columns: 
> 			stop position:
> 				> on first 1 column(s).
> 				Ordered null semantics on the following columns: 
> 			qualifiers:
> 				None
> 			optimizer estimated row count: 1.00
> 			optimizer estimated cost: 6.59
> [EL Fine]: 2013-01-17 11:01:00.732--ServerSession(1237006689)--Connection(927179828)--Thread(Thread["Initial
Lisp Listener",5,SubL Thread Group])--SELECT TERM_ID, ARG0, ARG1, ARG2, ARG3, FORMULA_HASH,
FORMULA_LENGTH, FORMULA_TYPE, KB_STATUS FROM KB.FORMULA_TERM WHERE (((TERM_ID = ?) OR (TERM_ID
= ?)) OR (TERM_ID = ?))
> 	bind => [2251799814033500, 2251799814033501, 2251799814033499]
> Thu Jan 17 11:01:10 CST 2013 Thread["Initial Lisp Listener",5,SubL Thread Group] (XID
= 4711078), (SESSIONID = 3), SELECT TERM_ID, ARG0, ARG1, ARG2, ARG3, FORMULA_HASH, FORMULA_LENGTH,
FORMULA_TYPE, KB_STATUS FROM KB.FORMULA_TERM WHERE (((TERM_ID = ?) OR (TERM_ID = ?)) OR (TERM_ID
= ?)) ******* Project-Restrict ResultSet (3):
> Number of opens = 1
> Rows seen = 3
> Rows filtered = 0
> restriction = false
> projection = true
> 	constructor time (milliseconds) = 0
> 	open time (milliseconds) = 0
> 	next time (milliseconds) = 0
> 	close time (milliseconds) = 0
> 	restriction time (milliseconds) = 0
> 	projection time (milliseconds) = 0
> 	optimizer estimated row count: 1176730.30
> 	optimizer estimated cost: 5931065.54
> Source result set:
> 	Project-Restrict ResultSet (2):
> 	Number of opens = 1
> 	Rows seen = 11767298
> 	Rows filtered = 11767295
> 	restriction = true
> 	projection = false
> 		constructor time (milliseconds) = 0
> 		open time (milliseconds) = 0
> 		next time (milliseconds) = 0
> 		close time (milliseconds) = 0
> 		restriction time (milliseconds) = 0
> 		projection time (milliseconds) = 0
> 		optimizer estimated row count: 1176730.30
> 		optimizer estimated cost: 5931065.54
> 	Source result set:
> 		Table Scan ResultSet for FORMULA_TERM at read committed isolation level using instantaneous
share row locking chosen by the optimizer
> 		Number of opens = 1
> 		Rows seen = 11767298
> 		Rows filtered = 0
> 		Fetch Size = 16
> 			constructor time (milliseconds) = 0
> 			open time (milliseconds) = 0
> 			next time (milliseconds) = 0
> 			close time (milliseconds) = 0
> 			next time in milliseconds/row = 0
> 		scan information:
> 			Bit set of columns fetched=All
> 			Number of columns fetched=9
> 			Number of pages visited=34358
> 			Number of rows qualified=11767298
> 			Number of rows visited=11767298
> 			Scan type=heap
> 			start position:
> 				null
> 			stop position:
> 				null
> 			qualifiers:
> 				None
> 			optimizer estimated row count: 1176730.30
> 			optimizer estimated cost: 5931065.54
> [EL Fine]: 2013-01-17 11:27:00.627--ServerSession(1237006689)--Connection(1688096771)--Thread(Thread["Initial
Lisp Listener",5,SubL Thread Group])--SELECT TERM_ID, ARG0, ARG1, ARG2, ARG3, FORMULA_HASH,
FORMULA_LENGTH, FORMULA_TYPE, KB_STATUS FROM KB.FORMULA_TERM WHERE (TERM_ID IN (?,?,?))
> 	bind => [2251799814033500, 2251799814033501, 2251799814033499]
> Thu Jan 17 11:47:26 CST 2013 Thread["Initial Lisp Listener",5,SubL Thread Group] (XID
= 4711080), (SESSIONID = 3), SELECT TERM_ID, ARG0, ARG1, ARG2, ARG3, FORMULA_HASH, FORMULA_LENGTH,
FORMULA_TYPE, KB_STATUS FROM KB.FORMULA_TERM WHERE (TERM_ID IN (?,?,?)) ******* Project-Restrict
ResultSet (3):
> Number of opens = 1
> Rows seen = 3
> Rows filtered = 0
> restriction = false
> projection = true
> 	constructor time (milliseconds) = 0
> 	open time (milliseconds) = 0
> 	next time (milliseconds) = 0
> 	close time (milliseconds) = 0
> 	restriction time (milliseconds) = 0
> 	projection time (milliseconds) = 0
> 	optimizer estimated row count: 1176730.30
> 	optimizer estimated cost: 5931065.54
> Source result set:
> 	Project-Restrict ResultSet (2):
> 	Number of opens = 1
> 	Rows seen = 11767298
> 	Rows filtered = 11767295
> 	restriction = true
> 	projection = false
> 		constructor time (milliseconds) = 0
> 		open time (milliseconds) = 0
> 		next time (milliseconds) = 0
> 		close time (milliseconds) = 0
> 		restriction time (milliseconds) = 0
> 		projection time (milliseconds) = 0
> 		optimizer estimated row count: 1176730.30
> 		optimizer estimated cost: 5931065.54
> 	Source result set:
> 		Table Scan ResultSet for FORMULA_TERM at read committed isolation level using instantaneous
share row locking chosen by the optimizer
> 		Number of opens = 1
> 		Rows seen = 11767298
> 		Rows filtered = 0
> 		Fetch Size = 16
> 			constructor time (milliseconds) = 0
> 			open time (milliseconds) = 0
> 			next time (milliseconds) = 0
> 			close time (milliseconds) = 0
> 			next time in milliseconds/row = 0
> 		scan information:
> 			Bit set of columns fetched=All
> 			Number of columns fetched=9
> 			Number of pages visited=34358
> 			Number of rows qualified=11767298
> 			Number of rows visited=11767298
> 			Scan type=heap
> 			start position:
> 				null
> 			stop position:
> 				null
> 			qualifiers:
> 				None
> 			optimizer estimated row count: 1176730.30
> 			optimizer estimated cost: 5931065.54

--
This message is automatically generated by JIRA.
If you think it was sent incorrectly, please contact your JIRA administrators
For more information on JIRA, see: http://www.atlassian.com/software/jira

Mime
View raw message