├── README.md └── images ├── function-input-name.png └── public-functions.png /README.md: -------------------------------------------------------------------------------- 1 | This document is largely inspired by the [Ruby Style Guide](https://github.com/bbatsov/ruby-style-guide). 2 | 3 | # Prelude 4 | > No one man should have all that power.
5 | > -- Kanye West 6 | 7 | This is an evolving document. Submit a pull request and start the conversation! 8 | 9 | # VBA Style Guide 10 | 11 | ## Source Code Layout 12 | 13 | > Not complicated, it's simple.
14 | > -- Big Sean 15 | 16 | * Limit lines to 80 characters. 17 | 18 | * Use 4-character tabs to indent. 19 | 20 | ```vb 21 | 'Bad 22 | If blnSomething Then 23 | Msgbox "True" '<~ 2-character indents 24 | Else 25 | Msgbox "False" 26 | End If 27 | 28 | 'Good 29 | If blnSomething Then 30 | Msgbox "True" '<~ 4-character indents 31 | Else 32 | Msgbox "False" 33 | End If 34 | ``` 35 | 36 | * All conditionals, loops and blocks should be indented. 37 | 38 | ```vb 39 | 'Bad 40 | If lngNumber >= 0 Then 41 | Msgbox "Yep" 42 | Else 43 | Msgbox "Nope" 44 | End 45 | 46 | 'Good 47 | If lngNumber >= 0 Then 48 | Msgbox "Yep" 49 | Else 50 | Msgbox "Nope" 51 | End 52 | 53 | 'Bad 54 | For lngIndex = 1 To lngLastRow 55 | lngCounter = lngCounter + lngIndex 56 | Next lngIndex 57 | 58 | 'Good 59 | For lngIndex = 1 To lngLastRow 60 | lngCounter = lngCounter + lngIndex 61 | Next lngIndex 62 | 63 | 'Bad 64 | With wksSource 65 | Set rngSource = .Range(.Cells(1, 1), .Cells(lngLastRow, 1)) 66 | End With 67 | 68 | 'Good 69 | With wksSource 70 | Set rngSource = .Range(.Cells(1, 1), .Cells(lngLastRow, 1)) 71 | End With 72 | ``` 73 | 74 | * Do not write multiple statements on a single line (using `:`). 75 | 76 | ```vb 77 | 'Bad 78 | For i = 1 To 10: DoSomething(i): Next i 79 | 80 | 'Good 81 | For i = 1 To 10 82 | DoSomething(i) 83 | Next i 84 | ``` 85 | 86 | ## Variables and Naming 87 | 88 | > Oh that looks like what's-her-name, chances are it's what's-her-name.
89 | > -- Drake 90 | 91 | * Use `Option Explicit` to mandate variable declaration. 92 | 93 | ```vb 94 | 'Bad 95 | Public Sub MyMacro() 96 | 'do something 97 | End Sub 98 | 99 | 'Good 100 | Option Explicit 101 | Public Sub MyMacro() 102 | 'do something 103 | End 104 | ``` 105 | 106 | * Declare variable types explicitly. 107 | 108 | ```vb 109 | 'Bad 110 | Dim MyNumber 111 | Dim MyBlock 112 | Dim MyVariable 113 | 114 | 'Good 115 | Dim MyNumber As Long 116 | Dim MyBlock As Range 117 | Dim MyVariable As Variant 118 | ``` 119 | 120 | * When declaring variables on one line, they ALL must be declared explicitly. 121 | 122 | ```vb 123 | 'Bad 124 | Dim lngLastRow, lngLastCol As Long '<~ lngLastRow is a Variant, NOT a Long 125 | 126 | 'Good 127 | Dim lngLastRow As Long, lngLastCol As Long '<~ both variables are Long 128 | ``` 129 | 130 | * Use a two statement declaration for objects rather than the `Dim X As New Y` syntax. 131 | 132 | ```vb 133 | 'Bad 134 | Dim col As New Collection 135 | 136 | 'Good 137 | Dim col As Collection 138 | Set col = New Collection 139 | ``` 140 | 141 | * Prepend all variables with a 3-letter code to indicate its type. This is commonly referred to as Hungarian Notation (or, more accurately, [_Apps Hungarian_](http://en.wikipedia.org/wiki/Hungarian_notation)) 142 | 143 | | Variable Type | 3-Letter Code | 144 | | ------------------ | ------------- | 145 | | Boolean | `bln` | 146 | | ChartObject | `cho` | 147 | | Collection | `col` | 148 | | Comment | `cmt` | 149 | | Date | `dat` | 150 | | Double | `dbl` | 151 | | FileDialog | `fdo` | 152 | | FileSystemObject | `fso` | 153 | | Long | `lng` | 154 | | Object | `obj` | 155 | | Pivot Cache | `pvc` | 156 | | Pivot Table | `pvt` | 157 | | Range | `rng` | 158 | | Shape | `shp` | 159 | | String | `str` | 160 | | TextStream | `txs` | 161 | | Variant | `var` | 162 | | Workbook | `wbk` | 163 | | Worksheet | `wks` | 164 | | WshShell | `wsh` | 165 | 166 | **EXCEPTION:** input variables to function should NOT have a 3-letter code. These variable types can be identified trivially by Intellisense and should be named to maximize readability: 167 | 168 | ![Image](images/function-input-name.png) 169 | 170 | * When working with whole numbers, use `Long` instead of `Integer`. 171 | 172 | ```vb 173 | 'Bad 174 | Dim intValue As Integer 175 | 176 | 'Good 177 | Dim lngValue As Long 178 | 179 | 'Integers are 16-bit and can only store values up to 32,767 180 | lngValue = 50000 '<~ no issue 181 | intValue = 50000 '<~ overflow error 182 | ``` 183 | 184 | Under the covers, `Integer`-type variables are converted into `Long`-type variables, the math is executed, then the `Long` is converted back to an `Integer`. Avoid the debugging headache and `Dim` all integers as `Long`-type. 185 | 186 | * Name **local** variables in `CamelCase`. (Keep acronyms like HTTP, RFC and XML uppercase.) 187 | 188 | ```vb 189 | 'Bad 190 | Dim str_my_variable As String 191 | Dim strmyvariable As String 192 | Dim strHttp As String 193 | 194 | 'Good 195 | Dim strMyVariable As String 196 | Dim strHTTP As String 197 | ``` 198 | 199 | * Name **global** variables in `SCREAMING_SNAKE_CASE`. (Keep acronyms like HTTP, RFC and XML uppercase.) 200 | 201 | ```vb 202 | 'Bad 203 | Dim str_error_message As String 204 | Dim strErrorMessage As String 205 | Dim lngCONSTANT As Long 206 | Dim lngHttpAcceptedCode As Long 207 | 208 | 'Good 209 | Dim str_ERROR_MESSAGE As String 210 | Dim lng_CONSTANT As Long 211 | Dim lng_HTTP_ACCEPTED_CODE As Long 212 | ``` 213 | 214 | * Generic 3-letter variable names are OK for common iterators. 215 | 216 | ```vb 217 | 'OK 218 | Dim wks As Worksheet 219 | 220 | For Each wks In ThisWorkbook.Worksheets 221 | 'do stuff to each sheet 222 | Msgbox (wks.Name) 223 | Next wks 224 | ``` 225 | 226 | * Store all global constants in a single unique module named `ImportGlobalConstants`. 227 | 228 | ```vb 229 | Option Explicit 230 | 231 | Public lng_MAX_NUM_FILES As Long 232 | Public lng_EXCEL_2003_WIN As Long 233 | Public lng_EXCEL_2007_WIN As Long 234 | Public lng_EXCEL_BINARY_WIN As Long 235 | Public lng_EXCEL_MACRO_ENABLED_WIN As Long 236 | 237 | Public Sub ImportGlobalConstants() 238 | lng_MAX_NUM_FILES = 1000 239 | lng_EXCEL_2003_WIN = 56 240 | lng_EXCEL_2007_WIN = 51 241 | lng_EXCEL_BINARY_WIN = 50 242 | lng_EXCEL_MACRO_ENABLED_WIN = 52 243 | End Sub 244 | ``` 245 | 246 | This allows you to import all pre-defined constants by adding: 247 | 248 | ```vb 249 | Call ImportGlobalConstants 250 | ``` 251 | 252 | to your script. 253 | 254 | * All public, reusable functions and subroutines that are not task-specific should be stored in a unique and easy-to-find module. 255 | 256 | ![Image](images/public-functions.png) 257 | 258 | * Prefer the verb "Create" for functions that return a `String`. 259 | 260 | ```vb 261 | Public Function CreateFullFilename() As String 262 | 'the magic happens in here 263 | CreateFullFilename = ThisWorkbook.Path & "\not_really_this_easy.xlsb" 264 | End Function 265 | ``` 266 | 267 | * Prefer the verb "Calculate" for functions that return a `Long`. 268 | 269 | ```vb 270 | Public Function CalculateUltimateQuestionOfLife() As Long 271 | CalculateUltimateQuestionOfLife = 42 272 | End Function 273 | ``` 274 | 275 | * Prefer the verb "Get" for functions that return a `Workbook`. 276 | 277 | ```vb 278 | Public Function GetExceptionsTemplate() As Workbook 279 | 'the magic happens in here 280 | Set GetExceptionsTemplate = Workbooks.Open(strFilePathToExceptionsTemplate) 281 | End Function 282 | ``` 283 | 284 | * Prefer the verb "Pluck" for functions that return a `Range`. 285 | 286 | ```vb 287 | Public Function PluckIYYRow() As Range 288 | 'the magic happens in here 289 | Set PluckIYYRow = .Range(.Cells(rngIYY.Row, 1), _ 290 | .Cells(rngIYY.Row, lngLastCol)) 291 | End Function 292 | ``` 293 | 294 | * Prefer the verb "Collect" for functions that return a `Collection`. 295 | 296 | ```vb 297 | Public Function CollectDataFilePaths() As Collection 298 | 'the magic happens in here 299 | While Len(strFile) > 0 300 | col.Add (str_GLOBAL_DIR & strFile) 301 | strFile = Dir 302 | Wend 303 | Set CollectDataFilePaths = col 304 | End Function 305 | ``` 306 | 307 | * Prefer the verb "Assemble" for functions that return a `Scripting.Dictionary`. 308 | 309 | ```vb 310 | Public Function AssemblePairs() As Scripting.Dictionary 311 | 'the magic happens in here 312 | For lngIdx = 1 To lngLastRow 313 | dic.Add Key:=.Cells(lngIdx, 1), Item:=.Cells(lngIdx, 2) 314 | Next lngIdx 315 | Set AssemblePairs = dic 316 | End Function 317 | ``` 318 | 319 | ## Syntax 320 | 321 | > I'mma be fresh as hell if the Feds watching.
322 | > -- 2 Chainz & Pharrell 323 | 324 | * Close `For...Next` loops with the iterative variable after `Next`. 325 | 326 | ```vb 327 | 'Bad 328 | For Each wks in ThisWorkbook.Worksheets 329 | 'do stuff with each worksheet 330 | Next 331 | 332 | 'Good 333 | For Each wks in ThisWorkbook.Worksheets 334 | 'do stuff with each worksheet 335 | Next wks 336 | ``` 337 | 338 | * Prefer `With...End With` blocks to reduce repetition. 339 | 340 | ```vb 341 | 'Bad 342 | Set rng = wks.Range(wks.Cells(1, 1), wks.Cells(lngLastRow, 1)) 343 | 344 | 'Good 345 | With wks 346 | Set rng = .Range(.Cells(1, 1), .Cells(lngLastRow, 1)) 347 | End With 348 | ``` 349 | 350 | * Qualify `Range` objects with a `Worksheet`. 351 | 352 | ```vb 353 | 'Bad 354 | Set rng = Range(Cells(1, 1), Cells(lngIdx, 1)) 355 | 356 | 'Good 357 | Set wks = ThisWorkbook.Worksheets("Data") 358 | With wks 359 | Set rng = .Range(.Cells(1, 1), .Cells(lngIdx, 1)) 360 | End With 361 | ``` 362 | 363 | -------------------------------------------------------------------------------- /images/function-input-name.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/danwagnerco/vba-style-guide/696705eb7c9c34aea2fda0c3afa73efa08c7bbd7/images/function-input-name.png -------------------------------------------------------------------------------- /images/public-functions.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/danwagnerco/vba-style-guide/696705eb7c9c34aea2fda0c3afa73efa08c7bbd7/images/public-functions.png --------------------------------------------------------------------------------