summaryrefslogtreecommitdiff
path: root/lib/sqitchtutorial-mysql.pod
blob: 71bae521f85601853fa95b56d7a188bccad22396 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
=encoding UTF-8

=head1 Name

sqitchtutorial-mysql - A tutorial introduction to Sqitch change management on MySQL

=head1 Synopsis

  sqitch *

=head1 Description

This tutorial explains how to create a sqitch-enabled MySQL 5.7 project, use a VCS
for deployment planning, and work with other developers to make sure changes
remain in sync and in the proper order.

We'll start by creating new project from scratch, a fictional antisocial
networking site called Flipr. All examples use L<Git|https://git-scm.com/> as
the VCS and L<MySQL|https://dev.mysql.com/> as the storage engine.

If you'd like to manage a PostgreSQL database, see L<sqitchtutorial>.

If you'd like to manage an SQLite database, see L<sqitchtutorial-sqlite>.

If you'd like to manage an Oracle database, see L<sqitchtutorial-oracle>.

If you'd like to manage a Firebird database, see L<sqitchtutorial-firebird>.

If you'd like to manage a Vertica database, see L<sqitchtutorial-vertica>.

If you'd like to manage an Exasol database, see L<sqitchtutorial-exasol>.

If you'd like to manage a Snowflake database, see L<sqitchtutorial-snowflake>.

=head1 Starting a New Project

Usually the first thing to do when starting a new project is to create a
source code repository. So let's do that with Git:

  > mkdir flipr
  > cd flipr
  > git init .
  Initialized empty Git repository in /flipr/.git/
  > touch README.md
  > git add .
  > git commit -am 'Initialize project, add README.'
  [main (root-commit) fdf2a40] Initialize project, add README.
   1 file changed, 38 insertions(+)
   create mode 100644 README.md

If you're a Git user and want to follow along the history, the repository used
in these examples is L<on GitHub|https://github.com/sqitchers/sqitch-mysql-intro>.

Now that we have a repository, let's get started with Sqitch. Every Sqitch
project must have a name associated with it, and, optionally, a unique URI. We
recommend including the URI, as it increases the uniqueness of object
identifiers internally, and will prevent the deployment of a different project
with the same name. So let's specify one when we initialize Sqitch:

  > sqitch init flipr --uri https://github.com/sqitchers/sqitch-mysql-intro/ --engine mysql
  Created sqitch.conf
  Created sqitch.plan
  Created deploy/
  Created revert/
  Created verify/

Let's have a look at F<sqitch.conf>:

  > cat sqitch.conf
  [core]
  	engine = mysql
  	# plan_file = sqitch.plan
  	# top_dir = .
  # [engine "mysql"]
  	# target = db:mysql:
  	# registry = sqitch
  	# client = mysql

Good, it picked up on the fact that we're creating changes for the MySQL
engine, thanks to the C<--engine mysql> option, and saved it to the file.
Furthermore, it wrote a commented-out C<[engine "mysql"]> section with all the
available MySQL engine-specific settings commented out and ready to be edited
as appropriate.

By default, Sqitch will read F<sqitch.conf> in the current directory for
settings. But it will also read F<~/.sqitch/sqitch.conf> for user-specific
settings. Since MySQL's
L<C<mysql client>|https://dev.mysql.com/doc/refman/5.7/en/mysql.html> is not
in the path on my system, let's go ahead an tell it where to find the client
on our computer (don't bother if you're using the
L<Docker image|https://hub.docker.com/r/sqitch/sqitch/> because it uses the
client inside the container, not on your host machine):

  > sqitch config --user engine.mysql.client /usr/local/mysql/bin/mysql

And let's also tell it who we are, since this data will be used in all
of our projects:

  > sqitch config --user user.name 'Marge N. O’Vera'
  > sqitch config --user user.email 'marge@example.com'

Have a look at F<~/.sqitch/sqitch.conf> and you'll see this:

  > cat ~/.sqitch/sqitch.conf
  [engine "mysql"]
  	client = /usr/local/mysql/bin/mysql
  [user]
  	name = Marge N. O’Vera
  	email = marge@example.com

Which means that Sqitch should be able to find C<mysql> for any project, and
that it will always properly identify us when planning and committing changes.

Back to the repository. Have a look at the plan file, F<sqitch.plan>:

  > cat sqitch.plan
  %syntax-version=1.0.0
  %project=flipr
  %uri=https://github.com/sqitchers/sqitch-mysql-intro/


Note that it has picked up on the name and URI of the app we're building.
Sqitch uses this data to manage cross-project dependencies. The
C<%syntax-version> pragma is always set by Sqitch, so that it always knows how
to parse the plan, even if the format changes in the future.

Let's commit these changes and start creating the database changes.

  > git add .
  > git commit -am 'Initialize Sqitch configuration.'
  [main 79fe2cc] Initialize Sqitch configuration.
   2 files changed, 19 insertions(+)
   create mode 100644 sqitch.conf
   create mode 100644 sqitch.plan

=head1 Our First Change

First, our app will need a database user, so let's create one. Run this
command:

  > sqitch add appuser -n 'Creates a an application user.'
  Created deploy/appuser.sql
  Created revert/appuser.sql
  Created verify/appuser.sql
  Added "appuser" to sqitch.plan

The L<C<add>|sqitch-add> command adds a database change to the plan and writes
deploy, revert, and verify scripts that represent the change. Now we edit
these files. The C<deploy> script's job is to create the table. By default,
the F<deploy/appuser.sql> file looks like this:

  -- Deploy flipr:appuser to mysql

  BEGIN;

  -- XXX Add DDLs here.

  COMMIT;

What we want to do is to replace the C<XXX> comment with the C<CREATE USER>
statement, like so:

  -- Deploy flipr:users to mysql

  BEGIN;

  CREATE USER flipr;

  COMMIT;

The C<revert> script's job is to precisely revert the change to the deploy
script, so we edit this to F<revert/appuser.sql> to look like this:

  -- Revert flipr:users from mysql

  BEGIN;

  DROP USER flipr;

  COMMIT;

Now we can try deploying this change. First, we need to create a database
to deploy to:

  > mysql -u root --execute 'CREATE DATABASE flipr_test'

Now we tell Sqitch where to send the change via a
L<database URI|https://github.com/libwww-perl/uri-db/>:

  > sqitch deploy db:mysql://root@/flipr_test
  Deploying changes to db:mysql://root@/flipr_test
    + appuser .. ok

First Sqitch created the registry database and tables used to track database
changes. The registry database is separate from the database to which the
C<appuser> change was deployed; by default, its name is C<sqitch>, and will be
used to manage I<all> projects on a single MySQL server. Ideally, only Sqitch
data will be stored in this database, so it probably makes the most sense to
create a superuser named C<sqitch> or something similar and use it to deploy
changes.

If you'd like it to use a different database as the registry database, use
C<sqitch engine add mysql $name> to configure it (or via the
L<C<target> command|sqitch-target>; more L<below|/On Target>). This will be
useful if you don't want to use the same registry database to manage multiple
databases on the same server.

Next, Sqitch deploys changes to the target database, which we specified on the
command-line. We only have one change so far; the C<+> reinforces the idea
that the change is being I<added> to the database.

