source: trunk/FACT++/src/fits2sql.cc@ 19136

Last change on this file since 19136 was 19136, checked in by tbretz, 6 years ago
Output some more connection information with print-connect
File size: 25.3 KB
Line 
1#include <boost/algorithm/string/join.hpp>
2#include <boost/regex.hpp>
3
4#include "Database.h"
5
6#include "tools.h"
7#include "Time.h"
8#include "Configuration.h"
9
10#include "zfits.h"
11
12using namespace std;
13
14// ------------------------------------------------------------------------
15
16struct Map : pair<string, string>
17{
18 Map() { }
19};
20
21std::istream &operator>>(std::istream &in, Map &m)
22{
23 const istreambuf_iterator<char> eos;
24 string txt(istreambuf_iterator<char>(in), eos);
25
26 const boost::regex expr("((.*)[^\\\\])/(.*)");
27 boost::smatch match;
28 if (!boost::regex_match(txt, match, expr))
29 throw runtime_error("Could not evaluate map argument: "+txt);
30
31 m.first = match[1].str();
32 m.second = match[3].str();
33
34 return in;
35}
36
37
38void SetupConfiguration(Configuration &conf)
39{
40 po::options_description control("Root to SQL");
41 control.add_options()
42 ("uri,u", var<string>()
43#if BOOST_VERSION >= 104200
44 ->required()
45#endif
46 , "Database link as in\n\tuser:password@server[:port]/database[/comp].")
47 ("file", var<string>("")
48#if BOOST_VERSION >= 104200
49 ->required()
50#endif
51 , "The root file to read from")
52 ("force", po_switch(), "Force processing even if there is no database connection")
53 ("create", po_switch(), "Create the database if not existing")
54 ("drop", po_switch(), "Drop the table (implies create)")
55 ("extension,e", var<string>(""), "Name of the fits extension (table) to convert")
56 ("table", var<string>(""), "Name of the table to use (default is the tree name)")
57 ("map", vars<Map>(), "A regular expression which is applied to the leaf name befoee it is used as SQL column name)")
58 ("sql-type", vars<Map>(), "Allows to overwrite the calculated SQL type for a given column e.g. 'sql-column-name/UNSIGNED IN'")
59 ("ignore", vars<string>(), "Ignore the given leaf, if the given regular expression matches")
60 ("unsigned", vars<string>(), "In fits files per default columns are signed. This interpretss the column as unsigned value. Use the FITS column name.")
61 ("primary", vars<string>(), "List of columns to be used as primary keys during table creation (in connection with --create)")
62 ("first", var<int64_t>(int64_t(0)), "First event to start with (default: 0), mainly for test purpose")
63 ("max", var<int64_t>(int64_t(0)), "Maximum number of events to process (0: all), mainly for test purpose")
64 ("engine", var<string>(""), "Database engine to be used when a new table is created")
65 ("row-format", var<string>(""), "Defines the ROW_FORMAT keyword for table creation")
66 ("duplicate", vars<string>(), "Specifies an assignment_list for an 'ON DUPLICATE KEY UPDATE' expression")
67 ("ignore-errors", po_switch(), "Adds the IGNORE keyword to the INSERT query (turns errors into warnings, ignores rows with errors)")
68 ;
69
70 po::options_description debug("Debug options");
71 debug.add_options()
72 ("no-insert", po_switch(), "Does not insert any data into the table")
73 ("dry-run", po_switch(), "Skip any query which changes the databse (might result in consecutive failures)")
74 ("print-extensions", po_switch(), "Print extensions (tables) from fits file")
75 ("print-connection", po_switch(), "Print database connection information")
76 ("print-columns", po_switch(), "Print columns in fits table")
77 ("print-insert", po_switch(), "Print the INSERT query (note that it contains all data)")
78 ("print-create", po_switch(), "Print the CREATE query")
79 ("verbose,v", var<uint16_t>(1), "Verbosity (0: quiet, 1: default, 2: more, 3, ...)")
80 ;
81
82 po::positional_options_description p;
83 p.add("file", 1); // The 1st positional options (n=1)
84
85 conf.AddOptions(control);
86 conf.AddOptions(debug);
87 conf.SetArgumentPositions(p);
88}
89
90void PrintUsage()
91{
92 cout <<
93 "fits2sql - Fills the data from a fits file into a database\n"
94 "\n"
95 "For convenience, this documentation uses the extended version of the options, "
96 "refer to the output below to get the abbreviations.\n"
97 "\n"
98 "This is a general purpose tool to fill the contents of a fite file into a database.\n"
99 "\n"
100 "Each fits file contians several table, so called extenbsions. Each tables has "
101 "a number of columns compilsed from basic data types. The default extension to "
102 "read from is the first one on the file but the name can be overwritten using "
103 "--extension. The default table name to fill the data into is identical to "
104 "the extension name. It can be overwritten using --table.\n"
105 "\n"
106 "The name of each column to which data is filled is obtained from "
107 "the fits column names. The column names can be checked using --print-columns. "
108 "Sometimes these names might not be convenient. To allow to simplify or replace "
109 "column names, regular expressions (using boost's regex) can be defined to change "
110 "the names. Note that these regular expressions are applied one by one on each "
111 "columns's name. A valid expression could "
112 "be:\n"
113 " --map=MHillas\\.f/\n"
114 "which would remove all occurances of 'MHillas.f'. This option can be used more than "
115 "once. They are applied in sequence. A single match does not stop the sequence.\n"
116 "\n"
117 "Sometimes it might also be convenient to skip a column. This can be done with "
118 "the --ignore resource. If the given regular expresion yields a match, the "
119 "column will be ignored. Note that the regular expression works on the raw-name "
120 "of the column not the readily mapped SQL column names. Example:\n"
121 " --ignore=ThetaSq\\..*\n"
122 "will skip all leaved which start with 'ThetaSq.'. This option can be used"
123 "more than once.\n"
124 "\n"
125 "The data type of each column is kept as close as possible to the columns' data "
126 "types. If for some reason this is not wanted, the data type of the SQL column "
127 "can be overwritten with --sql-type sql-column/sql-ytpe, for example:\n"
128 " --sql-type=FileId/UNSIGNED INT\n"
129 "while the first argument of the name of the SQL column to which the data type "
130 "should be applied. The second column is the basic SQL data type. The option can "
131 "be given more than once.\n"
132 "\n"
133 "Database interaction:\n"
134 "\n"
135 "To drop an existing table, --drop can be used.\n"
136 "\n"
137 "To create a table according to theSQL column names and data types, --create "
138 "can be used. The query used can be printed with --print-create even --create "
139 "has not been specified.\n"
140 "\n"
141 "To choose the columns which should become primary keys, use --primary, "
142 "for exmaple:\n"
143 " --primary=col1\n"
144 "To define more than one column as primary key, the option can be given more than "
145 "once. Note that the combination of these columns must be unique.\n"
146 "\n"
147 "All columns are created as NOT NULL as default. To force a database engine "
148 "and/or a storage format, use --engine and --rot-format.\n"
149 "\n"
150 "Usually, the INSERT query would fail if the PRIMARY key exists already. "
151 "This can be avoided using the 'ON DUPLICATE KEY UPDATE' directive. With the "
152 "--duplicate, you can specify what should be updated in case of a duplicate key. "
153 "To keep the row untouched, you can just update the primary key "
154 "with the identical primary key, e.g. --duplicate='MyPrimary=VALUES(MyPrimary)'. "
155 "The --duplicate resource can be specified more than once to add more expressions "
156 "to the assignment_list. For more details, see the MySQL manual.\n"
157 "\n"
158 "Another possibility is to add the IGNORE keyword to the INSERT query by "
159 "--ignore-errors, which essentially ignores all errors and turns them into "
160 "warnings which are printed after the query succeeded.\n"
161 "\n"
162 "For debugging purpose, or to just create or drop a table, the final insert "
163 "query can be skipped using --no-insert. Note that for performance reason, "
164 "all data is collected in memory and a single INSERT query is issued at the "
165 "end.\n"
166 "\n"
167 "Using a higher verbosity level (-v), an overview of the written columns or all "
168 "processed leaves is printed depending on the verbosity level. The output looks "
169 "like the following\n"
170 " Leaf name [root data type] (SQL name)\n"
171 "for example\n"
172 " MTime.fTime.fMilliSec [Long64_t] (MilliSec)\n"
173 "which means that the leaf MTime.fTime.fMilliSec is detected to be a Long64_t "
174 "which is filled into a column called MilliSec. Leaves with non basic data types "
175 "are ignored automatically and are marked as (-n/a-). User ignored columnd "
176 "are marked as (-ignored-).\n"
177 "\n"
178 "If a query failed, the query is printed to stderr together with the error message. "
179 "For the main INSERT query, this is only true if the verbosity level is at least 2 "
180 "or the query has less than 80*25 bytes.\n"
181 "\n"
182 "In case of succes, 0 is returned, a value>0 otherwise.\n"
183 "\n"
184 "Usage: fits2sql [options] --uri URI fitsfile.fits[.gz]\n"
185 "\n"
186 ;
187 cout << endl;
188}
189
190enum BasicType_t
191{
192 kNone = 0,
193 kVarchar,
194 kBool,
195 kFloat,
196 kDouble,
197 kInt8,
198 kUInt8,
199 kInt16,
200 kUInt16,
201 kInt32,
202 kUInt32,
203 kInt64,
204 kUInt64,
205// kMJD,
206};
207
208static const map<char, pair<BasicType_t, string>> ConvFits =
209{
210 { 'A', { kVarchar, "VARCHAR" } },
211 { 'a', { kVarchar, "VARCHAR" } },
212 { 'L', { kBool, "BOOLEAN" } },
213 { 'l', { kBool, "BOOLEAN" } },
214 { 'B', { kInt8, "TINYINT" } },
215 { 'b', { kUInt8, "TINYINT UNSIGNED" } },
216 { 'I', { kInt16, "SMALLINT" } },
217 { 'i', { kUInt16, "SMALLINT UNSIGNED" } },
218 { 'J', { kInt32, "INT" } },
219 { 'j', { kUInt32, "INT UNSIGNED" } },
220 { 'K', { kInt64, "BIGINT" } },
221 { 'k', { kUInt64, "BIGINT UNSIGNED" } },
222 { 'E', { kFloat, "FLOAT" } },
223 { 'e', { kFloat, "FLOAT" } },
224 { 'D', { kDouble, "DOUBLE" } },
225 { 'd', { kDouble, "DOUBLE" } },
226};
227
228struct Container
229{
230 string branch; // fits column name
231 string column; // sql column name
232 BasicType_t type;
233 size_t num;
234// double offset;
235 void *ptr;
236
237 Container(const string &b, const string &c, const BasicType_t &t, const size_t &n/*, const double &offset=0*/) : branch(b), column(c), type(t), num(n), ptr(0)
238 {
239 }
240 ~Container()
241 {
242 }
243
244 string fmt(const size_t &index) const
245 {
246 ostringstream str;
247
248 switch (type)
249 {
250 //case kVarchar: str << string(reinterpret_cast<char*>(ptr), num); break;
251 case kVarchar: str << string(reinterpret_cast<char*>(ptr), num).c_str(); break;
252 case kFloat: str << setprecision(8) << reinterpret_cast<float*>(ptr)[index]; break;
253// case kMJD: str << setprecision(16) << reinterpret_cast<double*>(ptr)[0]+offset; break;
254 case kDouble: str << setprecision(16) << reinterpret_cast<double*>(ptr)[index]; break;
255 case kBool:
256 case kInt8: str << int32_t(reinterpret_cast<int8_t*>(ptr)[index]); break;
257 case kUInt8: str << uint32_t(reinterpret_cast<uint8_t*>(ptr)[index]); break;
258 case kInt16: str << reinterpret_cast<int16_t*>(ptr)[index]; break;
259 case kUInt16: str << reinterpret_cast<uint16_t*>(ptr)[index]; break;
260 case kInt32: str << reinterpret_cast<int32_t*>(ptr)[index]; break;
261 case kUInt32: str << reinterpret_cast<uint32_t*>(ptr)[index]; break;
262 case kInt64: str << reinterpret_cast<int64_t*>(ptr)[index]; break;
263 case kUInt64: str << reinterpret_cast<uint64_t*>(ptr)[index]; break;
264 case kNone:
265 break;
266 }
267
268 return str.str();
269 }
270};
271
272int main(int argc, const char* argv[])
273{
274 Time start;
275
276 Configuration conf(argv[0]);
277 conf.SetPrintUsage(PrintUsage);
278 SetupConfiguration(conf);
279
280 if (!conf.DoParse(argc, argv))
281 return 127;
282
283 // ----------------------------- Evaluate options --------------------------
284 const string uri = conf.Get<string>("uri");
285 const string file = conf.Get<string>("file");
286 const string extension = conf.Get<string>("extension");
287 string table = conf.Get<string>("table");
288
289 const uint16_t verbose = conf.Get<uint16_t>("verbose");
290 const int64_t first = conf.Get<int64_t>("first");
291 const int64_t max = conf.Get<int64_t>("max");
292
293 const bool force = conf.Get<bool>("force");
294 const bool drop = conf.Get<bool>("drop");
295 const bool create = conf.Get<bool>("create") || drop;
296 const bool noinsert = conf.Get<bool>("no-insert");
297 const bool dry_run = conf.Get<bool>("dry-run");
298
299 const string engine = conf.Get<string>("engine");
300 const string row_format = conf.Get<string>("row-format");
301
302 const bool ignore_errors = conf.Get<bool>("ignore-errors");
303
304 const bool print_connection = conf.Get<bool>("print-connection");
305 const bool print_extensions = conf.Get<bool>("print-extensions");
306 const bool print_columns = conf.Get<bool>("print-columns");
307 const bool print_create = conf.Get<bool>("print-create");
308 const bool print_insert = conf.Get<bool>("print-insert");
309
310 const vector<Map> mymap = conf.Vec<Map>("map");
311 const vector<Map> sqltypes = conf.Vec<Map>("sql-type");
312 const vector<string> _ignore = conf.Vec<string>("ignore");
313 const vector<string> primary = conf.Vec<string>("primary");
314
315 const vector<string> duplicate = conf.Vec<string>("duplicate");
316 const vector<string> notsigned = conf.Vec<string>("unsigned");
317
318 // -------------------------------------------------------------------------
319
320 if (verbose>0)
321 cout << "\n-------------------------- Evaluating file -------------------------" << endl;
322
323 zfits f(file.c_str(), extension.c_str());
324 if (!f)
325 {
326 cerr << "Could not open file " << file << ": " << strerror(errno) << endl;
327 return 1;
328 }
329
330 if (verbose>0)
331 cout << "File: " << file << endl;
332
333 if (!extension.empty() && extension!=f.Get<string>("EXTNAME"))
334 {
335 cerr << "Extension " << extension << " not found in file." << endl;
336 return 2;
337 }
338
339 if (print_extensions)
340 {
341 cout << "\nTables:\n - " << boost::join(f.GetTables(), "\n - ") << '\n' << endl;
342 return 3;
343 }
344
345 if (verbose>0)
346 cout << "FITS extension [table]: " << f.Get<string>("EXTNAME") << endl;
347
348 if (table.empty())
349 table = f.Get<string>("EXTNAME");
350
351 if (verbose>0)
352 cout << "SQL table: " << table << endl;
353
354// const double mjdref = f.Get("MJDREF", double(0));
355
356 if (print_columns)
357 {
358 cout << '\n';
359 f.PrintColumns();
360 cout << '\n';
361 }
362
363 const auto cols = f.GetColumns();
364
365 if (verbose>0)
366 {
367 cout << f.GetNumRows() << " events found." << endl;
368 cout << cols.size() << " columns found." << endl;
369 }
370
371 string query =
372 "CREATE TABLE IF NOT EXISTS `"+table+"`\n"
373 "(\n";
374
375 vector<Container> vec;
376
377 for (const auto &ic : cols)
378 {
379 const auto &col = ic.second;
380
381 if (verbose>2)
382 cout << '\n' << col.type << " " << ic.first << "[" << col.num << "]";
383
384 string name = ic.first;
385
386 bool found = false;
387 for (auto b=_ignore.cbegin(); b!=_ignore.cend(); b++)
388 {
389 if (boost::regex_match(name, boost::regex(*b)))
390 {
391 found = true;
392 if (verbose>2)
393 cout << " (-ignored-)";
394 break;
395 }
396 }
397 if (found)
398 continue;
399
400 const char tn = find(notsigned.cbegin(), notsigned.cend(), ic.first)!=notsigned.cend() ?
401 tolower(col.type) : toupper(col.type);
402
403 auto it = ConvFits.find(tn);
404 if (it==ConvFits.end())
405 {
406 if (verbose>2)
407 cout << " (-n/a-)";
408 continue;
409 }
410
411 if (verbose==2)
412 cout << '\n' << name << " [" << tn << "]";
413
414 for (auto m=mymap.cbegin(); m!=mymap.cend(); m++)
415 name = boost::regex_replace(name, boost::regex(m->first), m->second);
416
417 if (verbose>1)
418 cout << " (" << name << ")";
419
420 string sqltype = it->second.second;
421
422 for (auto m=sqltypes.cbegin(); m!=sqltypes.cend(); m++)
423 if (m->first==name)
424 sqltype = m->second;
425
426 if (!vec.empty())
427 query += ",\n";
428
429 const size_t N = col.type=='A' ? 1 : col.num;
430 for (int i=0; i<N; i++)
431 {
432 query += " `"+name;
433 if (N>1)
434 query += "["+to_string(i)+"]";
435 query += "` "+sqltype;
436 if (col.type=='A')
437 query += '('+to_string(col.num)+')';
438 query += " NOT NULL COMMENT '"+ic.first;
439 if (!col.unit.empty())
440 query += "["+col.unit+"]";
441 if (!col.comment.empty())
442 query += ": "+col.comment;
443 query += +"'";
444 if (N>1 && i!=N-1)
445 query += ",\n";
446 }
447
448 const BasicType_t bt =
449 /*ic.first=="Time" && col.num==1 && col.unit=="MJD" && it->second.first==kDouble ?
450 kMJD :*/ it->second.first;
451
452 vec.emplace_back(ic.first, name, bt, col.num/*, mjdref*/);
453 vec.back().ptr = f.SetPtrAddress(ic.first);
454 }
455
456 if (verbose>1)
457 cout << "\n\n";
458 if (verbose>0)
459 cout << vec.size() << " columns setup for reading." << endl;
460
461 // -------------------------------------------------------------------------
462 // Checking for database connection
463
464 Database connection(uri);
465
466 if (verbose>0)
467 {
468 cout << "Client Version: " << connection.client_version() << '\n';
469 cout << "Server Version: " << connection.server_version() << endl;
470 }
471
472 if (print_connection)
473 {
474 try
475 {
476 const auto &res1 = connection.query("SHOW STATUS LIKE 'Compression'").store();
477 cout << "Compression of databse connection is " << string(res1[0][1]) << endl;
478
479 const auto &res2 = connection.query("SHOW STATUS LIKE 'Ssl_cipher'").store();
480 cout << "Connection to databases is " << (string(res2[0][1]).empty()?"UNENCRYPTED":"ENCRYPTED ("+string(res2[0][1])+")") << endl;
481 }
482 catch (const exception &e)
483 {
484 cerr << "\nSHOW STATUS LIKE COMPRESSION\n\n";
485 cerr << "SQL query failed:\n" << e.what() << endl;
486 return 6;
487 }
488 }
489
490 try
491 {
492 if (!force)
493 connection.connected();
494 }
495 catch (const exception &e)
496 {
497 cerr << "SQL connection failed: " << e.what() << '\n' << endl;
498 return 4;
499 }
500
501 // -------------------------------------------------------------------------
502
503 if (verbose>0)
504 cout << "\n--------------------------- Database Table -------------------------" << endl;
505
506 if (!primary.empty())
507 query += ",\n PRIMARY KEY USING BTREE (`"+boost::algorithm::join(primary, "`, `")+"`)\n";
508
509 query +=
510 ")\n"
511 "DEFAULT CHARSET=latin1 COLLATE=latin1_general_ci\n";
512 if (!engine.empty())
513 query += "ENGINE="+engine+"\n";
514 if (!row_format.empty())
515 query += "ROW_FORMAT="+row_format+"\n";
516 query += "COMMENT='created by "+conf.GetName()+"'\n";
517
518
519 // FIXME: Can we omit the catching to be able to print the
520 // query 'autmatically'?
521 try
522 {
523 if (drop)
524 {
525 // => Simple result
526 if (!dry_run)
527 connection.query("DROP TABLE `"+table+"`").execute();
528 if (verbose>0)
529 cout << "Table `" << table << "` dropped." << endl;
530 }
531 }
532 catch (const exception &e)
533 {
534 cerr << "DROP TABLE `" << table << "`\n\n";
535 cerr << "SQL query failed:\n" << e.what() << '\n' << endl;
536 return 5;
537 }
538
539 try
540 {
541 if (create && !dry_run)
542 connection.query(query).execute();
543 }
544 catch (const exception &e)
545 {
546 cerr << query << "\n\n";
547 cerr << "SQL query failed:\n" << e.what() << '\n' << endl;
548 return 6;
549 }
550
551 if (print_create)
552 cout << query << endl;
553
554 if (create && verbose>0)
555 cout << "Table `" << table << "` created." << endl;
556
557 // -------------------------------------------------------------------------
558
559 if (verbose>0)
560 cout << "\n---------------------------- Reading file --------------------------" << endl;
561
562 //query = update ? "UPDATE" : "INSERT";
563 query = "INSERT ";
564 if (ignore_errors)
565 query += "IGNORE ";
566 query += "`"+table+"`\n"
567 "(\n";
568
569 for (auto c=vec.cbegin(); c!=vec.cend(); c++)
570 {
571 const size_t N = c->type==kVarchar ? 1 : c->num;
572 for (int i=0; i<N; i++)
573 {
574 if (c!=vec.cbegin())
575 query += ",\n";
576
577 if (N==1)
578 query += " `"+c->column+"`";
579 else
580 query += " `"+c->column+"["+to_string(i)+"]`";
581
582 if (N>1 && i!=N-1)
583 query += ",\n";
584 }
585 }
586
587 query +=
588 "\n)\n"
589 "VALUES\n";
590
591 size_t count = 0;
592
593 const size_t num = max>0 && (max-first)<f.GetNumRows() ? (max-first) : f.GetNumRows();
594 for (size_t j=first; j<num; j++)
595 {
596 f.GetRow(j);
597
598 if (count>0)
599 query += ",\n";
600
601 query += "(\n";
602
603 for (auto c=vec.cbegin(); c!=vec.cend(); c++)
604 {
605 const size_t N = c->type==kVarchar ? 1 : c->num;
606 for (int i=0; i<N; i++)
607 {
608 if (c!=vec.cbegin())
609 query += ",\n";
610
611 if (c->type==kVarchar)
612 query += " '"+c->fmt(i)+"'";
613 else
614 query += " "+c->fmt(i);
615
616 if (print_insert && i==0)
617 query += " /* "+c->column+" -> "+c->branch+" */";
618
619 if (N>1 && i!=N-1)
620 query += ",\n";
621 }
622 }
623 query += "\n)";
624
625 count ++;
626 }
627
628 if (!duplicate.empty())
629 query += "\nON DUPLICATE KEY UPDATE\n " + boost::join(duplicate, ",\n ");
630
631 if (verbose>0)
632 cout << count << " out of " << num << " row(s) read from file [N=" << first << ".." << num-1 << "]." << endl;
633
634 if (count==0)
635 {
636 if (verbose>0)
637 cout << "Total execution time: " << Time().UnixTime()-start.UnixTime() << "s\n" << endl;
638 return 0;
639 }
640
641 // -------------------------------------------------------------------------
642
643 if (verbose>0)
644 {
645 cout << "\n--------------------------- Inserting data -------------------------" << endl;
646 cout << "Sending INSERT query (" << query.length() << " bytes)" << endl;
647 }
648
649 try
650 {
651 if (!noinsert && !dry_run)
652 {
653 auto q = connection.query(query);
654 q.execute();
655 cout << q.info() << '\n' << endl;
656 }
657 else
658 cout << "Insert query skipped!" << endl;
659
660 if (print_insert)
661 cout << query << endl;
662 }
663 catch (const exception &e)
664 {
665 if (verbose>1 || query.length()<80*25)
666 cerr << query << "\n\n";
667 cerr << "SQL query failed (" << query.length() << " bytes):\n" << e.what() << '\n' << endl;
668 return 7;
669 }
670
671 if (verbose>0)
672 {
673 const auto sec = Time().UnixTime()-start.UnixTime();
674 cout << "Total execution time: " << sec << "s ";
675 cout << "(" << Tools::Fractional(sec/count) << "s/row)\n";
676
677 try
678 {
679 const auto resw =
680 connection.query("SHOW WARNINGS").store();
681
682 for (size_t i=0; i<resw.num_rows(); i++)
683 {
684 const mysqlpp::Row &roww = resw[i];
685
686 cout << roww["Level"] << '[' << roww["Code"] << "]: ";
687 cout << roww["Message"] << '\n';
688 }
689 cout << endl;
690
691 }
692 catch (const exception &e)
693 {
694 cerr << "\nSHOW WARNINGS\n\n";
695 cerr << "SQL query failed:\n" << e.what() << '\n' <<endl;
696 return 8;
697 }
698 }
699
700 if (print_connection)
701 {
702 try
703 {
704 const auto &res1 = connection.query("SHOW STATUS LIKE 'Bytes_%'").store();
705 cout << left << setw(16) << res1[0]["Variable_name"] << ' ' << Tools::Scientific(res1[0]["Value"]) << endl;
706 cout << left << setw(16) << res1[1]["Variable_name"] << ' ' << Tools::Scientific(res1[1]["Value"]) << endl;
707 cout << endl;
708 }
709 catch (const exception &e)
710 {
711 cerr << "\nSHOW STATUS LIKE 'Bytes_%'\n\n";
712 cerr << "SQL query failed:\n" << e.what() << endl;
713 return 6;
714 }
715 }
716
717 return 0;
718}
Note: See TracBrowser for help on using the repository browser.