cl_sortkey now back down to varbinary(230). Glad PG doesn't have this issue.
[lhc/web/wiklou.git] / maintenance / postgres / compare_schemas.pl
1 #!/usr/bin/perl
2
3 ## Rough check that the base and postgres "tables.sql" are in sync
4 ## Should be run from maintenance/postgres
5 ## Checks a few other things as well...
6
7 use strict;
8 use warnings;
9 use Data::Dumper;
10 use Cwd;
11
12 #check_valid_sql();
13
14 my @old = ('../tables.sql');
15 my $new = 'tables.sql';
16 my @xfile;
17
18 ## Read in exceptions and other metadata
19 my %ok;
20 while (<DATA>) {
21 next unless /^(\w+)\s*:\s*([^#]+)/;
22 my ($name,$val) = ($1,$2);
23 chomp $val;
24 if ($name eq 'RENAME') {
25 die "Invalid rename\n" unless $val =~ /(\w+)\s+(\w+)/;
26 $ok{OLD}{$1} = $2;
27 $ok{NEW}{$2} = $1;
28 next;
29 }
30 if ($name eq 'XFILE') {
31 push @xfile, $val;
32 next;
33 }
34 for (split /\s+/ => $val) {
35 $ok{$name}{$_} = 0;
36 }
37 }
38
39 my $datatype = join '|' => qw(
40 bool
41 tinyint int bigint real float
42 tinytext mediumtext text char varchar varbinary binary
43 timestamp datetime
44 tinyblob mediumblob blob
45 );
46 $datatype .= q{|ENUM\([\"\w\', ]+\)};
47 $datatype = qr{($datatype)};
48
49 my $typeval = qr{(\(\d+\))?};
50
51 my $typeval2 = qr{ signed| unsigned| binary| NOT NULL| NULL| PRIMARY KEY| AUTO_INCREMENT| default ['\-\d\w"]+| REFERENCES .+CASCADE};
52
53 my $indextype = join '|' => qw(INDEX KEY FULLTEXT), 'PRIMARY KEY', 'UNIQUE INDEX', 'UNIQUE KEY';
54 $indextype = qr{$indextype};
55
56 my $engine = qr{TYPE|ENGINE};
57
58 my $tabletype = qr{InnoDB|MyISAM|HEAP|HEAP MAX_ROWS=\d+|InnoDB MAX_ROWS=\d+ AVG_ROW_LENGTH=\d+};
59
60 my $charset = qr{utf8|binary};
61
62 open my $newfh, '<', $new or die qq{Could not open $new: $!\n};
63
64
65 my ($table,%old);
66
67 ## Read in the xfiles
68 my %xinfo;
69 for my $xfile (@xfile) {
70 print "Loading $xfile\n";
71 my $info = parse_sql($xfile);
72 for (keys %$info) {
73 $xinfo{$_} = $info->{$_};
74 }
75 }
76
77 for my $oldfile (@old) {
78 print "Loading $oldfile\n";
79 my $info = parse_sql($oldfile);
80 for (keys %xinfo) {
81 $info->{$_} = $xinfo{$_};
82 }
83 $old{$oldfile} = $info;
84 }
85
86 sub parse_sql {
87
88 my $oldfile = shift;
89
90 open my $oldfh, '<', $oldfile or die qq{Could not open $oldfile: $!\n};
91
92 my %info;
93 while (<$oldfh>) {
94 next if /^\s*\-\-/ or /^\s+$/;
95 s/\s*\-\- [\w ]+$//;
96 chomp;
97
98 if (/CREATE\s*TABLE/i) {
99 if (m{^CREATE TABLE /\*_\*/(\w+) \($}) {
100 $table = $1;
101 }
102 elsif (m{^CREATE TABLE /\*\$wgDBprefix\*/(\w+) \($}) {
103 $table = $1;
104 }
105 else {
106 die qq{Invalid CREATE TABLE at line $. of $oldfile\n};
107 }
108 $info{$table}{name}=$table;
109 }
110 elsif (m{^\) /\*\$wgDBTableOptions\*/}) {
111 $info{$table}{engine} = 'ENGINE';
112 $info{$table}{type} = 'variable';
113 }
114 elsif (/^\) ($engine)=($tabletype);$/) {
115 $info{$table}{engine}=$1;
116 $info{$table}{type}=$2;
117 }
118 elsif (/^\) ($engine)=($tabletype), DEFAULT CHARSET=($charset);$/) {
119 $info{$table}{engine}=$1;
120 $info{$table}{type}=$2;
121 $info{$table}{charset}=$3;
122 }
123 elsif (/^ (\w+) $datatype$typeval$typeval2{0,4},?$/) {
124 $info{$table}{column}{$1} = $2;
125 my $extra = $3 || '';
126 $info{$table}{columnfull}{$1} = "$2$extra";
127 }
128 elsif (m{^ UNIQUE KEY (\w+) \((.+?)\)}) {
129 }
130 elsif (m{^CREATE (?:UNIQUE )?(?:FULLTEXT )?INDEX /\*i\*/(\w+) ON /\*_\*/(\w+) \((.+?)\);}) {
131 }
132 elsif (m{^\s*PRIMARY KEY \([\w,]+\)}) {
133 }
134 else {
135 die "Cannot parse line $. of $oldfile:\n$_\n";
136 }
137
138 }
139 close $oldfh or die qq{Could not close "$oldfile": $!\n};
140
141 return \%info;
142
143 } ## end of parse_sql
144
145 for my $oldfile (@old) {
146
147 ## Begin non-standard indent
148
149 ## MySQL sanity checks
150 for my $table (sort keys %{$old{$oldfile}}) {
151 my $t = $old{$oldfile}{$table};
152 if ($t->{engine} eq 'TYPE') {
153 die "Invalid engine for $oldfile: $t->{engine}\n" unless $t->{name} eq 'profiling';
154 }
155 my $charset = $t->{charset} || '';
156 if ($oldfile !~ /binary/ and $charset eq 'binary') {
157 die "Invalid charset for $oldfile: $charset\n";
158 }
159 }
160
161 my $dtype = join '|' => qw(
162 SMALLINT INTEGER BIGINT NUMERIC SERIAL
163 TEXT CHAR VARCHAR
164 BYTEA
165 TIMESTAMPTZ
166 CIDR
167 );
168 $dtype = qr{($dtype)};
169 my %new;
170 my ($infunction,$inview,$inrule,$lastcomma) = (0,0,0,0);
171 seek $newfh, 0, 0;
172 while (<$newfh>) {
173 next if /^\s*\-\-/ or /^\s*$/;
174 s/\s*\-\- [\w ']+$//;
175 next if /^BEGIN;/ or /^SET / or /^COMMIT;/;
176 next if /^CREATE SEQUENCE/;
177 next if /^CREATE(?: UNIQUE)? INDEX/;
178 next if /^CREATE FUNCTION/;
179 next if /^CREATE TRIGGER/ or /^ FOR EACH ROW/;
180 next if /^INSERT INTO/ or /^ VALUES \(/;
181 next if /^ALTER TABLE/;
182 chomp;
183
184 if (/^\$mw\$;?$/) {
185 $infunction = $infunction ? 0 : 1;
186 next;
187 }
188 next if $infunction;
189
190 next if /^CREATE VIEW/ and $inview = 1;
191 if ($inview) {
192 /;$/ and $inview = 0;
193 next;
194 }
195
196 next if /^CREATE RULE/ and $inrule = 1;
197 if ($inrule) {
198 /;$/ and $inrule = 0;
199 next;
200 }
201
202 if (/^CREATE TABLE "?(\w+)"? \($/) {
203 $table = $1;
204 $new{$table}{name}=$table;
205 $lastcomma = 1;
206 }
207 elsif (/^\);$/) {
208 if ($lastcomma) {
209 warn "Stray comma before line $.\n";
210 }
211 }
212 elsif (/^ (\w+) +$dtype.*?(,?)(?: --.*)?$/) {
213 $new{$table}{column}{$1} = $2;
214 if (!$lastcomma) {
215 print "Missing comma before line $. of $new\n";
216 }
217 $lastcomma = $3 ? 1 : 0;
218 }
219 elsif (m{^\s*PRIMARY KEY \([\w,]+\)}) {
220 $lastcomma = 0;
221 }
222 else {
223 die "Cannot parse line $. of $new:\n$_\n";
224 }
225 }
226
227 ## Which column types are okay to map from mysql to postgres?
228 my $COLMAP = q{
229 ## INTS:
230 tinyint SMALLINT
231 int INTEGER SERIAL
232 bigint BIGINT
233 real NUMERIC
234 float NUMERIC
235
236 ## TEXT:
237 varchar(15) TEXT
238 varchar(32) TEXT
239 varchar(70) TEXT
240 varchar(255) TEXT
241 varchar TEXT
242 text TEXT
243 tinytext TEXT
244 ENUM TEXT
245
246 ## TIMESTAMPS:
247 varbinary(14) TIMESTAMPTZ
248 binary(14) TIMESTAMPTZ
249 datetime TIMESTAMPTZ
250 timestamp TIMESTAMPTZ
251
252 ## BYTEA:
253 mediumblob BYTEA
254
255 ## OTHER:
256 bool SMALLINT # Sigh
257
258 };
259 ## Allow specific exceptions to the above
260 my $COLMAPOK = q{
261 ## User inputted text strings:
262 ar_comment tinyblob TEXT
263 fa_description tinyblob TEXT
264 img_description tinyblob TEXT
265 ipb_reason tinyblob TEXT
266 log_action varbinary(32) TEXT
267 log_type varbinary(32) TEXT
268 oi_description tinyblob TEXT
269 rev_comment tinyblob TEXT
270 rc_log_action varbinary(255) TEXT
271 rc_log_type varbinary(255) TEXT
272
273 ## Simple text-only strings:
274 ar_flags tinyblob TEXT
275 cl_collation varbinary(32) TEXT
276 cl_sortkey varbinary(230) TEXT
277 ct_params blob TEXT
278 fa_minor_mime varbinary(100) TEXT
279 fa_storage_group varbinary(16) TEXT # Just 'deleted' for now, should stay plain text
280 fa_storage_key varbinary(64) TEXT # sha1 plus text extension
281 ipb_address tinyblob TEXT # IP address or username
282 ipb_range_end tinyblob TEXT # hexadecimal
283 ipb_range_start tinyblob TEXT # hexadecimal
284 img_minor_mime varbinary(100) TEXT
285 lc_lang varbinary(32) TEXT
286 lc_value varbinary(32) TEXT
287 img_sha1 varbinary(32) TEXT
288 iw_wikiid varchar(64) TEXT
289 job_cmd varbinary(60) TEXT # Should we limit to 60 as well?
290 keyname varbinary(255) TEXT # No tablename prefix (objectcache)
291 ll_lang varbinary(20) TEXT # Language code
292 lc_value mediumblob TEXT
293 log_params blob TEXT # LF separated list of args
294 log_type varbinary(10) TEXT
295 ls_field varbinary(32) TEXT
296 md_deps mediumblob TEXT # JSON
297 mr_blob mediumblob TEXT # JSON
298 mr_lang varbinary(32) TEXT
299 oi_minor_mime varbinary(100) TEXT
300 oi_sha1 varbinary(32) TEXT
301 old_flags tinyblob TEXT
302 old_text mediumblob TEXT
303 pp_propname varbinary(60) TEXT
304 pp_value blob TEXT
305 page_restrictions tinyblob TEXT # CSV string
306 pf_server varchar(30) TEXT
307 pr_level varbinary(60) TEXT
308 pr_type varbinary(60) TEXT
309 pt_create_perm varbinary(60) TEXT
310 pt_reason tinyblob TEXT
311 qc_type varbinary(32) TEXT
312 qcc_type varbinary(32) TEXT
313 qci_type varbinary(32) TEXT
314 rc_params blob TEXT
315 rlc_to_blob blob TEXT
316 ts_tags blob TEXT
317 ug_group varbinary(16) TEXT
318 ul_value blob TEXT
319 up_property varbinary(32) TEXT
320 up_value blob TEXT
321 user_email_token binary(32) TEXT
322 user_ip varbinary(40) TEXT
323 user_newpassword tinyblob TEXT
324 user_options blob TEXT
325 user_password tinyblob TEXT
326 user_token binary(32) TEXT
327 iwl_prefix varbinary(20) TEXT
328
329 ## Text URLs:
330 el_index blob TEXT
331 el_to blob TEXT
332 iw_api blob TEXT
333 iw_url blob TEXT
334 tb_url blob TEXT
335 tc_url varbinary(255) TEXT
336
337 ## Deprecated or not yet used:
338 ar_text mediumblob TEXT
339 job_params blob TEXT
340 log_deleted tinyint INTEGER # Not used yet, but keep it INTEGER for safety
341 rc_type tinyint CHAR
342
343 ## Number tweaking:
344 fa_bits int SMALLINT # bits per pixel
345 fa_height int SMALLINT
346 fa_width int SMALLINT # Hope we don't see an image this wide...
347 hc_id int BIGINT # Odd that site_stats is all bigint...
348 img_bits int SMALLINT # bits per image should stay sane
349 oi_bits int SMALLINT
350
351 ## True binary fields, usually due to gzdeflate and/or serialize:
352 math_inputhash varbinary(16) BYTEA
353 math_outputhash varbinary(16) BYTEA
354
355 ## Namespaces: not need for such a high range
356 ar_namespace int SMALLINT
357 job_namespace int SMALLINT
358 log_namespace int SMALLINT
359 page_namespace int SMALLINT
360 pl_namespace int SMALLINT
361 pt_namespace int SMALLINT
362 qc_namespace int SMALLINT
363 rc_namespace int SMALLINT
364 rd_namespace int SMALLINT
365 rlc_to_namespace int SMALLINT
366 tl_namespace int SMALLINT
367 wl_namespace int SMALLINT
368
369 ## Easy enough to change if a wiki ever does grow this big:
370 ss_active_users bigint INTEGER
371 ss_good_articles bigint INTEGER
372 ss_total_edits bigint INTEGER
373 ss_total_pages bigint INTEGER
374 ss_total_views bigint INTEGER
375 ss_users bigint INTEGER
376
377 ## True IP - keep an eye on these, coders tend to make textual assumptions
378 rc_ip varbinary(40) CIDR # Want to keep an eye on this
379
380 ## Others:
381 tc_time int TIMESTAMPTZ
382
383
384 };
385
386 my %colmap;
387 for (split /\n/ => $COLMAP) {
388 next unless /^\w/;
389 s/(.*?)#.*/$1/;
390 my ($col,@maps) = split / +/, $_;
391 for (@maps) {
392 $colmap{$col}{$_} = 1;
393 }
394 }
395
396 my %colmapok;
397 for (split /\n/ => $COLMAPOK) {
398 next unless /^\w/;
399 my ($col,$old,$new) = split / +/, $_;
400 $colmapok{$col}{$old}{$new} = 1;
401 }
402
403 ## Old but not new
404 for my $t (sort keys %{$old{$oldfile}}) {
405 if (!exists $new{$t} and !exists $ok{OLD}{$t}) {
406 print "Table not in $new: $t\n";
407 next;
408 }
409 next if exists $ok{OLD}{$t} and !$ok{OLD}{$t};
410 my $newt = exists $ok{OLD}{$t} ? $ok{OLD}{$t} : $t;
411 my $oldcol = $old{$oldfile}{$t}{column};
412 my $oldcolfull = $old{$oldfile}{$t}{columnfull};
413 my $newcol = $new{$newt}{column};
414 for my $c (keys %$oldcol) {
415 if (!exists $newcol->{$c}) {
416 print "Column $t.$c not in $new\n";
417 next;
418 }
419 }
420 for my $c (sort keys %$newcol) {
421 if (!exists $oldcol->{$c}) {
422 print "Column $t.$c not in $oldfile\n";
423 next;
424 }
425 ## Column types (roughly) match up?
426 my $new = $newcol->{$c};
427 my $old = $oldcolfull->{$c};
428
429 ## Known exceptions:
430 next if exists $colmapok{$c}{$old}{$new};
431
432 $old =~ s/ENUM.*/ENUM/;
433 if (! exists $colmap{$old}{$new}) {
434 print "Column types for $t.$c do not match: $old does not map to $new\n";
435 }
436 }
437 }
438 ## New but not old:
439 for (sort keys %new) {
440 if (!exists $old{$oldfile}{$_} and !exists $ok{NEW}{$_}) {
441 print "Not in $oldfile: $_\n";
442 next;
443 }
444 }
445
446
447 } ## end each file to be parsed
448
449
450 sub check_valid_sql {
451
452 ## Check for a few common problems in most php files
453
454 my $olddir = getcwd();
455 chdir("../..");
456 for my $basedir (qw/includes extensions/) {
457 scan_dir($basedir);
458 }
459 chdir $olddir;
460
461 return;
462
463 } ## end of check_valid_sql
464
465
466 sub scan_dir {
467
468 my $dir = shift;
469
470 opendir my $dh, $dir or die qq{Could not opendir $dir: $!\n};
471 #print "Scanning $dir...\n";
472 for my $file (grep { -f "$dir/$_" and /\.php$/ } readdir $dh) {
473 find_problems("$dir/$file");
474 }
475 rewinddir $dh;
476 for my $subdir (grep { -d "$dir/$_" and ! /\./ } readdir $dh) {
477 scan_dir("$dir/$subdir");
478 }
479 closedir $dh or die qq{Closedir failed: $!\n};
480 return;
481
482 } ## end of scan_dir
483
484 sub find_problems {
485
486 my $file = shift;
487 open my $fh, '<', $file or die qq{Could not open "$file": $!\n};
488 my $lastline = '';
489 my $inarray = 0;
490 while (<$fh>) {
491 if (/FORCE INDEX/ and $file !~ /Database\w*\.php/) {
492 warn "Found FORCE INDEX string at line $. of $file\n";
493 }
494 if (/REPLACE INTO/ and $file !~ /Database\w*\.php/) {
495 warn "Found REPLACE INTO string at line $. of $file\n";
496 }
497 if (/\bIF\s*\(/ and $file !~ /DatabaseMySQL\.php/) {
498 warn "Found IF string at line $. of $file\n";
499 }
500 if (/\bCONCAT\b/ and $file !~ /Database\w*\.php/) {
501 warn "Found CONCAT string at line $. of $file\n";
502 }
503 if (/\bGROUP\s+BY\s*\d\b/i and $file !~ /Database\w*\.php/) {
504 warn "Found GROUP BY # at line $. of $file\n";
505 }
506 if (/wfGetDB\s*\(\s+\)/io) {
507 warn "wfGETDB is missing parameters at line $. of $file\n";
508 }
509 if (/=\s*array\s*\(\s*$/) {
510 $inarray = 1;
511 next;
512 }
513 if ($inarray) {
514 if (/\s*\);\s*$/) {
515 $inarray = 0;
516 next;
517 }
518 next if ! /\w/ or /array\(\s*$/ or /^\s*#/ or m{^\s*//};
519 if (! /,/) {
520 my $nextline = <$fh>;
521 last if ! defined $nextline;
522 if ($nextline =~ /^\s*\)[;,]/) {
523 $inarray = 0;
524 next;
525 }
526 #warn "Array is missing a comma? Line $. of $file\n";
527 }
528 }
529 }
530 close $fh or die qq{Could not close "$file": $!\n};
531 return;
532
533 } ## end of find_problems
534
535
536 __DATA__
537 ## Known exceptions
538 OLD: searchindex ## We use tsearch2 directly on the page table instead
539 RENAME: user mwuser ## Reserved word causing lots of problems
540 RENAME: text pagecontent ## Reserved word
541 XFILE: ../archives/patch-profiling.sql