With this change deployed, if you connect to the database, you'll be able to
see the user:

  > mysql -u root --execute "SELECT user from mysql.user WHERE user = 'flipr';"
  +-------+
  | User  |
  +-------+
  | flipr |
  +-------+

=head2 Trust, But Verify

But that's too much work. do you really want to do something like that after
every deploy?

Here's where the C<verify> script comes in. Its job is to test that the deploy
did was it was supposed to. It should do so without regard to any data that
might be in the database, and should throw an error if the deploy was not
successful. The simplest way to see if a user exists is to check the
C<mysql.user> table. However, throwing an error in the event that the user
does not exist is tricky in MySQL. To simplify things, on MySQL 5.5.0 and
higher, Sqitch provides a custom function you can use in your tests,
C<checkit()>. It works kind of like a C<CHECK> constraint in other databases:
pass an expression as the first argument, and an error message as the second.
If the expression evaluates to false, an exception will be thrown with the
error message.

Give it a try. Put this query into F<verify/appuser.sql>:

  SELECT sqitch.checkit(COUNT(*), 'User "flipr" does not exist')
    FROM mysql.user WHERE user = 'flipr';

This will work well as long as we know that the registry database is named
C<sqitch>. If you've set C<engine.mysql.registry> to a different value, you
will need to make sure you specify the correct database name in the script.

Now you can run the C<verify> script with the L<C<verify>|sqitch-verify>
command:

  > sqitch verify db:mysql://root@/flipr_test
  Verifying flipr_test
    * appuser .. ok
  Verify successful

Looks good! If you want to make sure that the verify script correctly dies if
the table doesn't exist, temporarily change the user name in the script to
something that doesn't exist, something like:

  SELECT sqitch.checkit(COUNT(*), 'User "flipr" does not exist')
    FROM mysql.user WHERE user = 'nonesuch';

Then L<C<verify>|sqitch-verify> again:

  > sqitch verify db:mysql://root@/flipr_test
  Verifying db:mysql://root@/flipr_test
    * appuser .. ERROR 1644 (ERR0R) at line 5 in file: 'verify/appuser.sql': User "flipr" does not exist
  # Verify script "verify/appuser.sql" failed.
  not ok

  Verify Summary Report
  ---------------------
  Changes: 1
  Errors:  1
  Verify failed

The C<checkit()> function is kind enough to use the error message to tell us
what the problem is. Don't forget to change the table name back before
continuing!

=head2 Status, Revert, Log, Repeat

For purely informational purposes, we can always see how a deployment was
recorded via the L<C<status>|sqitch-status> command, which reads the tables
from the registry database:

  > sqitch status db:mysql://root@/flipr_test
  # On database db:mysql://root@/flipr_test
  # Project:  flipr
  # Change:   f56dd1a1ab029f398cec2cebb2ecc527fa0332c2
  # Name:     appuser
  # Deployed: 2013-12-31 13:13:17 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Let's make sure that we can revert the change:

  > sqitch revert db:mysql://root@/flipr_test
  Revert all changes from db:mysql://root@/flipr_test? [Yes] 
    - appuser .. ok

The L<C<revert>|sqitch-revert> command first prompts to make sure that we
really do want to revert. This is to prevent unnecessary accidents. You can
pass the C<-y> option to disable the prompt. Also, notice the C<-> before the
change name in the output, which reinforces that the change is being
I<removed> from the database. And now the schema should be gone:

  > mysql -u root --execute "SELECT user from mysql.user WHERE user = 'flipr';"

And the status message should reflect as much:

  > sqitch status db:mysql://root@/flipr_test
  # On database db:mysql://root@/flipr_test
  No changes deployed

Of course, since nothing is deployed, the L<C<verify>|sqitch-verify> command
has nothing to verify:

  > sqitch verify db:mysql://root@/flipr_test
  Verifying db:mysql://root@/flipr_test
  No changes deployed

However, we still have a record that the change happened, visible via the
L<C<log>|sqitch-log> command:

  > sqitch log db:mysql://root@/flipr_test
  On database db:mysql://root@/flipr_test
  Revert f56dd1a1ab029f398cec2cebb2ecc527fa0332c2
  Name:      appuser
  Committer: Marge N. O’Vera <marge@example.com>
  Date:      2013-12-31 13:26:39 -0800

      Creates a an application user.

  Deploy f56dd1a1ab029f398cec2cebb2ecc527fa0332c2
  Name:      appuser
  Committer: Marge N. O’Vera <marge@example.com>
  Date:      2013-12-31 13:13:17 -0800

      Creates a an application user.

Note that the actions we took are shown in reverse chronological order, with
the revert first and then the deploy.

Cool. Now let's commit it.

  > git add .
  > git commit -m 'Add the "flipr" user.'
  [main c63acb9] Add the "flipr" user.
   4 files changed, 23 insertions(+)
   create mode 100644 deploy/appuser.sql
   create mode 100644 revert/appuser.sql
   create mode 100644 verify/appuser.sql

And then deploy again. This time, let's use the C<--verify> option, so that
the C<verify> script is applied when the change is deployed:

  > sqitch deploy --verify db:mysql://root@/flipr_test
  Deploying changes to db:mysql://root@/flipr_test
    + appuser .. ok

And now the C<flipr> user should be back:

  > mysql -u root --execute "SELECT user from mysql.user WHERE user = 'flipr';"
  +-------+
  | user  |
  +-------+
  | flipr |
  +-------+

When we look at the status, the deployment will be there:

  > sqitch status db:mysql://root@/flipr_test
  # On database db:mysql://root@/flipr_test
  # Project:  flipr
  # Change:   f56dd1a1ab029f398cec2cebb2ecc527fa0332c2
  # Name:     appuser
  # Deployed: 2013-12-31 13:28:23 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

=head1 On Target

I'm getting a little tired of always having to type
C<db:mysql://root@/flipr_test>, aren't you?  This
L<database connection URI|https://github.com/libwww-perl/uri-db/> tells Sqitch how
to connect to the deployment target, but we don't have to keep using the URI.
We can name the target:

  > sqitch target add flipr_test db:mysql://root@/flipr_test

The L<C<target>|sqitch-target> command, inspired by
L<C<git-remote>|https://git-scm.com/docs/git-remote>, allows management of one
or more named deployment targets. We've just added a target named
C<flipr_test>, which means we can use the string C<flipr_test> for the target,
rather than the URI. But since we're doing so much testing, we can also tell
Sqitch to deploy to the C<flipr_test> target by default:

  > sqitch engine add mysql flipr_test

Now we can omit the target argument altogether, unless we need to deploy to
another database. Which we will, eventually, but at least our examples will be
simpler from here on in, e.g.:

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   f56dd1a1ab029f398cec2cebb2ecc527fa0332c2
  # Name:     appuser
  # Deployed: 2013-12-31 13:28:23 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Yay, that allows things to be a little more concise. Let's also make sure that
changes are verified after deploying them:

  > sqitch config --bool deploy.verify true
  > sqitch config --bool rebase.verify true

