@@ -97,6 +97,50 @@ fn opcode_to_type(op: &str) -> DataType {
97
97
}
98
98
}
99
99
100
+ fn root_block_columns (
101
+ conn : & mut ConnectionState ,
102
+ ) -> Result < HashMap < i64 , HashMap < i64 , DataType > > , Error > {
103
+ let table_block_columns: Vec < ( i64 , i64 , String ) > = execute:: iter (
104
+ conn,
105
+ "SELECT s.rootpage, col.cid as colnum, col.type
106
+ FROM sqlite_schema s
107
+ JOIN pragma_table_info(s.name) AS col
108
+ WHERE s.type = 'table'" ,
109
+ None ,
110
+ false ,
111
+ ) ?
112
+ . filter_map ( |res| res. map ( |either| either. right ( ) ) . transpose ( ) )
113
+ . map ( |row| FromRow :: from_row ( & row?) )
114
+ . collect :: < Result < Vec < _ > , Error > > ( ) ?;
115
+
116
+ let index_block_columns: Vec < ( i64 , i64 , String ) > = execute:: iter (
117
+ conn,
118
+ "SELECT s.rootpage, idx.seqno as colnum, col.type
119
+ FROM sqlite_schema s
120
+ JOIN pragma_index_info(s.name) AS idx
121
+ LEFT JOIN pragma_table_info(s.tbl_name) as col
122
+ ON col.cid = idx.cid
123
+ WHERE s.type = 'index'" ,
124
+ None ,
125
+ false ,
126
+ ) ?
127
+ . filter_map ( |res| res. map ( |either| either. right ( ) ) . transpose ( ) )
128
+ . map ( |row| FromRow :: from_row ( & row?) )
129
+ . collect :: < Result < Vec < _ > , Error > > ( ) ?;
130
+
131
+ let mut row_info: HashMap < i64 , HashMap < i64 , DataType > > = HashMap :: new ( ) ;
132
+ for ( block, colnum, datatype) in table_block_columns {
133
+ let row_info = row_info. entry ( block) . or_default ( ) ;
134
+ row_info. insert ( colnum, datatype. parse ( ) . unwrap_or ( DataType :: Null ) ) ;
135
+ }
136
+ for ( block, colnum, datatype) in index_block_columns {
137
+ let row_info = row_info. entry ( block) . or_default ( ) ;
138
+ row_info. insert ( colnum, datatype. parse ( ) . unwrap_or ( DataType :: Null ) ) ;
139
+ }
140
+
141
+ return Ok ( row_info) ;
142
+ }
143
+
100
144
// Opcode Reference: https://sqlite.org/opcode.html
101
145
pub ( super ) fn explain (
102
146
conn : & mut ConnectionState ,
@@ -112,6 +156,8 @@ pub(super) fn explain(
112
156
// Nullable columns
113
157
let mut n = HashMap :: < i64 , bool > :: with_capacity ( 6 ) ;
114
158
159
+ let root_block_cols = root_block_columns ( conn) ?;
160
+
115
161
let program: Vec < ( i64 , String , i64 , i64 , i64 , Vec < u8 > ) > =
116
162
execute:: iter ( conn, & format ! ( "EXPLAIN {}" , query) , None , false ) ?
117
163
. filter_map ( |res| res. map ( |either| either. right ( ) ) . transpose ( ) )
@@ -190,7 +236,23 @@ pub(super) fn explain(
190
236
191
237
OP_OPEN_READ | OP_OPEN_WRITE | OP_OPEN_EPHEMERAL | OP_OPEN_AUTOINDEX => {
192
238
//Create a new pointer which is referenced by p1
193
- p. insert ( p1, HashMap :: with_capacity ( 6 ) ) ;
239
+
240
+ //Create a new pointer which is referenced by p1, take column metadata from db schema if found
241
+ if p3 == 0 {
242
+ if let Some ( columns) = root_block_cols. get ( & p2) {
243
+ p. insert (
244
+ p1,
245
+ columns
246
+ . iter ( )
247
+ . map ( |( & colnum, & datatype) | ( colnum, datatype) )
248
+ . collect ( ) ,
249
+ ) ;
250
+ } else {
251
+ p. insert ( p1, HashMap :: with_capacity ( 6 ) ) ;
252
+ }
253
+ } else {
254
+ p. insert ( p1, HashMap :: with_capacity ( 6 ) ) ;
255
+ }
194
256
}
195
257
196
258
OP_VARIABLE => {
@@ -339,3 +401,126 @@ pub(super) fn explain(
339
401
340
402
Ok ( ( output, nullable) )
341
403
}
404
+
405
+ #[ test]
406
+ fn test_root_block_columns_has_types ( ) {
407
+ use crate :: sqlite:: SqliteConnectOptions ;
408
+ use std:: str:: FromStr ;
409
+ let conn_options = SqliteConnectOptions :: from_str ( "sqlite::memory:" ) . unwrap ( ) ;
410
+ let mut conn = super :: EstablishParams :: from_options ( & conn_options)
411
+ . unwrap ( )
412
+ . establish ( )
413
+ . unwrap ( ) ;
414
+
415
+ assert ! ( execute:: iter(
416
+ & mut conn,
417
+ r"CREATE TABLE t(a INTEGER PRIMARY KEY, b_null TEXT NULL, b TEXT NOT NULL);" ,
418
+ None ,
419
+ false
420
+ )
421
+ . unwrap( )
422
+ . next( )
423
+ . is_some( ) ) ;
424
+ assert ! (
425
+ execute:: iter( & mut conn, r"CREATE INDEX i1 on t (a,b_null);" , None , false )
426
+ . unwrap( )
427
+ . next( )
428
+ . is_some( )
429
+ ) ;
430
+ assert ! ( execute:: iter(
431
+ & mut conn,
432
+ r"CREATE UNIQUE INDEX i2 on t (a,b_null);" ,
433
+ None ,
434
+ false
435
+ )
436
+ . unwrap( )
437
+ . next( )
438
+ . is_some( ) ) ;
439
+ assert ! ( execute:: iter(
440
+ & mut conn,
441
+ r"CREATE TABLE t2(a INTEGER, b_null NUMERIC NULL, b NUMERIC NOT NULL);" ,
442
+ None ,
443
+ false
444
+ )
445
+ . unwrap( )
446
+ . next( )
447
+ . is_some( ) ) ;
448
+ assert ! ( execute:: iter(
449
+ & mut conn,
450
+ r"CREATE INDEX t2i1 on t2 (a,b_null);" ,
451
+ None ,
452
+ false
453
+ )
454
+ . unwrap( )
455
+ . next( )
456
+ . is_some( ) ) ;
457
+ assert ! ( execute:: iter(
458
+ & mut conn,
459
+ r"CREATE UNIQUE INDEX t2i2 on t2 (a,b);" ,
460
+ None ,
461
+ false
462
+ )
463
+ . unwrap( )
464
+ . next( )
465
+ . is_some( ) ) ;
466
+
467
+ let table_block_nums: HashMap < String , i64 > = execute:: iter (
468
+ & mut conn,
469
+ r"select name, rootpage from sqlite_master" ,
470
+ None ,
471
+ false ,
472
+ )
473
+ . unwrap ( )
474
+ . filter_map ( |res| res. map ( |either| either. right ( ) ) . transpose ( ) )
475
+ . map ( |row| FromRow :: from_row ( row. as_ref ( ) . unwrap ( ) ) )
476
+ . collect :: < Result < HashMap < _ , _ > , Error > > ( )
477
+ . unwrap ( ) ;
478
+
479
+ let root_block_cols = root_block_columns ( & mut conn) . unwrap ( ) ;
480
+
481
+ assert_eq ! ( 6 , root_block_cols. len( ) ) ;
482
+
483
+ //prove that we have some information for each table & index
484
+ for blocknum in table_block_nums. values ( ) {
485
+ assert ! ( root_block_cols. contains_key( blocknum) ) ;
486
+ }
487
+
488
+ //prove that each block has the correct information
489
+ {
490
+ let blocknum = table_block_nums[ "t" ] ;
491
+ assert_eq ! ( ( DataType :: Int64 ) , root_block_cols[ & blocknum] [ & 0 ] ) ;
492
+ assert_eq ! ( ( DataType :: Text ) , root_block_cols[ & blocknum] [ & 1 ] ) ;
493
+ assert_eq ! ( ( DataType :: Text ) , root_block_cols[ & blocknum] [ & 2 ] ) ;
494
+ }
495
+
496
+ {
497
+ let blocknum = table_block_nums[ "i1" ] ;
498
+ assert_eq ! ( ( DataType :: Int64 ) , root_block_cols[ & blocknum] [ & 0 ] ) ;
499
+ assert_eq ! ( ( DataType :: Text ) , root_block_cols[ & blocknum] [ & 1 ] ) ;
500
+ }
501
+
502
+ {
503
+ let blocknum = table_block_nums[ "i2" ] ;
504
+ assert_eq ! ( ( DataType :: Int64 ) , root_block_cols[ & blocknum] [ & 0 ] ) ;
505
+ assert_eq ! ( ( DataType :: Text ) , root_block_cols[ & blocknum] [ & 1 ] ) ;
506
+ }
507
+
508
+ {
509
+ let blocknum = table_block_nums[ "t2" ] ;
510
+ assert_eq ! ( ( DataType :: Int64 ) , root_block_cols[ & blocknum] [ & 0 ] ) ;
511
+ assert_eq ! ( ( DataType :: Null ) , root_block_cols[ & blocknum] [ & 1 ] ) ;
512
+ assert_eq ! ( ( DataType :: Null ) , root_block_cols[ & blocknum] [ & 2 ] ) ;
513
+ }
514
+
515
+ {
516
+ let blocknum = table_block_nums[ "t2i1" ] ;
517
+ assert_eq ! ( ( DataType :: Int64 ) , root_block_cols[ & blocknum] [ & 0 ] ) ;
518
+ assert_eq ! ( ( DataType :: Null ) , root_block_cols[ & blocknum] [ & 1 ] ) ;
519
+ }
520
+
521
+ {
522
+ let blocknum = table_block_nums[ "t2i2" ] ;
523
+ assert_eq ! ( ( DataType :: Int64 ) , root_block_cols[ & blocknum] [ & 0 ] ) ;
524
+ assert_eq ! ( ( DataType :: Null ) , root_block_cols[ & blocknum] [ & 1 ] ) ;
525
+ }
526
+ }
0 commit comments