|
| 1 | +package main |
| 2 | + |
| 3 | +import ( |
| 4 | + "context" |
| 5 | + "fmt" |
| 6 | + "os" |
| 7 | + "regexp" |
| 8 | + "strings" |
| 9 | + |
| 10 | + "github.com/alecthomas/kong" |
| 11 | + _ "github.com/go-sql-driver/mysql" |
| 12 | + "github.com/jmoiron/sqlx" |
| 13 | +) |
| 14 | + |
| 15 | +var cli struct { |
| 16 | + CopyUsers struct { |
| 17 | + SourceDSN string `arg:"" required:"true" help:"Source DSN"` |
| 18 | + TargetDSN string `arg:"" required:"true" help:"Target DSN"` |
| 19 | + MergeUsersByName bool `default:"true" help:"Merge users by name"` |
| 20 | + } `cmd:"copy-users" help:"Copy users from source to target"` |
| 21 | +} |
| 22 | + |
| 23 | +type User struct { |
| 24 | + User string `db:"User"` |
| 25 | + Host string `db:"Host"` |
| 26 | +} |
| 27 | + |
| 28 | +func main() { |
| 29 | + ctx := kong.Parse(&cli, |
| 30 | + kong.Name("myducktools"), |
| 31 | + kong.Description("MyDuckServer tools"), |
| 32 | + kong.UsageOnError()) |
| 33 | + switch ctx.Command() { |
| 34 | + case "copy-users <source-dsn> <target-dsn>": |
| 35 | + if err := copyUsers(cli.CopyUsers.SourceDSN, cli.CopyUsers.TargetDSN, cli.CopyUsers.MergeUsersByName); err != nil { |
| 36 | + fmt.Printf("Error copying users: %v\n", err) |
| 37 | + os.Exit(1) |
| 38 | + } |
| 39 | + } |
| 40 | +} |
| 41 | + |
| 42 | +func copyUsers(sourceDSN, targetDSN string, mergeUsersByName bool) error { |
| 43 | + sourceDB, err := sqlx.Open("mysql", sourceDSN) |
| 44 | + if err != nil { |
| 45 | + return fmt.Errorf("failed to connect to source database: %w", err) |
| 46 | + } |
| 47 | + defer sourceDB.Close() |
| 48 | + |
| 49 | + if err := sourceDB.Ping(); err != nil { |
| 50 | + return fmt.Errorf("failed to ping source database: %w", err) |
| 51 | + } |
| 52 | + |
| 53 | + targetDB, err := sqlx.Open("mysql", targetDSN) |
| 54 | + if err != nil { |
| 55 | + return fmt.Errorf("failed to connect to target database: %w", err) |
| 56 | + } |
| 57 | + defer targetDB.Close() |
| 58 | + |
| 59 | + if err := targetDB.Ping(); err != nil { |
| 60 | + return fmt.Errorf("failed to ping target database: %w", err) |
| 61 | + } |
| 62 | + |
| 63 | + users, err := getUsers(sourceDB) |
| 64 | + if err != nil { |
| 65 | + return fmt.Errorf("failed to get users from source: %w", err) |
| 66 | + } |
| 67 | + |
| 68 | + fmt.Printf("Found %d users to copy\n", len(users)) |
| 69 | + |
| 70 | + processedUsers := make(map[string]bool) |
| 71 | + for _, user := range users { |
| 72 | + if _, ok := processedUsers[user.User]; ok && mergeUsersByName { |
| 73 | + continue |
| 74 | + } |
| 75 | + |
| 76 | + userOnHost := fmt.Sprintf("`%s`@`%s`", user.User, user.Host) |
| 77 | + userStatements, err := prepareUserStatements(sourceDB, user) |
| 78 | + if err != nil { |
| 79 | + fmt.Printf("Warning: Failed to prepare user statements for %s: %v\n", userOnHost, err) |
| 80 | + continue |
| 81 | + } |
| 82 | + |
| 83 | + if mergeUsersByName { |
| 84 | + for i, stmt := range userStatements { |
| 85 | + userStatements[i] = strings.ReplaceAll(stmt, userOnHost, fmt.Sprintf("`%s`@`%%`", user.User)) |
| 86 | + } |
| 87 | + } |
| 88 | + |
| 89 | + // Debug |
| 90 | + // fmt.Printf("Prepared user statements:\n%#v\n", userStatements) |
| 91 | + |
| 92 | + tx, err := targetDB.BeginTx(context.Background(), nil) |
| 93 | + if err != nil { |
| 94 | + fmt.Printf("Warning: Failed to begin transaction for user %s: %v\n", userOnHost, err) |
| 95 | + continue |
| 96 | + } |
| 97 | + |
| 98 | + for _, stmt := range userStatements { |
| 99 | + if _, err := tx.Exec(stmt); err != nil { |
| 100 | + // Debug |
| 101 | + // fmt.Printf("Warning: Failed to execute statement %s: %v\n", stmt, err) |
| 102 | + fmt.Printf("Warning: Failed to copy user %s: %v\n", userOnHost, err) |
| 103 | + tx.Rollback() |
| 104 | + break |
| 105 | + } |
| 106 | + } |
| 107 | + |
| 108 | + if err := tx.Commit(); err != nil { |
| 109 | + fmt.Printf("Warning: Failed to commit transaction for user %s: %v\n", userOnHost, err) |
| 110 | + continue |
| 111 | + } |
| 112 | + |
| 113 | + // Debug |
| 114 | + // fmt.Printf("Successfully copied user: %s\n", userOnHost) |
| 115 | + processedUsers[user.User] = true |
| 116 | + } |
| 117 | + |
| 118 | + if _, err := targetDB.Exec("FLUSH PRIVILEGES"); err != nil { |
| 119 | + return fmt.Errorf("failed to flush privileges: %w", err) |
| 120 | + } |
| 121 | + |
| 122 | + return nil |
| 123 | +} |
| 124 | + |
| 125 | +// Get all non-system users from a database. |
| 126 | +func getUsers(db *sqlx.DB) ([]User, error) { |
| 127 | + query := ` |
| 128 | + SELECT user, host FROM mysql.user WHERE user NOT IN ('mariadb.sys','mysql','root')` |
| 129 | + |
| 130 | + users := []User{} |
| 131 | + err := db.Select(&users, query) |
| 132 | + return users, err |
| 133 | +} |
| 134 | + |
| 135 | +// Prepare user creation and grant statements. |
| 136 | +// Because there are inconsistencies in the way users are created in MySQL and MariaDB, |
| 137 | +// we need to modify the statements to work with the MySQL syntax. |
| 138 | +// Also, currently MyDuckServer has issues when connecting with user@host, |
| 139 | +// so we need to create the user with the wildcard (%) as host. |
| 140 | +func prepareUserStatements(sourceDB *sqlx.DB, user User) ([]string, error) { |
| 141 | + userOnHost := fmt.Sprintf("`%s`@`%s`", user.User, user.Host) |
| 142 | + createUserStmt, err := getCreateUserStatement(sourceDB, userOnHost) |
| 143 | + if err != nil { |
| 144 | + return nil, fmt.Errorf("failed to get CREATE USER statement for %s: %w", userOnHost, err) |
| 145 | + } |
| 146 | + |
| 147 | + grantStmts, err := getGrantStatements(sourceDB, userOnHost) |
| 148 | + if err != nil { |
| 149 | + return nil, fmt.Errorf("failed to get GRANT statements for %s: %w", userOnHost, err) |
| 150 | + } |
| 151 | + |
| 152 | + createUserStmt = makeCreateUserCompatible(createUserStmt) |
| 153 | + |
| 154 | + grantStmts = makeGrantStatementsCompatible(grantStmts) |
| 155 | + |
| 156 | + userStatements := []string{createUserStmt} |
| 157 | + userStatements = append(userStatements, grantStmts...) |
| 158 | + return userStatements, nil |
| 159 | +} |
| 160 | + |
| 161 | +func getCreateUserStatement(db *sqlx.DB, user string) (string, error) { |
| 162 | + var createUserStmt string |
| 163 | + err := db.Get(&createUserStmt, fmt.Sprintf("SHOW CREATE USER %s", user)) |
| 164 | + return createUserStmt, err |
| 165 | +} |
| 166 | + |
| 167 | +func getGrantStatements(db *sqlx.DB, user string) ([]string, error) { |
| 168 | + var grants []string |
| 169 | + err := db.Select(&grants, fmt.Sprintf("SHOW GRANTS FOR %s", user)) |
| 170 | + return grants, err |
| 171 | +} |
| 172 | + |
| 173 | +func makeCreateUserCompatible(createUserStmt string) string { |
| 174 | + createUserStmt = strings.Replace(createUserStmt, "CREATE USER", "CREATE USER IF NOT EXISTS", 1) |
| 175 | + createUserStmt = strings.Replace(createUserStmt, "IDENTIFIED BY PASSWORD", "IDENTIFIED WITH mysql_native_password AS", 1) |
| 176 | + return createUserStmt |
| 177 | +} |
| 178 | + |
| 179 | +var unsupportedGrants = map[string]bool{ |
| 180 | + `BINLOG MONITOR`: true, |
| 181 | + `DELETE HISTORY`: true, |
| 182 | + `SET USER`: true, |
| 183 | + `READ_ONLY ADMIN`: true, |
| 184 | + `FEDERATED ADMIN`: true, |
| 185 | + `BINLOG ADMIN`: true, |
| 186 | + `SLAVE MONITOR`: true, |
| 187 | + `CONNECTION ADMIN`: true, |
| 188 | + `REPLICATION MASTER ADMIN`: true, |
| 189 | +} |
| 190 | + |
| 191 | +func makeGrantStatementsCompatible(grantStmts []string) []string { |
| 192 | + compatibleGrants := []string{} |
| 193 | + |
| 194 | + for _, stmt := range grantStmts { |
| 195 | + // "IDENTIFIED BY PASSWORD" is part of CREATE USER only, not GRANT in MySQL. |
| 196 | + // While in MariaDB, it can be in both. |
| 197 | + stmt = regexp.MustCompile(` IDENTIFIED BY PASSWORD '.*'`).ReplaceAllString(stmt, "") |
| 198 | + |
| 199 | + // "WITH MAX_USER_CONNECTIONS" is part of CREATE USER only, not GRANT in MySQL. |
| 200 | + // While in MariaDB, it can be in both. |
| 201 | + stmt = regexp.MustCompile(` WITH MAX_USER_CONNECTIONS [0-9]+`).ReplaceAllString(stmt, "") |
| 202 | + |
| 203 | + grantsRegex := regexp.MustCompile(`^GRANT (.*) ON (.*)$`) |
| 204 | + matches := grantsRegex.FindStringSubmatch(stmt) |
| 205 | + if len(matches) == 0 { |
| 206 | + continue |
| 207 | + } |
| 208 | + grantsInStmt := strings.Split(matches[1], ", ") |
| 209 | + |
| 210 | + // Remove unsupported GRANTs |
| 211 | + supportedGrants := []string{} |
| 212 | + for _, grant := range grantsInStmt { |
| 213 | + if !unsupportedGrants[grant] { |
| 214 | + supportedGrants = append(supportedGrants, grant) |
| 215 | + } |
| 216 | + } |
| 217 | + if len(supportedGrants) == 0 { |
| 218 | + continue |
| 219 | + } |
| 220 | + stmt = "GRANT " + strings.Join(supportedGrants, ", ") + " ON " + matches[2] |
| 221 | + |
| 222 | + // For some reason for "REPLICATION SLAVE ADMIN" we need to use underscores, |
| 223 | + // while for other multi-word grants spaces are fine. |
| 224 | + stmt = strings.ReplaceAll(stmt, "REPLICATION SLAVE ADMIN", "REPLICATION_SLAVE_ADMIN") |
| 225 | + |
| 226 | + compatibleGrants = append(compatibleGrants, stmt) |
| 227 | + } |
| 228 | + |
| 229 | + return compatibleGrants |
| 230 | +} |
0 commit comments