We'll see the L<C<rebase>|sqitch-rebase> command a bit later. In the meantime,
let's commit the new configuration and and make some more changes!

  > git commit -am 'Set default target and always verify.'
  [main c793050] Set default target and always verify.
   1 file changed, 8 insertions(+)

=head1 Deploy with Dependency

Let's add another change, this time to create a table. Our app will need
users, of course, so we'll create a table for them. First, add the new change:

  > sqitch add users --requires appuser -n 'Creates table to track our users.'
  Created deploy/users.sql
  Created revert/users.sql
  Created verify/users.sql
  Added "users [appuser]" to sqitch.plan

Note that we're requiring the C<appuser> change as a dependency of the new
C<users> change. Although that change has already been added to the plan and
therefore should always be applied before the C<users> change, it's a good
idea to be explicit about dependencies.

Now edit the scripts. When you're done, F<deploy/users.sql> should look like
this:

  -- Deploy flipr:users to mysql
  -- requires: appuser

  BEGIN;

  CREATE TABLE users (
      nickname  VARCHAR(512) PRIMARY KEY,
      password  VARCHAR(512) NOT NULL,
      timestamp DATETIME(6)  NOT NULL
  );

  GRANT SELECT ON TABLE users TO flipr;

  COMMIT;

A few things to notice here. On the second line, the dependence on the
C<appuser> change has been listed. This doesn't do anything, but the default
MySQL C<deploy> template lists it here for your reference while editing the
file. Useful, right?

The C<flipr> user has been granted C<SELECT> access to the table. The app
needs to read the data, right? This is why we need to require the C<appuser>
change.

Now for the verify script. The simplest way to check that the table was
created and has the expected columns without touching the data? Just select
from the table with a false C<WHERE> clause. Add this to F<verify/users.sql>:

  SELECT nickname, password, timestamp
    FROM users
   WHERE 0;

Now for the revert script: all we have to do is drop the table. Add this to
F<revert/users.sql>:

  DROP TABLE users;

Couldn't be much simpler, right? Let's deploy this bad boy:

  > sqitch deploy
  Deploying changes to flipr_test
    + users .. ok

We know, since verification is enabled, that the table must have been created.
But for the purposes of visibility, let's have a quick look:

  > mysql -u root -D flipr_test --execute 'SHOW TABLES'
  +----------------------+
  | Tables_in_flipr_test |
  +----------------------+
  | users                |
  +----------------------+

We can also verify all currently deployed changes with the
L<C<verify>|sqitch-verify> command:

  > sqitch verify
  Verifying flipr_test
    * appuser .. ok
    * users .... ok
  Verify successful

Now have a look at the status:

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   2bd1190fdb324c2609f0c7f0cef73d8cb434ba0e
  # Name:     users
  # Deployed: 2013-12-31 13:34:25 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Success! Let's make sure we can revert the change, as well:

  > sqitch revert --to @HEAD^ -y
  Reverting changes to appuser from flipr_test
    - users .. ok

Note that we've used the C<--to> option to specify the change to revert to.
And what do we revert to? The symbolic tag C<@HEAD>, when passed to
L<C<revert>|sqitch-revert>, always refers to the last change deployed to the
database. (For other commands, it refers to the last change in the plan.)
Appending the caret (C<^>) tells Sqitch to select the change I<prior> to the
last deployed change. So we revert to C<appuser>, the penultimate change. The
other potentially useful symbolic tag is C<@ROOT>, which refers to the first
change deployed to the database (or in the plan, depending on the command).

Back to the database. The C<users> table should be gone but the C<flipr> user
should still be around:

  > mysql -u root -D flipr_test --execute 'SHOW TABLES'
  > mysql -u root --execute "SELECT user from mysql.user WHERE user = 'flipr';"
  +-------+
  | User  |
  +-------+
  | flipr |
  +-------+

The L<C<status>|sqitch-status> command politely informs us that we have
undeployed changes:

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   f56dd1a1ab029f398cec2cebb2ecc527fa0332c2
  # Name:     appuser
  # Deployed: 2013-12-31 13:28:23 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Undeployed change:
    * users

As does the L<C<verify>|sqitch-verify> command:

  > sqitch verify
  Verifying flipr_test
    * appuser .. ok
  Undeployed change:
    * users
  Verify successful

Note that the verify is successful, because all currently-deployed changes are
verified. The list of undeployed changes (just "users" here) reminds us about
the current state.

Okay, let's commit and deploy again:

  > git add .
  > git commit -am 'Add users table.'
  [main 7c99fb0] Add users table.
   4 files changed, 31 insertions(+)
   create mode 100644 deploy/users.sql
   create mode 100644 revert/users.sql
   create mode 100644 verify/users.sql
  > sqitch deploy
  Deploying changes to flipr_test
    + users .. ok

Looks good. Check the status:

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   2bd1190fdb324c2609f0c7f0cef73d8cb434ba0e
  # Name:     users
  # Deployed: 2013-12-31 13:37:02 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Excellent. Let's do some more!

=head1 Add Two at Once

Let's add a couple more changes to add functions for managing users.

  > sqitch add insert_user --requires users --requires appuser \
    -n 'Creates a function to insert a user.'
  Created deploy/insert_user.sql
  Created revert/insert_user.sql
  Created verify/insert_user.sql
  Added "insert_user [users appuser]" to sqitch.plan

  > sqitch add change_pass --requires users --requires appuser \
    -n 'Creates a function to change a user password.'
  Created deploy/change_pass.sql
  Created revert/change_pass.sql
  Created verify/change_pass.sql
  Added "change_pass [users appuser]" to sqitch.plan

Now might be a good time to have a look at the deployment plan:

  > cat sqitch.plan
  %syntax-version=1.0.0
  %project=flipr
  %uri=https://github.com/sqitchers/sqitch-mysql-intro/

  appuser 2013-12-31T21:04:04Z Marge N. O’Vera <marge@example.com> # Creates a an application user.
  users [appuser] 2013-12-31T21:32:48Z Marge N. O’Vera <marge@example.com> # Creates table to track our users.
  insert_user [users appuser] 2013-12-31T21:37:29Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a user.
  change_pass [users appuser] 2013-12-31T21:37:36Z Marge N. O’Vera <marge@example.com> # Creates a function to change a user password.

Each change appears on a single line with the name of the change, a bracketed
list of dependencies, a timestamp, the name and email address of the user who
planned the change, and a note.

Let's write the code for the new changes. Here's what
F<deploy/insert_user.sql> should look like:

  -- Deploy flipr:insert_user to mysql
  -- requires: users
  -- requires: appuser

  BEGIN;

  DELIMITER //

  CREATE PROCEDURE insert_user(
      nickname VARCHAR(512),
      password VARCHAR(512)
  ) SQL SECURITY DEFINER
  BEGIN
      INSERT INTO users (nickname, password, timestamp)
      VALUES (nickname, md5(password), UTC_TIMESTAMP(6));
  END
  //

  DELIMITER ;

  GRANT EXECUTE ON PROCEDURE insert_user to flipr;

  COMMIT;

Here's what F<verify/insert_user.sql> might look like, using the Sqitch
C<checkit()> function again:

  -- Verify flipr:insert_user on mysql

  BEGIN;

  SELECT sqitch.checkit(COUNT(*), 'Procedure "insert_user" does not exist')
    FROM information_schema.routines
   WHERE routine_schema = database()
     AND routine_name = 'insert_user';

  ROLLBACK;

