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

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