We simply take advantage of the fact that the new procedure should be listed
in the C<information_schema.routines> table and throw an exception if it does not exist.

And F<revert/insert_user.sql> should look something like this:

  -- Revert flipr:insert_user from mysql
  BEGIN;
  DROP PROCEDURE insert_user;
  COMMIT;

Now for C<change_pass>; F<deploy/change_pass.sql> might look like this:

  -- Deploy flipr:change_pass to mysql
  -- requires: users
  -- requires: appuser

  BEGIN;

  DELIMITER //

  CREATE FUNCTION change_pass(
      nickname VARCHAR(512),
      oldpass  VARCHAR(512),
      newpass  VARCHAR(512)
  ) RETURNS INTEGER DETERMINISTIC SQL SECURITY DEFINER
  BEGIN
      UPDATE users
         SET password = md5(newpass)
       WHERE nickname = nickname
         AND password = md5(oldpass);
      RETURN ROW_COUNT();
  END;
  //

  DELIMITER ;

  GRANT EXECUTE ON FUNCTION change_pass to flipr;

  COMMIT;

Use C<checkit()> in F<verify/change_pass.sql> again:

  BEGIN;
  SELECT sqitch.checkit(COUNT(*), 'Procedure "change_pass" does not exist')
    FROM information_schema.routines
   WHERE routine_schema = database()
     AND routine_name = 'change_pass';
  COMMIT;

And of course, its C<revert> script, F<revert/change_pass.sql>, should look
something like:

  -- Revert flipr:change_pass from mysql
  BEGIN;
  DROP FUNCTION change_pass;
  COMMIT;

Try em out!

  > sqitch deploy
  Deploying changes to flipr_test
    + insert_user .. ok
    + change_pass .. ok

Do we have the functions? Of course we do, they were verified. Still, have a
look:

  > mysql -u root --execute "SELECT routine_name FROM information_schema.routines WHERE routine_schema = 'flipr_test'"
  +--------------+
  | routine_name |
  +--------------+
  | change_pass  |
  | insert_user  |
  +--------------+

And what's the status?

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   b0a598b91ce97cf1b95ded97a6452bf03231a2cd
  # Name:     change_pass
  # Deployed: 2013-12-31 13:39:49 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Looks good. Let's make sure revert works:

  > sqitch revert -y --to @HEAD^^
  Reverting changes to users from flipr_test
    - change_pass .. ok
    - insert_user .. ok
  > mysql -u root --execute "SELECT routine_name FROM information_schema.routines WHERE routine_schema = 'flipr_test'"

Note the use of C<@HEAD^^> to specify that the revert be to two changes prior
the last deployed change. Looks good. Let's do the commit and re-deploy dance:

  > git add .
  > git commit -m 'Add `insert_user()` and `change_pass()`.'
  [main 0f95e13] Add `insert_user()` and `change_pass()`.
   7 files changed, 86 insertions(+)
   create mode 100644 deploy/change_pass.sql
   create mode 100644 deploy/insert_user.sql
   create mode 100644 revert/change_pass.sql
   create mode 100644 revert/insert_user.sql
   create mode 100644 verify/change_pass.sql
   create mode 100644 verify/insert_user.sql

  > sqitch deploy
  Deploying changes to flipr_test
    + insert_user .. ok
    + change_pass .. ok

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   b0a598b91ce97cf1b95ded97a6452bf03231a2cd
  # Name:     change_pass
  # Deployed: 2013-12-31 13:40:40 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

  > sqitch verify
  Verifying flipr_test
    * appuser ...... ok
    * users ........ ok
    * insert_user .. ok
    * change_pass .. ok
  Verify successful

Great, we're fully up-to-date!

=head1 Ship It!

Let's do a first release of our app. Let's call it C<1.0.0-dev1> Since we want
to have it go out with deployments tied to the release, let's tag it:

  > sqitch tag v1.0.0-dev1 -n 'Tag v1.0.0-dev1.'
  Tagged "change_pass" with @v1.0.0-dev1
  > git commit -am 'Tag the database with v1.0.0-dev1.'
  [main 0595297] Tag the database with v1.0.0-dev1.
   1 file changed, 1 insertion(+)
  > git tag v1.0.0-dev1 -am 'Tag v1.0.0-dev1'

Now let's bundle everything up for release:

  > sqitch bundle
  Bundling into bundle/
  Writing config
  Writing plan
  Writing scripts
    + appuser
    + users
    + insert_user
    + change_pass @v1.0.0-dev1

Now we can package the F<bundle> directory and distribute it. When it gets
installed somewhere, users can use Sqitch to deploy to the database. We ought
to try deploying it, but first we'll need to revert our existing databases, as
a single Sqitch project cannot be deployed to two databases on the same server
unless it uses a different registry database and the C<checkit()> function is
not used in verify scripts. We have used C<checkit()> quite a bit, so we need
to keep the Sqitch database name just where it is. Fortunately, it's easy to
build the database again, so let's just revert it.

  > sqitch revert -y
  Reverting all changes from flipr_test
    - change_pass .. ok
    - insert_user .. ok
    - users ........ ok
    - appuser ...... ok

Now we can try deploying the bundle:

  > cd bundle
  > mysql -u root --execute 'CREATE DATABASE flipr_dev'
  > sqitch deploy db:mysql://root@/flipr_dev
  Deploying changes to db:mysql://root@/flipr_dev
    + appuser ................... ok
    + users ..................... ok
    + insert_user ............... ok
    + change_pass @v1.0.0-dev1 .. ok

Great, all four changes were deployed and C<change_pass> was tagged with
C<@v1.0.0-dev1>. Let's have a look at the status:

  > sqitch status db:mysql://root@/flipr_dev
  # On database db:mysql://root@/flipr_dev
  # Project:  flipr
  # Change:   b0a598b91ce97cf1b95ded97a6452bf03231a2cd
  # Name:     change_pass
  # Tag:      @v1.0.0-dev1
  # Deployed: 2013-12-31 13:44:04 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Looks good, eh? Go ahead and revert it:

  > sqitch revert -y db:mysql://root@/flipr_dev
  Reverting all changes from db:mysql://root@/flipr_dev
    - change_pass @v1.0.0-dev1 .. ok
    - insert_user ............... ok
    - users ..................... ok
    - appuser ................... ok

Now package it up and ship it!

  > cd ..
  > mv bundle flipr-v1.0.0-dev1
  > tar -czf flipr-v1.0.0-dev1.tgz flipr-v1.0.0-dev1

=head1 Flip Out

Now that we've got the basics of user management done, let's get to work on
the core of our product, the "flip." Since other folks are working on other
tasks in the repository, we'll work on a branch, so we can all stay out of
each other's way. So let's branch:

  > git checkout -b flips
  Switched to a new branch 'flips'

Now we can add a new change to create a table for our flips.

  > sqitch add flips -r appuser -r users -n 'Adds table for storing flips.'
  Created deploy/flips.sql
  Created revert/flips.sql
  Created verify/flips.sql
  Added "flips [appuser users]" to sqitch.plan

You know the drill by now. Edit F<deploy/flips.sql>:

  -- Deploy flipr:flips to mysql
  -- requires: appuser
  -- requires: users

  BEGIN;

  CREATE TABLE flips (
      id        BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT,
      nickname  VARCHAR(512) NOT NULL REFERENCES users(nickname),
      body      VARCHAR(180) NOT NULL,
      timestamp DATETIME(6)  NOT NULL
  );

  GRANT SELECT ON TABLE flips TO flipr;

  COMMIT;

Edit F<verify/flips.sql>:

  -- Verify flipr:flips on mysql

  BEGIN;

  SELECT id
       , nickname
       , body
       , timestamp
    FROM flipr.flips
   WHERE 0;

  ROLLBACK;

And edit F<revert/flips.sql>:

  -- Revert flipr:flips from mysql

  BEGIN;

  DROP TABLE flips;

  COMMIT;

And give it a whirl:

  > sqitch deploy
  Deploying changes to flipr_test
    + appuser ................... ok
    + users ..................... ok
    + insert_user ............... ok
    + change_pass @v1.0.0-dev1 .. ok

Look good?

  > sqitch status --show-tags
  # On database flipr_test
  # Project:  flipr
  # Change:   b3ccd37da58ac232c23edfa0adaf2d6f483842fd
  # Name:     flips
  # Deployed: 2013-12-31 13:55:04 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  # Tag:
  #   @v1.0.0-dev1 - 2013-12-31 13:55:04 -0800 - Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Note the use of C<--show-tags> to show all the deployed tags. Now make it so:

  > git add .
  > git commit -am 'Add flips table.'
  [flips ce1b53d] Add flips table.
   4 files changed, 37 insertions(+)
   create mode 100644 deploy/flips.sql
   create mode 100644 revert/flips.sql
   create mode 100644 verify/flips.sql

=head1 Wash, Rinse, Repeat

Now comes the time to add functions to manage flips. I'm sure you have things
nailed down now. Go ahead and add C<insert_flip> and C<delete_flip> changes
and commit them. The C<insert_flip> deploy script might look something like:

  -- Deploy flipr:insert_flip to mysql
  -- requires: flips
  -- requires: appuser

  BEGIN;

  DELIMITER //

  CREATE FUNCTION insert_flip(
      nickname VARCHAR(512),
      body     VARCHAR(180)
  ) RETURNS BIGINT DETERMINISTIC SQL SECURITY DEFINER
  BEGIN
      INSERT INTO flips (nickname, body)
      VALUES (nickname, body);
      RETURN LAST_INSERT_ID();
  END;
  //

  DELIMITER ;

  GRANT EXECUTE ON FUNCTION insert_flip to flipr;

  COMMIT;

And the C<delete_flip> deploy script might look something like:

  -- Deploy flipr:delete_flip to mysql
  -- requires: flips
  -- requires: appuser

  BEGIN;

  DELIMITER //

  CREATE FUNCTION delete_flip(
      flip_id BIGINT
  ) RETURNS INTEGER DETERMINISTIC SQL SECURITY DEFINER
  BEGIN
      DELETE FROM flips WHERE id = flip_id;
      RETURN ROW_COUNT();
  END;
  //

  DELIMITER ;

  GRANT EXECUTE ON FUNCTION delete_flip to flipr;

  COMMIT;

The C<verify> scripts are:

  -- Verify flipr:insert_flip on mysql

  BEGIN;

  SELECT sqitch.checkit(COUNT(*), 'Function "insert_flip" does not exist')
    FROM information_schema.routines
   WHERE routine_schema = database()
     AND routine_name = 'insert_flip';

  ROLLBACK;

And:

  -- Verify flipr:delete_flip on mysql

  BEGIN;

  SELECT sqitch.checkit(COUNT(*), 'Function "delete_flip" does not exist')
    FROM information_schema.routines
   WHERE routine_schema = database()
     AND routine_name = 'delete_flip';

  ROLLBACK;

The C<revert> scripts are:

  -- Revert flipr:insert_flip from mysql

  BEGIN;

  DROP FUNCTION insert_flip;

  COMMIT;

And:

  -- Revert flipr:delete_flip from mysql

  BEGIN;

  DROP FUNCTION delete_flip;

  COMMIT;

Check the L<example git repository|https://github.com/sqitchers/sqitch-intro> for
the complete details. Test L<C<deploy>|sqitch-deploy> and
L<C<revert>|sqitch-revert>, then commit it to the repository. The status
should end up looking something like this:

  > sqitch status --show-tags
  # On database flipr_test
  # Project:  flipr
  # Change:   7bf30e6b7b0a4e61f30dd4148f5b837bdddae086
  # Name:     delete_flip
  # Deployed: 2013-12-31 13:58:54 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  # Tag:
  #   @v1.0.0-dev1 - 2013-12-31 13:55:04 -0800 - Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Good, we've finished this feature. Time to merge back into C<main>.

=head2 Emergency

Let's do it:

  > git checkout main
  Switched to branch 'main'
  > git pull
  Updating 0595297..5a58089
  Fast-forward
   deploy/delete_list.sql | 22 ++++++++++++++++++++++
   deploy/insert_list.sql | 25 +++++++++++++++++++++++++
   deploy/lists.sql       | 17 +++++++++++++++++
   revert/delete_list.sql |  7 +++++++
   revert/insert_list.sql |  7 +++++++
   revert/lists.sql       |  7 +++++++
   sqitch.plan            |  4 ++++
   verify/delete_list.sql | 10 ++++++++++
   verify/insert_list.sql | 10 ++++++++++
   verify/lists.sql       |  8 ++++++++
   10 files changed, 117 insertions(+)
   create mode 100644 deploy/delete_list.sql
   create mode 100644 deploy/insert_list.sql
   create mode 100644 deploy/lists.sql
   create mode 100644 revert/delete_list.sql
   create mode 100644 revert/insert_list.sql
   create mode 100644 revert/lists.sql
   create mode 100644 verify/delete_list.sql
   create mode 100644 verify/insert_list.sql
   create mode 100644 verify/lists.sql

Hrm, that's interesting. Looks like someone made some changes to C<main>.
They added list support. Well, let's see what happens when we merge our
changes.

  > git merge --no-ff flips
  Auto-merging sqitch.plan
  CONFLICT (content): Merge conflict in sqitch.plan
  Automatic merge failed; fix conflicts and then commit the result.

Oh, a conflict in F<sqitch.plan>. Not too surprising, since both the merged
C<lists> branch and our C<flips> branch added changes to the plan. Let's try a
different approach.

The truth is, we got lazy. Those changes when we pulled main from the origin
should have raised a red flag. It's considered a bad practice not to look at
what's changed in C<main> before merging in a branch. What one I<should> do
is either:

=over

=item *

Rebase the F<flips> branch from main before merging. This "rewinds" the
branch changes, pulls from C<main>, and then replays the changes back on top
of the pulled changes.

=item *

Create a patch and apply I<that> to main. This is the sort of thing you
might have to do if you're sending changes to another user, especially if the
VCS is not Git.

=back

So let's restore things to how they were at main:

  > git reset --hard HEAD
  HEAD is now at 5a58089 Merge branch 'lists'

That throws out our botched merge. Now let's go back to our branch and rebase
it on C<main>:

  > git checkout flips
  Switched to branch 'flips'
  > git rebase main
  First, rewinding head to replay your work on top of it...
  Applying: Add flips table.
  Using index info to reconstruct a base tree...
  M	sqitch.plan
  Falling back to patching base and 3-way merge...
  Auto-merging sqitch.plan
  CONFLICT (content): Merge conflict in sqitch.plan
  Failed to merge in the changes.
  Patch failed at 0001 Add flips table.
  The copy of the patch that failed is found in:
     .git/rebase-apply/patch

  When you have resolved this problem, run "git rebase --continue".
  If you prefer to skip this patch, run "git rebase --skip" instead.
  To check out the original branch and stop rebasing, run "git rebase --abort".

Oy, that's kind of a pain. It seems like no matter what we do, we'll need to
resolve conflicts in that file. Except in Git. Fortunately for us, we can tell
Git to resolve conflicts in F<sqitch.plan> differently. Because we only ever
append lines to the file, we can have it use the "union" merge driver, which,
according to L<its
docs|https://git-scm.com/docs/gitattributes#_built-in_merge_drivers>:

=over

Run 3-way file level merge for text files, but take lines from both versions,
instead of leaving conflict markers. This tends to leave the added lines in
the resulting file in random order and the user should verify the result. Do
not use this if you do not understand the implications.

=back

This has the effect of appending lines from all the merging files, which is
exactly what we need. So let's give it a try. First, back out the botched
rebase:

  > git rebase --abort

Now add the union merge driver to F<.gitattributes> for F<sqitch.plan>
and rebase again:

  > echo sqitch.plan merge=union > .gitattributes
  > git rebase main
  First, rewinding head to replay your work on top of it...
  Applying: Add flips table.
  Using index info to reconstruct a base tree...
  M	sqitch.plan
  Falling back to patching base and 3-way merge...
  Auto-merging sqitch.plan
  Applying: Add functions to insert and delete flips.
  Using index info to reconstruct a base tree...
  M	sqitch.plan
  Falling back to patching base and 3-way merge...
  Auto-merging sqitch.plan

Ah, that looks a bit better. Let's have a look at the plan:

  > cat sqitch.plan
  %syntax-version=1.0.0
  %project=flipr
  %uri=https://github.com/sqitchers/sqitch-mysql-intro/

  appuser 2013-12-31T21:04:04Z Marge N. O’Vera <marge@example.com> # Creates a an application user.
  users [appuser] 2013-12-31T21:32:48Z Marge N. O’Vera <marge@example.com> # Creates table to track our users.
  insert_user [users appuser] 2013-12-31T21:37:29Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a user.
  change_pass [users appuser] 2013-12-31T21:37:36Z Marge N. O’Vera <marge@example.com> # Creates a function to change a user password.
  @v1.0.0-dev1 2013-12-31T21:41:08Z Marge N. O’Vera <marge@example.com> # Tag v1.0.0-dev1.

  lists [appuser users] 2013-12-31T21:46:22Z Marge N. O’Vera <marge@example.com> # Adds table for storing lists.
  insert_list [lists appuser] 2013-12-31T21:48:14Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a list.
  delete_list [lists appuser] 2013-12-31T21:49:41Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a list.
  flips [appuser users] 2013-12-31T21:53:03Z Marge N. O’Vera <marge@example.com> # Adds table for storing flips.
  insert_flip [flips appuser] 2013-12-31T21:56:12Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a flip.
  delete_flip [flips appuser] 2013-12-31T21:56:22Z Marge N. O’Vera <marge@example.com> # Creates a function to delete a flip.

Note that it has appended the changes from the merged "lists" branch, and then
merged the changes from our "flips" branch. Test it to make sure it works as
expected:

  > sqitch rebase -y
  Reverting all changes from flipr_test
    - delete_flip ............... ok
    - insert_flip ............... ok
    - flips ..................... ok
    - change_pass @v1.0.0-dev1 .. ok
    - insert_user ............... ok
    - users ..................... ok
    - appuser ................... ok
  Deploying changes to flipr_test
    + appuser ................... ok
    + users ..................... ok
    + insert_user ............... ok
    + change_pass @v1.0.0-dev1 .. ok
    + lists ..................... ok
    + insert_list ............... ok
    + delete_list ............... ok
    + flips ..................... ok
    + insert_flip ............... ok
    + delete_flip ............... ok

Note the use of L<C<rebase>|sqitch-rebase>, which combines a
L<C<revert>|sqitch-revert> and a L<C<deploy>|sqitch-deploy> into a single
command. Handy, right? It correctly reverted our changes, and then deployed
them all again in the proper order. So let's commit F<.gitattributes>; seems
worthwhile to keep that change:

  > git add .
  > git commit -m 'Add `.gitattributes` with union merge for `sqitch.plan`.'
  [flips d813f7c] Add `.gitattributes` with union merge for `sqitch.plan`.
   1 file changed, 1 insertion(+)
   create mode 100644 .gitattributes

=head2 Merges Mastered

And now, finally, we can merge into C<main>:

  > git checkout main
  Switched to branch 'main'
  > git merge --no-ff flips -m "Merge branch 'flips'"
  Merge made by the 'recursive' strategy.
   .gitattributes         |  1 +
   deploy/delete_flip.sql | 22 ++++++++++++++++++++++
   deploy/flips.sql       | 16 ++++++++++++++++
   deploy/insert_flip.sql | 24 ++++++++++++++++++++++++
   revert/delete_flip.sql |  7 +++++++
   revert/flips.sql       |  7 +++++++
   revert/insert_flip.sql |  7 +++++++
   sqitch.plan            |  3 +++
   verify/delete_flip.sql | 10 ++++++++++
   verify/flips.sql       | 12 ++++++++++++
   verify/insert_flip.sql | 10 ++++++++++
   11 files changed, 119 insertions(+)
   create mode 100644 .gitattributes
   create mode 100644 deploy/delete_flip.sql
   create mode 100644 deploy/flips.sql
   create mode 100644 deploy/insert_flip.sql
   create mode 100644 revert/delete_flip.sql
   create mode 100644 revert/flips.sql
   create mode 100644 revert/insert_flip.sql
   create mode 100644 verify/delete_flip.sql
   create mode 100644 verify/flips.sql
   create mode 100644 verify/insert_flip.sql

And double-check our work:

  > cat sqitch.plan
  %syntax-version=1.0.0
  %project=flipr
  %uri=https://github.com/sqitchers/sqitch-mysql-intro/

  appuser 2013-12-31T21:04:04Z Marge N. O’Vera <marge@example.com> # Creates a an application user.
  users [appuser] 2013-12-31T21:32:48Z Marge N. O’Vera <marge@example.com> # Creates table to track our users.
  insert_user [users appuser] 2013-12-31T21:37:29Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a user.
  change_pass [users appuser] 2013-12-31T21:37:36Z Marge N. O’Vera <marge@example.com> # Creates a function to change a user password.
  @v1.0.0-dev1 2013-12-31T21:41:08Z Marge N. O’Vera <marge@example.com> # Tag v1.0.0-dev1.

  lists [appuser users] 2013-12-31T21:46:22Z Marge N. O’Vera <marge@example.com> # Adds table for storing lists.
  insert_list [lists appuser] 2013-12-31T21:48:14Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a list.
  delete_list [lists appuser] 2013-12-31T21:49:41Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a list.
  flips [appuser users] 2013-12-31T21:53:03Z Marge N. O’Vera <marge@example.com> # Adds table for storing flips.
  insert_flip [flips appuser] 2013-12-31T21:56:12Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a flip.
  delete_flip [flips appuser] 2013-12-31T21:56:22Z Marge N. O’Vera <marge@example.com> # Creates a function to delete a flip.

Much much better, a nice clean main now. And because it is now identical to
the "flips" branch, we can just carry on. Go ahead and tag it, bundle, and
release:

  > sqitch tag v1.0.0-dev2 -n 'Tag v1.0.0-dev2.'
  Tagged "delete_flip" with @v1.0.0-dev2
  > git commit -am 'Tag the database with v1.0.0-dev2.'
  [main 76d6e15] Tag the database with v1.0.0-dev2.
   1 file changed, 1 insertion(+)
  > git tag v1.0.0-dev2 -am 'Tag v1.0.0-dev2'
  > sqitch bundle --dest-dir flipr-1.0.0-dev2
  Bundling into flipr-1.0.0-dev2
  Writing config
  Writing plan
  Writing scripts
    + appuser
    + users
    + insert_user
    + change_pass @v1.0.0-dev1
    + lists
    + insert_list
    + delete_list
    + flips
    + insert_flip
    + delete_flip @v1.0.0-dev2

Note the use of the C<--dest-dir> option to C<sqitch bundle>. Just a nicer way
to create the top-level directory name so we don't have to rename it from
F<bundle>.

=head1 In Place Changes

Uh-oh, someone just noticed that MD5 hashing is not particularly secure. Why?
Have a look at this:

  > mysql -u root -D flipr_test --execute "
      CALL insert_user('foo', 'secr3t');
      CALL insert_user('bar', 'secr3t');
      SELECT * FROM users;
  "
  +----------+----------------------------------+----------------------------+
  | nickname | password                         | timestamp                  |
  +----------+----------------------------------+----------------------------+
  | bar      | 9695da4dd567a19f9b92065f240c6725 | 2013-12-31 22:06:28.359118 |
  | foo      | 9695da4dd567a19f9b92065f240c6725 | 2013-12-31 22:06:28.358789 |
  +----------+----------------------------------+----------------------------+

If user "foo" ever got access to the database, she could quickly discover that
user "bar" has the same password and thus be able to exploit the account. Not
a great idea. So we need to modify the C<insert_user()> and C<change_pass()>
functions to fix that. How?

We can use MySQL's
L<C<ENCRYPT()>|https://dev.mysql.com/doc/refman/5.7/en/encryption-functions.html#function_encrypt>
function to encrypt passwords with a salt, so that they're all unique. But how
to deploy the changes to C<insert_user()> and C<change_pass()>?

Normally, modifying functions in database changes is a
L<PITA|https://www.urbandictionary.com/define.php?term=pita>. You have to make
changes like these:

=over

=item 1.

Copy F<deploy/insert_user.sql> to F<deploy/insert_user_encrypt.sql>.

=item 2.

Edit F<deploy/insert_user_encrypt.sql> to switch from C<MD5()> to C<ENCRYPT()>.

=item 3.

Copy F<deploy/insert_user.sql> to F<revert/insert_user_encrypt.sql>.
Yes, copy the original change script to the new revert change.

=item 4.

Copy F<verify/insert_user.sql> to F<verify/insert_user_encrypt.sql>.

=item 5.

Edit F<verify/insert_user_encrypt.sql> to test that the function now properly
uses C<ENCRYPT()>.

=item 6.

Test the changes to make sure you can deploy and revert the
C<insert_user_encrypt> change.

=item 7.

Now do the same for the C<change_pass> scripts.

=back

But you can have Sqitch do it for you. The only requirement is that a tag
appear between the two instances of a change we want to modify. In general,
you're going to make a change like this after a release, which you've tagged
anyway, right? Well we have, with C<@v1.0.0-dev2> added in the previous
section. With that, we can let Sqitch do most of the hard work for us, thanks
to the L<C<rework>|sqitch-rework> command, which is similar to
L<C<add>|sqitch-add>:

  > sqitch rework insert_user -n 'Change insert_user to use encyrpt().'
  Added "insert_user [insert_user@v1.0.0-dev2]" to sqitch.plan.
  Modify these files as appropriate:
    * deploy/insert_user.sql
    * revert/insert_user.sql
    * verify/insert_user.sql

Oh, so we can edit those files in place. Nice! How does Sqitch do it? Well, in
point of fact, it has copied the files to stand in for the previous instance
of the C<insert_user> change, which we can see via C<git status>:

  > git status
  # On branch main
  # Your branch is ahead of 'origin/main' by 5 commits.
  #   (use "git push" to publish your local commits)
  #
  # Changes not staged for commit:
  #   (use "git add <file>..." to update what will be committed)
  #   (use "git checkout -- <file>..." to discard changes in working directory)
  #
  #	modified:   revert/insert_user.sql
  #	modified:   sqitch.plan
  #
  # Untracked files:
  #   (use "git add <file>..." to include in what will be committed)
  #
  #	deploy/insert_user@v1.0.0-dev2.sql
  #	revert/insert_user@v1.0.0-dev2.sql
  #	verify/insert_user@v1.0.0-dev2.sql
  no changes added to commit (use "git add" and/or "git commit -a")

The "untracked files" part of the output is the first thing to notice. They
are all named C<insert_user@v1.0.0-dev2.sql>. What that means is: "the
C<insert_user> change as it was implemented as of the C<@v1.0.0-dev2> tag."
These are copies of the original scripts, and thereafter Sqitch will find them
when it needs to run scripts for the first instance of the C<insert_user>
change. As such, it's important not to change them again. But hey, if you're
reworking the change, you shouldn't need to.

The other thing to notice is that F<revert/insert_user.sql> has changed.
Sqitch replaced it with the original deploy script. As of now,
F<deploy/insert_user.sql> and F<revert/insert_user.sql> are identical. This is
on the assumption that the deploy script will be changed (we're reworking it,
remember?), and that the revert script should actually change things back to
how they were before. Of course, the original deploy script may not be
L<idempotent|https://en.wikipedia.org/wiki/Idempotence> -- that is, able to be
applied multiple times without changing the result beyond the initial
application. If it's not, you will likely need to modify it so that it
properly restores things to how they were after the original deploy script was
deployed. Or, more simply, it should revert changes back to how they were
as-of the deployment of F<deploy/insert_user@v1.0.0-dev2.sql>.

Had MySQL supported an C<OR REPLACE> expression on C<CREATE FUNCTION> and we
had used it, our function deploy scripts would already idempotent. No matter
how many times they were run, the end results would be the same instance of
the function, with no duplicates or errors.

Alas, such is not the case for MySQL, so we will have to modify the scripts to
drop the function before re-creating it. So let's do it. We'll modify the
scripts drop and re-create the functions with to use C<ENCRYPT()>. Make this
change to F<deploy/insert_user.sql>:

  @@ -6,13 +6,14 @@ BEGIN;
 
   DELIMITER //
 
  +DROP PROCEDURE insert_user;
   CREATE PROCEDURE insert_user(
       nickname VARCHAR(512),
       password VARCHAR(512)
   ) SQL SECURITY DEFINER
   BEGIN
       INSERT INTO users (nickname, password, timestamp)
  -    VALUES (nickname, md5(password), UTC_TIMESTAMP(6));
  +    VALUES (nickname, ENCRYPT(md5(password), md5(FLOOR(RAND() * 0xFFFFFFFF))), UTC_TIMESTAMP(6));
   END
   //
 
We just need to add the C<DROP> statement to the revert script,
F<revert/insert_user.sql>:

  @@ -6,6 +6,7 @@ BEGIN;
 
   DELIMITER //
 
  +DROP PROCEDURE insert_user;
   CREATE PROCEDURE insert_user(
       nickname VARCHAR(512),
       password VARCHAR(512)

Go ahead and rework the C<change_pass> change, too:

  > sqitch rework change_pass -n 'Change change_pass to use encyrpt().'
  Added "change_pass [change_pass@v1.0.0-dev2]" to sqitch.plan.
  Modify these files as appropriate:
    * deploy/change_pass.sql
    * revert/change_pass.sql
    * verify/change_pass.sql

And make this change to F<deploy/change_pass.sql>:

  @@ -6,6 +6,7 @@ BEGIN;
 
   DELIMITER //
 
  +DROP FUNCTION change_pass;
   CREATE FUNCTION change_pass(
       nickname VARCHAR(512),
       oldpass  VARCHAR(512),
  @@ -13,9 +14,9 @@ CREATE FUNCTION change_pass(
   ) RETURNS INTEGER DETERMINISTIC SQL SECURITY DEFINER
   BEGIN
       UPDATE users
  -       SET password = md5(newpass)
  +       SET password = ENCRYPT(md5(newpass), md5(FLOOR(RAND() * 0xFFFFFFFF)))
        WHERE nickname = nickname
  -       AND password = md5(oldpass);
  +       AND password = ENCRYPT(md5(oldpass), password);
       RETURN ROW_COUNT();
   END;
   //

And add the C<DROP FUNCTION> statement to its revert script, too:

  @@ -6,6 +6,7 @@ BEGIN;
 
   DELIMITER //
 
  +DROP FUNCTION change_pass;
   CREATE FUNCTION change_pass(
       nickname VARCHAR(512),
       oldpass  VARCHAR(512),

And now we're ready to try a deployment:

  >     sqitch deploy
  Deploying changes to flipr_test
    + insert_user .. ok
    + change_pass .. ok

So, are the changes deployed?

  > mysql -u root -D flipr_test --execute "
      DELETE FROM users;
      CALL insert_user('foo', 'secr3t');
      CALL insert_user('bar', 'secr3t');
      SELECT * FROM users;
  "
  +----------+---------------+----------------------------+
  | nickname | password      | timestamp                  |
  +----------+---------------+----------------------------+
  | bar      | 0aasvM1.AzY0Y | 2013-12-31 22:14:45.554942 |
  | foo      | 80v1DpnRrqbwo | 2013-12-31 22:14:45.554457 |
  +----------+---------------+----------------------------+

Awesome, the stored passwords are different now. But can we revert, even
though we haven't written any reversion scripts?

  > sqitch revert --to @HEAD^^ -y
  Reverting changes to delete_flip @v1.0.0-dev2 from flipr_test
    - change_pass .. ok
    - insert_user .. ok

Did that work, are the C<MD5()> passwords back?

  > mysql -u root -D flipr_test --execute "
      DELETE FROM users;
      CALL insert_user('foo', 'secr3t');
      CALL insert_user('bar', 'secr3t');
      SELECT * FROM users;
  "
  +----------+----------------------------------+----------------------------+
  | nickname | password                         | timestamp                  |
  +----------+----------------------------------+----------------------------+
  | bar      | 9695da4dd567a19f9b92065f240c6725 | 2013-12-31 22:15:29.843140 |
  | foo      | 9695da4dd567a19f9b92065f240c6725 | 2013-12-31 22:15:29.842700 |
  +----------+----------------------------------+----------------------------+

Yes, it works! Sqitch properly finds the original instances of these changes
in the new script files that include tags.

But what about the verify script? How can we verify that the functions have
been modified to use C<ENCRYPT()>? I think the simplest thing to do is to
examine the body of the function as returned by
L<C<INFORMATION_SCHEMA.ROUTINES>|https://dev.mysql.com/doc/refman/5.7/en/information-schema-routines-table.html>
So the C<insert_user> verify script looks like this:

  -- Verify flipr:insert_user on mysql

  BEGIN;

  SELECT sqitch.checkit(COUNT(*), 'Procedure "insert_user" does not exist or is not up-to-date')
    FROM information_schema.routines
   WHERE routine_schema = database()
     AND routine_name = 'insert_user'
     AND routine_definition LIKE '%ENCRYPT(md5(password), md5(FLOOR(RAND() * 0xFFFFFFFF))%';

  ROLLBACK;

And the C<change_pass> verify script looks like this:

  -- Verify flipr:change_pass on mysql

  BEGIN;

  SELECT sqitch.checkit(COUNT(*), 'Procedure "change_pass" does not exist or is not up-to-date')
    FROM information_schema.routines
   WHERE routine_schema = database()
     AND routine_name = 'change_pass'
     AND routine_definition LIKE '%ENCRYPT(md5(oldpass), password)%';

  ROLLBACK;

Make sure these pass by re-deploying:

  > sqitch deploy
  Deploying changes to flipr_test
    + insert_user .. ok
    + change_pass .. ok

Excellent. Let's go ahead and commit these changes:

  > git add .
  > git commit -m 'Use encrypt() to encrypt passwords.'
  [main abcce73] Use encrypt() to encrypt passwords.
   13 files changed, 137 insertions(+), 9 deletions(-)
   create mode 100644 deploy/change_pass@v1.0.0-dev2.sql
   create mode 100644 deploy/insert_user@v1.0.0-dev2.sql
   create mode 100644 revert/change_pass@v1.0.0-dev2.sql
   create mode 100644 revert/insert_user@v1.0.0-dev2.sql
   create mode 100644 verify/change_pass@v1.0.0-dev2.sql
   create mode 100644 verify/insert_user@v1.0.0-dev2.sql

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   6f2e1cd4b1c031a66930811328cfcdb0389d8320
  # Name:     change_pass
  # Deployed: 2013-12-31 14:16:45 -0800
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

=head1 More to Come

Sqitch is a work in progress. Better integration with version control systems
is planned to make managing idempotent reworkings even easier. Stay tuned.

=head1 Author

David E. Wheeler <david@justatheory.com>

=head1 License

Copyright (c) 2012-2023 iovation Inc., David E. Wheeler

Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software without restriction, including without limitation the rights
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:

The above copyright notice and this permission notice shall be included in all
copies or substantial portions of the Software.

THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.

=cut