├── .gitignore ├── README.md └── chapters_asciidoc ├── 00 Frontpage.asciidoc ├── 01 Introduction.asciidoc ├── 02 Document history.asciidoc ├── 03 Quick find.asciidoc ├── 04 Introduction to SQL.asciidoc ├── 05 Data Manipulation Language.asciidoc ├── 06 Coumpound SQL.asciidoc ├── 07 Column Functions.asciidoc ├── 08 OLAP Function.asciidoc ├── 09 Scalar Functions.asciidoc ├── 10 Table Functions.asciidoc ├── 11 Useful User-Defined Functions.asciidoc ├── 12 Order by Group by and Having.asciidoc ├── 13 Joins.asciidoc ├── 14 Sub Query.asciidoc ├── 15 Union Intersect Except.asciidoc ├── 16 Materialized Query Tables.asciidoc ├── 17 Identity Columns and Sequences.asciidoc ├── 18 Temporary Tables.asciidoc ├── 19 Recursive SQL.asciidoc ├── 20 Triggers.asciidoc ├── 21 Protecting Your Data.asciidoc ├── 22 Recording Changes.asciidoc ├── 23 Using SQL to Make SQL.asciidoc ├── 24 Running SQL Within SQL.asciidoc ├── 25 Fun with SQL.asciidoc ├── 26 Quirks in SQL.asciidoc ├── 27 Time Travel.asciidoc ├── 927 Appendix.asciidoc ├── 928 Appendix 2 Graeme Birchall.asciidoc ├── 998 References.asciidoc ├── 999 Index.asciidoc └── README.md /.gitignore: -------------------------------------------------------------------------------- 1 | /.project 2 | /.settings 3 | /.metadata 4 | /.asciidoctorconfig.adoc -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # db2-sql-cookbook 2 | Colaboration platform for the new version of the old Db2 SQL Cookbook. 3 | 4 | PDF Version can be found here: http://db2-sql-cookbook.org/pdf/Db2_SQL_Cookbook.pdf 5 | 6 | [Preamble] 7 | == Introduction 8 | 9 | I started using Db2 in 1991. Five years later, Graeme Birchall released the first version of his "Db2 SQL Cookbook". This book helped me to learn SQL and I used it a lot of times to learn new stuff and to check how he writes similar queries (the first time I can remember was when I took my first Db2 Certification. "IBM Certified Solutions Expert -- DB2 UDB V5 Application Development", in October 2000 at IDUG in Geneva). The last version of the book I am aware of was published in 16 August 2011, based on version 9.7 of Db2 LUW. In the past years I've googled sometimes to check if there was a new version of the book and if someone decided to maintain it. I didn't find any new version and, as far as I know, Graeme Birchall deleted everything he had (his homepage, where the book was published and every links that he maintained). 10 | 11 | Because I've learned a lot and I found the book very good to help people that are starting with SQL, I decided to take the contents of the book as they were in the last published version and use it to initiate a new version of the book. The idea behind it is to show how SQL works and enrich it with examples of the daily work with SQL. I use SQL almost everyday in my work. As I've heard in one of the many conferences I've visited in the last 30 years, "SQL is a very easy language, when you formulate very easy queries". You will find easy queries for simple use cases and complex queries for complex use cases. This is not necessarily a rule: I've seen many complex queries for simple use cases and great simple queries for complex use cases. The best SQL statements follow the old good KISS rule: Keep It Simple and Stupid. 12 | 13 | Somethings that I decided to change in this book, comparing to the original version: 14 | 15 | * I've migrated the text to asciidoc and opened a project in GitHub (https://github.com/rodneykrick/db2-sql-cookbook). As the people at *_Asciidoc_* use to say: "It's just text, mate!" I believe with this format the community will be able to contribute and improve the content. 16 | * Graeme tried to keep syntax diagrams in his book. I'll try to follow a more practical approach in this version of the book. You won't find syntax diagrams, just sample code that was tested in Db2 (some will work in other RDBMS, it would be great and helpful if we manage to check and document this). If you want to learn more about the statement and the syntax, you should use the SQL reference book of your RDBMS, in the version you are using. 17 | * To publish the result (the last version of the book) I reserved a new domain (http://db2-sql-cookbook.org). I'll try to generate a HTML Version of the book and upload it as frequently as possible. The PDF version can be found here: http://db2-sql-cookbook.org/pdf/Db2_SQL_Cookbook.pdf. It will be generated together with the HTML version. 18 | 19 | Some notes: 20 | 21 | * I will manage the project in the first phase. I hope, the experts outside will join it, enrich and update the content (this is what I also intend to do). Maybe we get more and more people involved and keep this book up to date. 22 | * If someone knows Graeme Birchall please let him know that we are trying to keep his work going on. I only decided to "clone" his book because of his statements regarding the distribution of the book (see <>). I really searched for him in the www, but wasn't successful. As I finished the first version I've put a message on the Db2 Listserver (hosted at http://www.idug.org) and got an answer from Ian Bjorhovde. He had the same idea in the past and contacted Graeme. Graeme gave him a copy of his book and wrote in his answer: "So think of this as one of those copyleft situations where I am putting the document in the public domain". Andres Gomez Casanova suggested to put the work under the Creative Commons Attribution-ShareAlike 4.0 International license with the following arguments: "With a specific license the original work from Graeme and any improvement will remain with the same rights, and prevent from any unfair use". I think this is a good thing! 23 | * And just another point: if you never worked with SQL, I recommend you to start with the SQL Tutorial in w3schools. It is a great site to start learing it! [https://www.w3schools.com/sql/default.asp] 24 | 25 | Have fun! 26 | 27 | Rodney Krick + 28 | rk@aformatik.de 29 | -------------------------------------------------------------------------------- /chapters_asciidoc/00 Frontpage.asciidoc: -------------------------------------------------------------------------------- 1 | :source-highlighter: rouge 2 | = Db2 SQL Cookbook 3 | 4 | 5 | :author: Graeme Birchall (until Version 9.7, 2011) 6 | :email: rk@aformatik.de 7 | 8 | 9 | :sectnums: 10 | 11 | ++++ 12 | 13 | ++++ 14 | 15 | :icons: font 16 | :toc: left 17 | :toclevels: 4 18 | :toc-title: Content 19 | :description: Overview of SQL in Db2 Linux, Windows and Unix (LUW) 20 | :keywords: Db2, SQL, Query Language, SQL Cookbook, Grame Birchall 21 | 22 | Graeme Birchall (until Version 9.7, 2011) + 23 | Version 1.0, Rodney Krick, November 2019 + 24 | Contributors: Andres Gomez Casanova, Robert Mala, Tobias Jeske 25 | 26 | ++++ 27 |
28 | Creative Commons License
Db2 SQL Cookbook by Graeme Birchall is licensed under a Creative Commons Attribution-ShareAlike 4.0 International License.
Based on a work at https://github.com/rodneykrick/db2-sql-cookbook.
Permissions beyond the scope of this license may be available at https://github.com/rodneykrick/db2-sql-cookbook 29 |
30 | ++++ 31 | -------------------------------------------------------------------------------- /chapters_asciidoc/01 Introduction.asciidoc: -------------------------------------------------------------------------------- 1 | [Preamble] 2 | == Introduction 3 | 4 | Project in GitHub: https://github.com/rodneykrick/db2-sql-cookbook 5 | The PDF version can be found here: http://db2-sql-cookbook.org/pdf/Db2_SQL_Cookbook.pdf. 6 | 7 | This version of the book is intended to be a community effort to help people learn SQL. Join, improve, enjoy, have fun! 8 | -------------------------------------------------------------------------------- /chapters_asciidoc/02 Document history.asciidoc: -------------------------------------------------------------------------------- 1 | == Document history 2 | 3 | (The history of the original book can bee seen at <>) 4 | 5 | [cols="1,2,7", options="header"] 6 | |=== 7 | |Version |Date |Content 8 | |1.0 |9.10.2019 |Started new project in GitHub. Text transformed to asciidoc. + 9 | Syntax diagrams were removed. + 10 | Cross references updated. 11 | |1.1 |24.11.2019|Added license terms 12 | |1.2 |06.12.2019|Update functions to Db2 version 11.1 13 | |1.3 |18.01.2020|Added Time Travel chapter. 14 | |1.4 |30.08.2022|Personal notes removed from introduction. 15 | |1.5 |06.10.2022|VARCHAR_FORMAT explation corrected. New contributor added. 16 | |=== 17 | 18 | 19 | -------------------------------------------------------------------------------- /chapters_asciidoc/03 Quick find.asciidoc: -------------------------------------------------------------------------------- 1 | == Quick find 2 | 3 | === Index of Concepts 4 | 5 | ==== Join rows 6 | (((join rows))) 7 | To combine matching rows in multiple tables, use a join (see <>). 8 | 9 | EMP_NM 10 | 11 | [options="header",] 12 | |=== 13 | |ID |NAME 14 | |10 |Sanders 15 | |20 |Pernal 16 | |50 |Hanes 17 | |=== 18 | 19 | EMP_JB 20 | 21 | [options="header",] 22 | |=== 23 | |ID |JOB 24 | |10 |Sales 25 | |20 |Clerk 26 | |=== 27 | 28 | .Join example 29 | [source,sql] 30 | .... 31 | SELECT nm.id 32 | , nm.name 33 | , jb.job 34 | FROM emp_nm nm 35 | , emp_jb jb 36 | WHERE nm.id = jb.id 37 | ORDER BY 1; 38 | .... 39 | 40 | _ANSWER_ 41 | 42 | [options="header",] 43 | |=== 44 | |ID |NAME |JOB 45 | |10 |Sanders |Sales 46 | |20 |Pernal |Clerk 47 | |=== 48 | 49 | 50 | ==== Outer Join 51 | (((outer join))) 52 | To get all of the rows from one table, plus the matching rows from another table (if there are any), use an outer join (see <>). 53 | 54 | EMP_NM 55 | 56 | [options="header",] 57 | |=== 58 | |ID |NAME 59 | |10 |Sanders 60 | |20 |Pernal 61 | |50 |Hanes 62 | |=== 63 | 64 | EMP_JB 65 | 66 | [options="header",] 67 | |=== 68 | |ID |JOB 69 | |10 |Sales 70 | |20 |Clerk 71 | |=== 72 | 73 | .Left-outer-join example 74 | [source,sql] 75 | .... 76 | SELECT nm.id ,nm.name ,jb.job 77 | FROM emp_nm nm 78 | LEFT OUTER JOIN emp_jb jb 79 | ON nm.id = jb.id 80 | ORDER BY nm.id; 81 | .... 82 | 83 | _ANSWER_ 84 | 85 | [options="header",] 86 | |=== 87 | |ID |NAME |JOB 88 | |10 |Sanders |Sales 89 | |20 |Pernal |Clerk 90 | |50 |Hanes |- 91 | |=== 92 | 93 | 94 | To get rows from either side of the join, regardless of whether they match (the join) or not, use a full outer join (see <>). 95 | 96 | [[null-values--replace]] 97 | ==== Null Values & Replace 98 | 99 | Use the COALESCE function (see <>) to replace a null value (e.g. generated in an outer join) with a non-null value. 100 | 101 | ==== Select Where No Match 102 | 103 | To get the set of the matching rows from one table where something is true or false in another table (e.g. no corresponding row), use a sub-query (see <>). 104 | 105 | EMP_NM 106 | 107 | [options="header",] 108 | |=== 109 | |ID |NAME 110 | |10 |Sanders 111 | |20 |Pernal 112 | |50 |Hanes 113 | |=== 114 | 115 | EMP_JB 116 | 117 | [options="header",] 118 | |=== 119 | |ID |JOB 120 | |10 |Sales 121 | |20 |Clerk 122 | |=== 123 | 124 | .Sub-query example 125 | [source,sql] 126 | .... 127 | SELECT * FROM emp_nm nm 128 | WHERE NOT EXISTS 129 | (SELECT * FROM emp_jb jb 130 | WHERE nm.id = jb.id) 131 | ORDER BY id; 132 | .... 133 | 134 | _ANSWER_ 135 | 136 | [options="header",] 137 | |=== 138 | |ID |NAME 139 | |50 |Hanes 140 | |=== 141 | 142 | 143 | ==== Append Rows 144 | 145 | To add (append) one set of rows to another set of rows, use a union (see <>). 146 | 147 | EMP_NM 148 | 149 | [options="header",] 150 | |=== 151 | |ID |NAME 152 | |10 |Sanders 153 | |20 |Pernal 154 | |50 |Hanes 155 | |=== 156 | 157 | EMP_JB 158 | 159 | [options="header",] 160 | |=== 161 | |ID |JOB 162 | |10 |Sales 163 | |20 |Clerk 164 | |=== 165 | 166 | .Union example 167 | [source,sql] 168 | .... 169 | SELECT * 170 | FROM emp_nm 171 | WHERE emp_nm.name < 'S' 172 | UNION 173 | SELECT * 174 | FROM emp_jb 175 | ORDER BY 1, 2; 176 | .... 177 | 178 | _ANSWER_ 179 | 180 | [options="header",] 181 | |=== 182 | |ID|2 183 | |10|Sales 184 | |20|Clerk 185 | |20|Pernal 186 | |50|Hanes 187 | |=== 188 | 189 | 190 | ==== Assign Output Numbers 191 | 192 | To assign line numbers to SQL output, use the ROW_NUMBER function (see <>). 193 | 194 | EMP_JB 195 | 196 | [options="header",] 197 | |=== 198 | |ID |JOB 199 | |10 |Sales 200 | |20 |Clerk 201 | |=== 202 | 203 | .Assign row-numbers example 204 | [source,sql] 205 | .... 206 | SELECT id 207 | , job 208 | , ROW_NUMBER() OVER(ORDER BY job) AS R 209 | FROM emp_jb 210 | ORDER BY job; 211 | .... 212 | 213 | _ANSWER_ 214 | 215 | [options="header",] 216 | |=== 217 | |ID |JOB |R 218 | |20 |Clerk|1 219 | |10 |Sales|2 220 | |=== 221 | 222 | 223 | ==== Assign Unique Key Numbers 224 | 225 | To make each row inserted into a table automatically get a unique key value, use an identity column, or a sequence, when creating the table (see <>). 226 | 227 | ==== If-Then-Else Logic 228 | 229 | To include if-then-else logical constructs in SQL stmts, use the CASE phrase (see <>). 230 | 231 | EMP_JB 232 | [options="header",] 233 | |=== 234 | |ID |JOB 235 | |10 |Sales 236 | |20 |Clerk 237 | |=== 238 | 239 | .Case stmt example 240 | [source,sql] 241 | .... 242 | SELECT id 243 | , job 244 | , CASE 245 | WHEN job = 'Sales' THEN 'Fire' 246 | ELSE 'Demote' 247 | END AS STATUS 248 | FROM emp_jb; 249 | .... 250 | 251 | _ANSWER_ 252 | 253 | [options="header",] 254 | |=== 255 | |ID |JOB |STATUS 256 | |10 |Sales|Fire 257 | |20 |Clerk|Demote | 258 | |=== 259 | 260 | 261 | ==== Get Dependents 262 | 263 | To get all of the dependents of some object, regardless of the degree of separation from the parent to the child, use recursion (see <>). 264 | 265 | FAMILY 266 | 267 | [options="header",] 268 | |=== 269 | |PARNT |CHILD 270 | |GrDad |Dad 271 | |Dad |Dghtr 272 | |Dghtr |GrSon 273 | |Dghtr |GrDtr 274 | |=== 275 | 276 | .Recursion example 277 | [source,sql] 278 | .... 279 | WITH temp (persn, lvl) 280 | AS (SELECT parnt, 1 281 | FROM family 282 | WHERE parnt = 'Dad' 283 | UNION ALL 284 | SELECT child, Lvl + 1 285 | FROM temp, family 286 | WHERE persn = parnt) 287 | SELECT * FROM temp; 288 | .... 289 | 290 | _ANSWER_ 291 | 292 | [options="header",] 293 | |=== 294 | |PERSN |LVL 295 | |Dad |1 296 | |Dghtr |2 297 | |GrSon |3 298 | |GrDtr |3 299 | |=== 300 | 301 | 302 | ==== Convert String to Rows 303 | 304 | To convert a (potentially large) set of values in a string (character field) into separate rows (e.g. one row per word), use recursion (see <>). 305 | 306 | *INPUT DATA* "Some silly text" 307 | Use Recursive SQL 308 | 309 | _ANSWER_ 310 | 311 | .Convert string to rows 312 | [options="header",] 313 | |=== 314 | |TEXT |LINE# 315 | |Some |1 316 | |silly |2 317 | |text |3 318 | |=== 319 | 320 | Be warned - in many cases, the code is not pretty. 321 | 322 | ==== Convert Rows to String 323 | 324 | To convert a (potentially large) set of values that are in multiple rows into a single combined field, use recursion (see <>). 325 | 326 | INPUT DATA 327 | 328 | [options="header",] 329 | |=== 330 | |TEXT |LINE# 331 | |Some |1 332 | |silly|2 333 | |text |3 334 | |=== 335 | Use Recursive SQL 336 | 337 | ANSWER: "Some silly text" 338 | 339 | ==== Fetch First "n" Rows 340 | 341 | To fetch the first "n" matching rows, use the FETCH FIRST notation (see <>). 342 | 343 | EMP_NM 344 | 345 | [options="header",] 346 | |=== 347 | |ID|NAME 348 | |10|Sanders 349 | |20|Pernal 350 | |50|Hanes 351 | |=== 352 | 353 | .Fetch first "n" rows example 354 | [source,sql] 355 | .... 356 | SELECT * FROM 357 | emp_nm 358 | ORDER BY id DESC 359 | FETCH FIRST 2 ROWS ONLY; 360 | .... 361 | 362 | _ANSWER_ 363 | 364 | [options="header",] 365 | |=== 366 | |ID |NAME 367 | |50 |Hanes 368 | |20 |Pernal 369 | |=== 370 | 371 | Another way to do the same thing is to assign row numbers to the output, and then fetch those rows where the row-number is less than "n" (see <>). 372 | 373 | ==== Fetch Subsequent "n" Rows 374 | 375 | To the fetch the "n" through "n + m" rows, first use the ROW_NUMBER function to assign output numbers, then put the result in a nested-table-expression, and then fetch the rows with desired numbers. 376 | 377 | ==== Fetch Uncommitted Data 378 | 379 | To retrieve data that may have been changed by another user, but which they have yet to commit, use the WITH UR (Uncommitted Read) notation. 380 | 381 | EMP_NM 382 | 383 | [options="header",] 384 | |=== 385 | |ID|NAME 386 | |10|Sanders 387 | |20|Pernal 388 | |50|Hanes 389 | |=== 390 | 391 | .Fetch WITH UR example 392 | [source,sql] 393 | .... 394 | SELECT * 395 | FROM emp_nm 396 | WHERE name like 'S%' 397 | WITH UR; 398 | .... 399 | 400 | _ANSWER_ 401 | 402 | [options="header",] 403 | |=== 404 | |ID|NAME 405 | |10|Sanders 406 | |=== 407 | 408 | 409 | Using this option can result in one fetching data that is subsequently rolled back, and so was never valid. Use with extreme care. 410 | 411 | ==== Summarize Column Contents 412 | 413 | Use a column function (see <>) to summarize the contents of a column. 414 | 415 | EMP_NM 416 | 417 | [options="header",] 418 | |=== 419 | |ID|NAME 420 | |10|Sanders 421 | |20|Pernal 422 | |50|Hanes| 423 | |=== 424 | 425 | .Column Functions example 426 | [source,sql] 427 | .... 428 | SELECT AVG(id)AS avg 429 | ,MAX(name) AS maxn 430 | ,COUNT(*) AS #rows 431 | FROM emp_nm; 432 | .... 433 | 434 | _ANSWER_ 435 | 436 | [options="header",] 437 | |=== 438 | |AVG|MAXN |#ROWS 439 | |26 |Sanders |3 440 | |=== 441 | 442 | ==== Subtotals and Grand Totals 443 | 444 | To obtain subtotals and grand-totals, use the ROLLUP or CUBE statements (see <>). 445 | 446 | .Subtotal and Grand-total example 447 | [source,sql] 448 | .... 449 | SELECT job 450 | ,dept 451 | ,SUM(salary) AS sum_sal 452 | ,COUNT(*) AS #emps 453 | FROM staff 454 | WHERE dept < 30 455 | AND salary < 90000 456 | AND job < 'S' 457 | GROUP BY ROLLUP(job, dept) 458 | ORDER BY job, dept; 459 | .... 460 | 461 | ANSWER 462 | 463 | [options="header",] 464 | |=== 465 | |JOB |DEPT|SUM_SAL |#EMPS 466 | |Clerk|15 |84766.70 |2 467 | |Clerk|20 |77757.35 |2 468 | |Clerk|- |162524.05|4 469 | |Mgr |10 |243453.45|3 470 | |Mgr |15 |80659.80 |1 471 | |Mgr |- |324113.25|4 472 | |- |- |486637.30|8 473 | |=== 474 | 475 | ==== Enforcing Data Integrity 476 | 477 | When a table is created, various Db2 features can be used to ensure that the data entered in the table is always correct: 478 | 479 | * Uniqueness (of values) can be enforced by creating unique indexes. 480 | * Check constraints can be defined to limit the values that a column can have. 481 | * Default values (for a column) can be defined - to be used when no value is provided. 482 | * Identity columns (see <>), can be defined to automatically generate unique numeric values (e.g. invoice numbers) for all of the rows in a table. Sequences can do the same thing over multiple tables. 483 | * Referential integrity rules can be created to enforce key 484 | relationships between tables. 485 | * Triggers can be defined to enforce more complex integrity rules, and also to do things (e.g. populate an audit trail) whenever data is changed. 486 | 487 | See the Db2 manuals for documentation or <> for more information about the above. 488 | 489 | ==== Hide Complex SQL 490 | 491 | One can create a view (see <>) to hide complex SQL that is run repetitively. Be warned however that doing so can make it significantly harder to tune the SQL - because some of the logic will be in the user code, and some in the view definition. 492 | 493 | === Summary Table 494 | 495 | Some queries that use a GROUP BY can be made to run much faster by defining a summary table (see <>) that Db2 automatically maintains. Subsequently, when the user writes the original GROUP BY against the source-data table, the optimizer substitutes with a much simpler (and faster) query against the summary table. 496 | 497 | 498 | -------------------------------------------------------------------------------- /chapters_asciidoc/06 Coumpound SQL.asciidoc: -------------------------------------------------------------------------------- 1 | [[compound.sql.chapter]] 2 | == Compound SQL 3 | (((Compound SQL))) 4 | A compound statement groups multiple independent SQL statements into a single executable. In addition, simple processing logic can be included to create what is, in effect, a very basic program. Such statements can be embedded in triggers, SQL functions, SQL methods, and dynamic SQL statements. 5 | 6 | === Introduction 7 | 8 | A compound SQL statement begins with an (optional) name, followed by the variable declarations, followed by the procedural logic. 9 | 10 | Below is a compound statement that reads a set of rows from the STAFF table and, for each row fetched, updates the COMM field to equal the current fetch number. 11 | 12 | .Sample Compound SQL statement 13 | [source,sql] 14 | .... 15 | BEGIN ATOMIC 16 | DECLARE cntr SMALLINT DEFAULT 1; 17 | FOR V1 AS 18 | SELECT id as idval 19 | FROM staff 20 | WHERE id < 80 21 | ORDER BY id 22 | DO 23 | UPDATE staff 24 | SET comm = cntr 25 | WHERE id = idval; 26 | SET cntr = cntr + 1; 27 | END FOR; 28 | END 29 | .... 30 | 31 | ==== Statement Delimiter 32 | (((Statement delimiter))) 33 | Db2 SQL does not come with a designated statement delimiter 34 | (terminator), though a semicolon is typically used. However, a semi-colon cannot be used in a compound SQL statement because that character is used to differentiate the sub-components of the statement. In Db2BATCH, one can run the SET DELIMITER command (intelligent comment) to use something other than a semi-colon. The following script illustrates this usage: 35 | 36 | .Set Delimiter example 37 | [source,sql] 38 | .... 39 | --#SET DELIMITER ! 40 | SELECT NAME FROM STAFF WHERE id = 10! 41 | --#SET DELIMITER ; 42 | SELECT NAME FROM STAFF WHERE id = 20; 43 | .... 44 | 45 | In the Db2 command processor one can do the same thing using the terminator keyword: 46 | 47 | .Set Terminator example 48 | [source,sql] 49 | .... 50 | --#SET TERMINATOR ! 51 | SELECT NAME FROM STAFF WHERE id = 10! 52 | --#SET TERMINATOR ; 53 | SELECT NAME FROM STAFF WHERE id = 20; 54 | .... 55 | 56 | ==== SQL Statement Usage 57 | 58 | When used in dynamic SQL, the following control statements can be used: 59 | 60 | * FOR statement 61 | * GET DIAGNOSTICS statement 62 | * IF statement 63 | * ITERATE statement 64 | * LEAVE statement 65 | * SIGNAL statement 66 | * WHILE statement 67 | 68 | NOTE: There are many more PSM (persistent stored modules) control statements than what is shown above. But only these ones can be used in Compound SQL statements. 69 | 70 | The following SQL statements can be issued: 71 | 72 | * fullselect 73 | * UPDATE 74 | * DELETE 75 | * INSERT 76 | * SET variable statement 77 | 78 | ==== DECLARE Variables 79 | 80 | All variables have to be declared at the start of the compound statement. Each variable must be given a name and a type and, optionally, a default (start) value. 81 | 82 | .DECLARE examples 83 | [source,sql] 84 | .... 85 | BEGIN ATOMIC 86 | DECLARE aaa, bbb, ccc SMALLINT DEFAULT 1; 87 | DECLARE ddd CHAR(10) DEFAULT NULL; 88 | DECLARE eee INTEGER; 89 | SET eee = aaa + 1; 90 | UPDATE staff 91 | SET comm = aaa 92 | , salary = bbb 93 | , years = eee 94 | WHERE id = 10; 95 | END 96 | .... 97 | 98 | *FOR Statement* 99 | 100 | The ((FOR)) statement executes a group of statements for each row fetched from a query. 101 | 102 | In the next example one row is fetched per year of service (for selected years) in the STAFF table. That row is then used to do two independent updates to the three matching rows: 103 | 104 | .FOR statement example 105 | [source,sql] 106 | .... 107 | BEGIN ATOMIC 108 | FOR V1 AS 109 | SELECT years AS yr_num 110 | , max(id) AS max_id 111 | FROM staff 112 | WHERE years < 4 113 | GROUP BY years 114 | ORDER BY years 115 | DO 116 | UPDATE staff 117 | SET salary = salary / 10 118 | WHERE id = max_id; 119 | UPDATE staff 120 | set comm = 0 121 | WHERE years = yr_num; 122 | END FOR; 123 | END 124 | .... 125 | 126 | *BEFORE* 127 | [options="header",] 128 | |=== 129 | |ID | SALARY | COMM 130 | |180| 37009.75| 236.50 131 | |230| 83369.80| 189.65 132 | |330| 49988.00| 55.50 133 | |=== 134 | *AFTER* 135 | [options="header",] 136 | |=== 137 | |ID | SALARY | COMM 138 | |180| 37009.75| 0.00 139 | |230| 8336.98 | 0.00 140 | |330| 4998.80 | 0.00 141 | |=== 142 | 143 | ==== GET DIAGNOSTICS Statement 144 | 145 | The ((GET DIAGNOSTICS)) statement returns information about the most recently run SQL statement. One can either get the number of rows processed (i.e. inserted, updated, or deleted), or the return status (for an external procedure call). 146 | 147 | In the example below, some number of rows are updated in the STAFF table. Then the count of rows updated is obtained, and used to update a row in the STAFF table: 148 | 149 | .GET DIAGNOSTICS statement example 150 | [source,sql] 151 | .... 152 | BEGIN ATOMIC 153 | DECLARE numrows INT DEFAULT 0; 154 | UPDATE staff 155 | SET salary = 12345 156 | WHERE id < 100; 157 | GET DIAGNOSTICS numrows = ROW_COUNT; 158 | UPDATE staff 159 | SET salary = numrows 160 | WHERE id = 10; 161 | END 162 | .... 163 | 164 | ==== IF Statement 165 | 166 | The ((IF)) statement is used to do standard if-then-else branching logic. It always begins with an IF THEN statement and ends with and END IF statement. 167 | 168 | The next example uses if-then-else logic to update one of three rows in the STAFF table, depending on the current timestamp value: 169 | 170 | .IF statement example 171 | [source,sql] 172 | .... 173 | BEGIN ATOMIC 174 | DECLARE cur INT; 175 | SET cur = MICROSECOND(CURRENT TIMESTAMP); 176 | IF cur > 600000 THEN 177 | UPDATE staff 178 | SET name = CHAR(cur) 179 | WHERE id = 10; 180 | ELSEIF cur > 300000 THEN 181 | UPDATE staff 182 | SET name = CHAR(cur) 183 | WHERE id = 20; 184 | ELSE 185 | UPDATE staff 186 | SET name = CHAR(cur) 187 | WHERE id = 30; 188 | END IF; 189 | END 190 | .... 191 | 192 | ==== ITERATE Statement 193 | 194 | The ((ITERATE)) statement causes the program to return to the beginning of the labeled loop. 195 | 196 | In next example, the second update statement will never get performed because the ITERATE will always return the program to the start of the loop: 197 | 198 | .ITERATE statement example 199 | [source,sql] 200 | .... 201 | BEGIN ATOMIC 202 | DECLARE cntr INT DEFAULT 0; 203 | whileloop: 204 | WHILE cntr < 60 DO 205 | SET cntr = cntr + 10; 206 | UPDATE staff 207 | SET salary = cntr 208 | WHERE id = cntr; 209 | ITERATE whileloop; 210 | UPDATE staff 211 | SET comm = cntr + 1 212 | WHERE id = cntr; 213 | END WHILE; 214 | END 215 | .... 216 | 217 | ==== LEAVE Statement 218 | 219 | The ((LEAVE)) statement exits the labeled loop. 220 | 221 | In the next example, the WHILE loop would continue forever, if left to its own devices. But after some random number of iterations, the LEAVE statement will exit the loop: 222 | 223 | .LEAVE statement example 224 | [source,sql] 225 | .... 226 | BEGIN ATOMIC 227 | DECLARE cntr INT DEFAULT 1; 228 | whileloop: 229 | WHILE 1 <> 2 DO 230 | SET cntr = cntr + 1; 231 | IF RAND() > 0.99 THEN 232 | LEAVE whileloop; 233 | END IF; 234 | END WHILE; 235 | UPDATE staff 236 | SET salary = cntr 237 | WHERE id = 10; 238 | END 239 | .... 240 | 241 | [[signal.statement]] 242 | ==== SIGNAL Statement 243 | 244 | The ((SIGNAL)) statement is used to issue an error or warning message. 245 | 246 | The next example loops a random number of times, and then generates an error message using the SIGNAL command, saying how many loops were done: 247 | 248 | .SIGNAL statement example 249 | [source,sql] 250 | .... 251 | BEGIN ATOMIC 252 | DECLARE cntr INT DEFAULT 1; 253 | DECLARE emsg CHAR(20); 254 | whileloop: 255 | WHILE RAND() < .99 DO 256 | SET cntr = cntr + 1; 257 | END WHILE; 258 | SET emsg = '#loops: ' || CHAR(cntr); 259 | SIGNAL SQLSTATE '75001' SET MESSAGE_TEXT = emsg; 260 | END 261 | .... 262 | 263 | ==== WHILE Statement 264 | 265 | The ((WHILE)) statement repeats one or more statements while some condition is true. 266 | 267 | The next statement has two nested WHILE loops, and then updates the STAFF table: 268 | 269 | .WHILE statement example 270 | [source,sql] 271 | .... 272 | BEGIN ATOMIC 273 | DECLARE c1, C2 INT DEFAULT 1; 274 | WHILE c1 < 10 DO 275 | WHILE c2 < 20 DO 276 | SET c2 = c2 + 1; 277 | END WHILE; 278 | SET c1 = c1 + 1; 279 | END WHILE; 280 | UPDATE staff 281 | SET salary = c1 282 | , comm = c2 283 | WHERE id = 10; 284 | END 285 | .... 286 | 287 | ==== Other Usage 288 | 289 | The following Db2 objects also support the language elements described above: 290 | 291 | * Triggers 292 | * Stored procedures 293 | * User-defined functions 294 | * Embedded compound SQL (in programs). 295 | 296 | Some of the above support many more language elements. For example stored procedures that are written in SQL also allow the following: 297 | `ASSOCIATE, CASE, GOTO, LOOP, REPEAT, RESIGNAL` , and `RETURN` . 298 | 299 | ==== Test Query 300 | 301 | To illustrate some of the above uses of compound SQL, we are going to get from the STAFF table a complete list of departments, and the number of rows in each department. Here is the basic query, with the related answer: 302 | 303 | .List departments in STAFF table 304 | [source,sql] 305 | .... 306 | SELECT dept 307 | , count(*) as #rows 308 | FROM staff 309 | GROUP BY dept 310 | ORDER BY dept; 311 | .... 312 | 313 | *ANSWER* 314 | [options="header",] 315 | |=== 316 | |DEPT| #ROWS 317 | |10 | 4 318 | |15 | 4 319 | |20 | 4 320 | |38 | 5 321 | |42 | 4 322 | |51 | 5 323 | |66 | 5 324 | |84 | 4 325 | |=== 326 | 327 | If all you want to get is this list, the above query is the way to go. 328 | But we will get the same answer using various other methods, just to show how it can be done using compound SQL statements. 329 | 330 | ===== Trigger 331 | (((Trigger))) 332 | One cannot get an answer using a trigger. All one can do is alter what happens during an insert, update, or delete. With this in mind, the following example does the following: 333 | 334 | * Sets the statement delimiter to an "!". Because we are using compound SQL inside the trigger definition, we cannot use the usual semi-colon. 335 | * Creates a new table (note: triggers are not allowed on temporary tables). 336 | * Creates an INSERT trigger on the new table. This trigger gets the number of rows per department in the STAFF table - for each row (department) inserted. 337 | * Inserts a list of departments into the new table. 338 | * Selects from the new table. 339 | 340 | Now for the code: 341 | 342 | .Trigger with compound SQL 343 | [source,sql] 344 | .... 345 | --#SET DELIMITER ! 346 | CREATE TABLE dpt 347 | ( dept SMALLINT NOT NULL 348 | , #names SMALLINT 349 | , PRIMARY KEY(dept))! 350 | COMMIT! 351 | 352 | CREATE TRIGGER dpt1 AFTER INSERT ON dpt 353 | REFERENCING NEW AS NNN 354 | FOR EACH ROW 355 | MODE Db2SQL 356 | BEGIN ATOMIC 357 | DECLARE namecnt SMALLINT DEFAULT 0; 358 | FOR getnames AS 359 | SELECT COUNT(*) AS #n 360 | FROM staff 361 | WHERE dept = nnn.dept 362 | DO 363 | SET namecnt = #n; 364 | END FOR; 365 | UPDATE dpt 366 | SET #names = namecnt 367 | WHERE dept = nnn.dept; 368 | END! 369 | COMMIT! 370 | 371 | INSERT INTO dpt (dept) 372 | SELECT DISTINCT dept 373 | FROM staff! 374 | COMMIT! 375 | SELECT * 376 | FROM dpt 377 | ORDER BY dept! 378 | .... 379 | 380 | NOTE: This example uses an "!" as the stmt delimiter. 381 | 382 | *ANSWER* 383 | [options="header",] 384 | |=== 385 | |DEPT| #NAMES 386 | |10 | 4 387 | |15 | 4 388 | |20 | 4 389 | |38 | 5 390 | |42 | 4 391 | |51 | 5 392 | |66 | 5 393 | |84 | 4 394 | |=== 395 | 396 | NOTE: The above code was designed to be run in Db2BATCH. The "set delimiter" notation will probably not work in other environments. 397 | 398 | ===== Scalar Function 399 | (((Scalar function))) 400 | One can do something very similar to the above that is almost as stupid using a user-defined scalar function, that calculates the number of rows in a given department. The basic logic will go as follows: 401 | 402 | * Set the statement delimiter to an "!". 403 | * Create the scalar function. 404 | * Run a query that first gets a list of distinct departments, then calls the function. 405 | 406 | Here is the code: 407 | 408 | .Scalar Function with compound SQL 409 | [source,sql] 410 | .... 411 | --#SET DELIMITER ! 412 | CREATE FUNCTION dpt1 (deptin SMALLINT) 413 | RETURNS SMALLINT 414 | BEGIN ATOMIC 415 | DECLARE num_names SMALLINT; 416 | FOR getnames AS 417 | SELECT COUNT(*) AS #n 418 | FROM staff 419 | WHERE dept = deptin 420 | DO 421 | SET num_names = #n; 422 | END FOR; 423 | RETURN num_names; 424 | END! 425 | 426 | COMMIT! 427 | 428 | SELECT XXX.* 429 | , dpt1(dept) as #names 430 | FROM 431 | (SELECT dept 432 | FROM staff 433 | GROUP BY dept 434 | ) AS XXX 435 | ORDER BY dept! 436 | .... 437 | 438 | NOTE: This example uses an "!" as the stmt delimiter. 439 | 440 | *ANSWER* 441 | [options="header",] 442 | |=== 443 | |DEPT| #NAMES 444 | |10 | 4 445 | |15 | 4 446 | |20 | 4 447 | |38 | 5 448 | |42 | 4 449 | |51 | 5 450 | |66 | 5 451 | |84 | 4 452 | |=== 453 | 454 | Because the query used in the above function will only ever return one row, we can greatly simplify the function definition thus: 455 | 456 | .Scalar Function with compound SQL 457 | [source,sql] 458 | .... 459 | --#SET DELIMITER ! 460 | CREATE FUNCTION dpt1 (deptin SMALLINT) 461 | RETURNS SMALLINT 462 | BEGIN ATOMIC 463 | RETURN 464 | SELECT COUNT(*) 465 | FROM staff 466 | WHERE dept = deptin; 467 | END! 468 | COMMIT! 469 | .... 470 | 471 | NOTE: This example uses an "!" as the stmt delimiter. 472 | 473 | .... 474 | SELECT XXX.* 475 | , dpt1(dept) as #names 476 | FROM 477 | (SELECT dept 478 | FROM staff 479 | GROUP BY dept 480 | ) AS XXX 481 | ORDER BY dept! 482 | .... 483 | 484 | In the above example, the RETURN statement is directly finding the one matching row, and then returning it to the calling statement. 485 | 486 | ===== Table Function 487 | (((Table function))) 488 | Below is almost exactly the same logic, this time using a table function: 489 | 490 | Table Function with compound SQL 491 | [source,sql] 492 | .... 493 | --#SET DELIMITER ! 494 | CREATE FUNCTION dpt2 () 495 | RETURNS TABLE ( dept SMALLINT 496 | , #names SMALLINT) 497 | BEGIN ATOMIC 498 | RETURN 499 | SELECT dept 500 | , count(*) 501 | FROM staff 502 | GROUP BY dept 503 | ORDER BY dept; 504 | END! 505 | 506 | COMMIT! 507 | 508 | --#SET DELIMITER ; 509 | SELECT * 510 | FROM TABLE(dpt2()) T1 511 | ORDER BY dept; 512 | .... 513 | 514 | NOTE: This example uses an "!" as the stmt delimiter. 515 | 516 | *ANSWER* 517 | [options="header",] 518 | |=== 519 | |DEPT| #NAMES 520 | |10 | 4 521 | |15 | 4 522 | |20 | 4 523 | |38 | 5 524 | |42 | 4 525 | |51 | 5 526 | |66 | 5 527 | |84 | 4 528 | |=== 529 | 530 | .Sample Compound SQL statement 531 | [source,sql] 532 | .... 533 | BEGIN ATOMIC 534 | DECLARE cntr SMALLINT DEFAULT 1; 535 | FOR V1 AS 536 | SELECT id as idval 537 | FROM staff 538 | WHERE id < 80 539 | ORDER BY id 540 | DO 541 | UPDATE staff SET comm = cntr 542 | WHERE id = idval; 543 | SET cntr = cntr + 1; 544 | END FOR; 545 | END 546 | .... 547 | 548 | 549 | -------------------------------------------------------------------------------- /chapters_asciidoc/07 Column Functions.asciidoc: -------------------------------------------------------------------------------- 1 | [[column.function.chapter]] 2 | == Column Functions or Aggregate Functions 3 | (((Column function))) (((Aggregate functions))) 4 | By themselves, column functions work on the complete set of matching rows. One can use a GROUP BY expression to limit them to a subset of matching rows. One can also use them in an OLAP function to treat individual rows differently. 5 | 6 | WARNING: Be very careful when using either a column function, or the DISTINCT clause, in a join. If the join is incorrectly coded, and does some form of Cartesian Product, the column function may get rid of the all the extra (wrong) rows so that it becomes very hard to confirm that the answer is incorrect. Likewise, be appropriately suspicious whenever you see that someone (else) has used a DISTINCT statement in a join. Sometimes, users add the DISTINCT clause to get rid of duplicate rows that they didn't anticipate and don't understand. 7 | 8 | === Column Functions, Definitions 9 | 10 | ==== ARRAY_AGG 11 | (((ARRAY_AGG))) 12 | Aggregate the set of elements in an array. If an ORDER BY is provided, it determines the order in which the elements are entered into the array. 13 | 14 | ==== AVG 15 | (((AVG))) 16 | Get the average (mean) value of a set of non-null rows. The columns(s) must be numeric. ALL is the default. If DISTINCT is used duplicate values are ignored. If no rows match, the null value is returned. 17 | 18 | .AVG function examples 19 | [source,sql] 20 | .... 21 | SELECT AVG(dept) AS a1 22 | , AVG(ALL dept) AS a2 23 | , AVG(DISTINCT dept) AS a3 24 | , AVG(dept/10) AS a4 25 | , AVG(dept)/10 AS a5 26 | FROM staff 27 | HAVING AVG(dept) > 40; 28 | .... 29 | 30 | _ANSWER_ 31 | [options="header",] 32 | |=== 33 | |A1| A2| A3| A4| A5 34 | |41| 41| 40| 3 | 4 35 | |=== 36 | 37 | WARNING: Observe columns A4 and A5 above. Column A4 has the average of each value divided by 10. Column A5 has the average of all of the values divided by 10. In the former case, precision has been lost due to rounding of the original integer value and the result is arguably 38 | incorrect. This problem also occurs when using the SUM function. 39 | 40 | ===== Averaging Null and Not-Null Values 41 | 42 | Some database designers have an intense and irrational dislike of using nullable fields. What they do instead is define all columns as not-null and then set the individual fields to zero (for numbers) or blank (for characters) when the value is unknown. This solution is reasonable in some situations, but it can cause the AVG function to give what is arguably the wrong answer. One solution to this problem is some form of counseling or group therapy to overcome the phobia. Alternatively, one can use the CASE expression to put null values back into the answer-set being processed by the AVG function. The following SQL statement uses a modified version of the IBM sample STAFF table (all null COMM values were changed to zero) to illustrate the technique: 43 | 44 | .Convert zero to null before doing AVG 45 | [source,sql] 46 | .... 47 | UPDATE staff 48 | SET comm = 0 49 | WHERE comm IS NULL; 50 | 51 | SELECT AVG(salary) AS salary 52 | , AVG(comm) AS comm1 53 | , AVG(CASE comm 54 | WHEN 0 THEN NULL 55 | ELSE comm 56 | END) AS comm2 57 | FROM staff; 58 | .... 59 | 60 | _ANSWER_ 61 | [options="header",] 62 | |=== 63 | |SALARY |COMM1 |COMM2 64 | |67932.78|351.98|513.31 65 | |=== 66 | 67 | [source,sql] 68 | .... 69 | UPDATE staff 70 | SET comm = NULL 71 | WHERE comm = 0; 72 | .... 73 | 74 | The COMM2 field above is the correct average. The COMM1 field is incorrect because it has factored in the zero rows with really represent null values. Note that, in this particular query, one cannot use a WHERE to exclude the "zero" COMM rows because it would affect the average 75 | salary value. 76 | 77 | ===== Dealing with Null Output 78 | 79 | The AVG, MIN, MAX, and SUM functions almost always return a null value when there are no matching rows (see <> for exceptions). One can use the COALESCE function, or a CASE expression, to convert the null value into a suitable substitute. Both methodologies are illustrated below: 80 | 81 | .Convert null output (from AVG) to zero 82 | [source,sql] 83 | .... 84 | SELECT COUNT(*) AS c1 85 | , AVG(salary) AS a1 86 | , COALESCE(AVG(salary),0) AS a2 87 | , CASE 88 | WHEN AVG(salary) IS NULL THEN 0 89 | ELSE AVG(salary) 90 | END AS a3 91 | FROM staff 92 | WHERE id < 10; 93 | .... 94 | 95 | _ANSWER_ 96 | [options="header",] 97 | |=== 98 | |C1| A1| A2| A3 99 | |0 | - | 0 | 0 100 | |=== 101 | 102 | ===== AVG Date/Time Values 103 | 104 | The AVG function only accepts numeric input. However, one can, with a bit of trickery, also use the AVG function on a date field. First convert the date to the number of days since the start of the Current Era, then get the average, then convert the result back to a date. 105 | Please be aware that, in many cases, the average of a date does not really make good business sense. Having said that, the following SQL gets the average birth-date of all employees: 106 | 107 | .AVG of date column 108 | [source,sql] 109 | .... 110 | SELECT AVG(DAYS(birthdate)) 111 | , DATE(AVG(DAYS(birthdate))) 112 | FROM employee; 113 | .... 114 | 115 | _ANSWER_ 116 | [options="header",] 117 | |=== 118 | |1 |2 119 | |721092|1975-04-14 120 | |=== 121 | 122 | Time data can be manipulated in a similar manner using the 123 | MIDNIGHT_SECONDS function. If one is really desperate (or silly), the average of a character field can also be obtained using the ASCII and CHR functions. 124 | 125 | ===== Average of an Average 126 | 127 | In some cases, getting the average of an average gives an overflow error. Inasmuch as you shouldn't do this anyway, it is no big deal: 128 | 129 | .Select average of average 130 | [source,sql] 131 | .... 132 | SELECT AVG(avg_sal) AS avg_avg 133 | FROM (SELECT dept 134 | , AVG(salary) AS avg_sal 135 | FROM staff 136 | GROUP BY dept 137 | ) AS xxx; 138 | .... 139 | 140 | ANSWER: Overflow error 141 | 142 | ==== CORRELATION 143 | (((CORRELATION))) 144 | I don't know a thing about statistics, so I haven't a clue what this function does. But I do know that the SQL Reference is wrong - because it says the value returned will be between 0 and 1. I found that it is between -1 and +1 (see below). The output type is float. 145 | 146 | .CORRELATION function examples 147 | [source,sql] 148 | .... 149 | WITH temp1(col1, col2, col3, col4) AS 150 | (VALUES (0, 0, 0, RAND(1)) 151 | UNION ALL 152 | SELECT col1 + 1 153 | , col2 - 1 154 | , RAND() 155 | , RAND() 156 | FROM temp1 157 | WHERE col1 <= 1000 158 | ) 159 | SELECT DEC(CORRELATION(col1, col1), 5, 3) AS cor11 160 | , DEC(CORRELATION(col1, col2), 5, 3) AS cor12 161 | , DEC(CORRELATION(col2, col3), 5, 3) AS cor23 162 | , DEC(CORRELATION(col3, col4), 5, 3) AS cor34 163 | FROM temp1; 164 | .... 165 | 166 | _ANSWER_ 167 | [options="header",] 168 | |=== 169 | |COR11| COR12 | COR23| COR34 170 | |1.000| -1.000|-0.017| -0.005 171 | |=== 172 | 173 | ==== COUNT 174 | (((COUNT))) 175 | Get the number of values in a set of rows. The result is an integer. The value returned depends upon the options used: 176 | 177 | * COUNT(*) gets a count of matching rows. 178 | * COUNT(expression) gets a count of rows with a non-null expression value. 179 | * COUNT(ALL expression) is the same as the COUNT(expression) statement. 180 | * COUNT(DISTINCT expression) gets a count of distinct non-null expression values. 181 | 182 | .COUNT function examples 183 | [source,sql] 184 | .... 185 | SELECT COUNT(*) AS c1 186 | , COUNT(INT(comm/10)) AS c2 187 | , COUNT(ALL INT(comm/10)) AS c3 188 | , COUNT(DISTINCT INT(comm/10)) AS c4 189 | , COUNT(DISTINCT INT(comm)) AS c5 190 | , COUNT(DISTINCT INT(comm))/10 AS c6 191 | FROM staff; 192 | .... 193 | _ANSWER_ 194 | [options="header",] 195 | |=== 196 | |C1| C2| C3| C4| C5| C6 197 | |35| 24| 24| 19| 24| 2 198 | |=== 199 | 200 | There are 35 rows in the STAFF table (see C1 above), but only 24 of them have non-null commission values (see C2 above). If no rows match, the COUNT returns zero - except when the SQL statement also contains a GROUP BY. In this latter case, the result is no row. 201 | 202 | .COUNT function with and without GROUP BY 203 | [source,sql] 204 | .... 205 | SELECT 'NO GP-BY' AS c1 206 | , COUNT(*) AS c2 207 | FROM staff 208 | WHERE id = -1 209 | UNION 210 | SELECT 'GROUP-BY' AS c1 211 | , COUNT(*) AS c2 212 | FROM staff 213 | WHERE id = -1 214 | GROUP BY dept; 215 | .... 216 | 217 | _ANSWER_ 218 | [options="header",] 219 | |=== 220 | |C1 | C2 221 | |NO GP-BY| 0 222 | |=== 223 | 224 | ==== COUNT_BIG 225 | (((COUNT_BIG))) 226 | Get the number of rows or distinct values in a set of rows. Use this function if the result is too large for the COUNT function. The result is of type decimal 31. If the DISTINCT option is used both duplicate and null values are eliminated. If no rows match, the result is zero. 227 | 228 | .COUNT_BIG function examples 229 | [source,sql] 230 | .... 231 | SELECT COUNT_BIG(*) AS c1 232 | , COUNT_BIG(dept) AS c2 233 | , COUNT_BIG(DISTINCT dept) AS c3 234 | , COUNT_BIG(DISTINCT dept/10) AS c4 235 | , COUNT_BIG(DISTINCT dept)/10 AS c5 236 | FROM STAFF; 237 | .... 238 | 239 | _ANSWER_ 240 | [options="header",] 241 | |=== 242 | |C1 | C2 | C3| C4| C5 243 | |35.| 35.| 8.| 7.| 0. 244 | |=== 245 | 246 | ==== COVARIANCE 247 | (((COVARIANCE))) 248 | Returns the covariance of a set of number pairs. The output type is float. 249 | 250 | .COVARIANCE function examples 251 | [source,sql] 252 | .... 253 | WITH temp1(c1, c2, c3, c4) AS 254 | (VALUES (0 , 0 , 0 , RAND(1)) 255 | UNION ALL 256 | SELECT c1 + 1 257 | , c2 - 1 258 | , RAND() 259 | , RAND() 260 | FROM temp1 261 | WHERE c1 <= 1000 262 | ) 263 | SELECT DEC(COVARIANCE(c1,c1),6,0) AS cov11 264 | , DEC(COVARIANCE(c1,c2),6,0) AS cov12 265 | , DEC(COVARIANCE(c2,c3),6,4) AS cov23 266 | , DEC(COVARIANCE(c3,c4),6,4) AS cov34 267 | FROM temp1; 268 | .... 269 | 270 | _ANSWER_ 271 | [options="header",] 272 | |=== 273 | |COV11 | COV12 | COV23 | COV34 274 | |83666.|-83666.| -1.4689| -0.0004 275 | |=== 276 | 277 | ==== COVARIANCE_SAMP 278 | (((COVARIANCE_SAMP))) 279 | Returns the sample covariance of a set of number pairs. 280 | 281 | ==== CUME_DIST 282 | (((CUME_DIST))) 283 | Returns the cumulative distribution of a row that is hypothetically inserted into a group of rows. 284 | 285 | [[grouping.function]] 286 | ==== GROUPING 287 | (((GROUPING))) 288 | The GROUPING function is used in CUBE, ROLLUP, and GROUPING SETS statements to identify what rows come from which particular GROUPING SET. A value of 1 indicates that the corresponding data field is null because the row is from of a GROUPING SET that does not involve this row. Otherwise, the value is zero. 289 | 290 | .GROUPING function example 291 | [source,sql] 292 | .... 293 | SELECT dept 294 | , AVG(salary) AS salary 295 | , GROUPING(dept) AS df 296 | FROM staff 297 | GROUP BY ROLLUP(dept) 298 | ORDER BY dept; 299 | .... 300 | 301 | _ANSWER_ 302 | [options="header",] 303 | |=== 304 | |DEPT| SALARY | DF 305 | |10 | 83365.86| 0 306 | |15 | 60482.33| 0 307 | |20 | 63571.52| 0 308 | |38 | 60457.11| 0 309 | |42 | 49592.26| 0 310 | |51 | 83218.16| 0 311 | |66 | 73015.24| 0 312 | |84 | 66536.75| 0 313 | |- | 67932.78| 1 314 | |=== 315 | 316 | NOTE: See the section titled "Group By and Having" for more 317 | information on this function. 318 | 319 | ==== LISTAGG 320 | (((LISTAGG))) 321 | Aggregates a set of string elements into one string by concatenating the strings. Optionally, a separator string can be provided which is inserted between contiguous input strings. 322 | 323 | ==== MAX 324 | (((MAX))) 325 | Get the maximum value of a set of rows. The use of the DISTINCT option has no affect. If no rows match, the null value is returned. 326 | 327 | .MAX function examples 328 | [source,sql] 329 | .... 330 | SELECT MAX(dept) 331 | , MAX(ALL dept) 332 | , MAX(DISTINCT dept) 333 | , MAX(DISTINCT dept/10) 334 | FROM staff; 335 | .... 336 | 337 | _ANSWER_ 338 | [options="header",] 339 | |=== 340 | |1 | 2 | 3 | 4 341 | |84| 84| 84| 8 342 | |=== 343 | 344 | ===== MAX and MIN usage with Scalar Functions 345 | (((MAX))) (((MIN))) 346 | Several Db2 scalar functions convert a value from one format to another, for example from numeric to character. The function output format will not always shave the same ordering sequence as the input. This difference can affect MIN, MAX, and ORDER BY processing. 347 | 348 | .MAX function with dates 349 | [source,sql] 350 | .... 351 | SELECT MAX(hiredate) 352 | , CHAR(MAX(hiredate),USA) 353 | , MAX(CHAR(hiredate,USA)) 354 | FROM employee; 355 | .... 356 | 357 | _ANSWER_ 358 | [options="header",] 359 | |=== 360 | |1 | 2 | 3 361 | |2006-12-15| 12/15/2006| 12/15/2006 362 | |=== 363 | 364 | In the above the SQL, the second field gets the MAX before doing the conversion to character whereas the third field works the other way round. In most cases, the later is wrong. In the next example, the MAX function is used on a small integer value that has been converted to character. If the CHAR function is used for the conversion, the output 365 | is left justified, which results in an incorrect answer. The DIGITS output is correct (in this example). 366 | 367 | .MAX function with numbers, 1 of 2 368 | [source,sql] 369 | .... 370 | SELECT MAX(id) AS id 371 | , MAX(CHAR(id)) AS chr 372 | , MAX(DIGITS(id)) AS dig 373 | FROM staff; 374 | .... 375 | 376 | _ANSWER_ 377 | [options="header",] 378 | |=== 379 | |ID | CHR| DIG 380 | |350| 90 | 00350 381 | |=== 382 | 383 | The DIGITS function can also give the wrong answer - if the input data is part positive and part negative. This is because this function does not put a sign indicator in the output. 384 | 385 | .MAX function with numbers, 2 of 2 386 | [source,sql] 387 | .... 388 | SELECT MAX(id - 250) AS id 389 | , MAX(CHAR(id - 250)) AS chr 390 | , MAX(DIGITS(id - 250)) AS dig 391 | FROM staff; 392 | .... 393 | 394 | _ANSWER_ 395 | [options="header",] 396 | |=== 397 | |D | CHR| DIG 398 | |100| 90 | 0000000240 399 | |=== 400 | 401 | WARNING: Be careful when using a column function on a field that has been converted from number to character, or from date/time to character. The result may not be what you intended. 402 | 403 | ==== MEDIAN 404 | (((MEDIAN))) 405 | Returns the median value in a set of values. 406 | 407 | ==== MIN 408 | (((MIN))) 409 | Get the minimum value of a set of rows. The use of the DISTINCT option has no affect. If no rows match, the null value is returned. 410 | 411 | .MIN function examples 412 | [source,sql] 413 | .... 414 | SELECT MIN(dept) 415 | , MIN(ALL dept) 416 | , MIN(DISTINCT dept) 417 | , MIN(DISTINCT dept/10) 418 | FROM staff; 419 | .... 420 | 421 | _ANSWER_ 422 | [options="header",] 423 | |=== 424 | |1 | 2 | 3 | 4 425 | |10| 10| 10| 1 426 | |=== 427 | 428 | ==== PERCENTILE_CONT 429 | (((PERCENTILE_CONT))) 430 | Returns the value that corresponds to the specified percentile given a sort specification by using a continuous distribution model. 431 | 432 | ==== PERCENTILE_DISC 433 | (((PERCENTILE_DISC))) 434 | Returns the value that corresponds to the specified percentile given a sort specification by using a discrete distribution model. 435 | 436 | ==== PERCENT_RANK 437 | (((PERCENT_RANK))) 438 | Returns the relative percentile rank of a row that is hypothetically inserted into a group of rows. 439 | 440 | ==== Regression Functions 441 | (((Regression functions))) 442 | The various regression functions support the fitting of an 443 | ordinary-least-squares regression line of the form y = a * x + b to a set of number pairs. 444 | 445 | *REGR_AVGX* returns a quantity that than can be used to compute the validity of the regression model. The output is of type float. 446 | 447 | *REGR_AVGY* (see REGR_AVGX). 448 | 449 | *REGR_COUNT* returns the number of matching non-null pairs. The output is integer. 450 | 451 | *REGR_INTERCEPT* returns the y-intercept of the regression line. 452 | 453 | *REGR_R2* returns the coefficient of determination for the regression. 454 | 455 | *REGR_SLOPE* returns the slope of the line. 456 | 457 | *REGR_SXX* (see REGR_AVGX). 458 | 459 | *REGR_SXY* (see REGR_AVGX). 460 | 461 | *REGR_SYY* (see REGR_AVGX). 462 | 463 | *See the IBM SQL Reference for more details on the above functions.* 464 | 465 | .REGRESSION functions examples 466 | [source,sql] 467 | .... 468 | SELECT DEC(REGR_SLOPE(bonus,salary),7,5) AS r_slope 469 | , DEC(REGR_INTERCEPT(bonus,salary),7,3) AS r_icpt 470 | , INT(REGR_COUNT(bonus,salary)) AS r_count 471 | , INT(REGR_AVGX(bonus,salary)) AS r_avgx 472 | , INT(REGR_AVGY(bonus,salary)) AS r_avgy 473 | , DEC(REGR_SXX(bonus,salary),10) AS r_sxx 474 | , INT(REGR_SXY(bonus,salary)) AS r_sxy 475 | , INT(REGR_SYY(bonus,salary)) AS r_syy 476 | FROM employee 477 | WHERE workdept = 'A00'; 478 | .... 479 | 480 | _ANSWERS_ 481 | [options="header",] 482 | |=== 483 | |r_slope|r_icpt |r_count|r_avgx|r_avgy|r_sxx |r_sxy |r_syy 484 | |0.00247|644.862|5 |70850 |820 |8784575000|21715000|168000 485 | |=== 486 | 487 | 488 | ==== STDDEV 489 | (((STDDEV))) 490 | Get the standard deviation of a set of numeric values. If DISTINCT is used, duplicate values are ignored. If no rows match, the result is null. The output format is double. 491 | 492 | .STDDEV function examples 493 | [source,sql] 494 | .... 495 | SELECT AVG(dept) AS a1 496 | ,STDDEV(dept) AS s1 497 | ,DEC(STDDEV(dept),3,1) AS s2 498 | ,DEC(STDDEV(ALL dept),3,1) AS s3 499 | ,DEC(STDDEV(DISTINCT dept),3,1) AS s4 500 | FROM staff; 501 | .... 502 | 503 | _ANSWER_ 504 | [options="header",] 505 | |=== 506 | |A1| S1 |S2 | S3 | S4 507 | |41| +2.3522355E+1|23.5| 23.5| 24.1 508 | |=== 509 | 510 | ==== STDDEV_SAMP 511 | (((STDDEV_SAMP))) 512 | The STDDEV_SAMP function returns the sample standard deviation (division by [n-1]) of a set of numbers. 513 | 514 | ==== SUM 515 | (((SUM))) 516 | Get the sum of a set of numeric values. If DISTINCT is used, duplicate values are ignored. Null values are always ignored. If no rows match, the result is null. 517 | 518 | .SUM function examples 519 | [source,sql] 520 | .... 521 | SELECT SUM(dept) AS s1 522 | , SUM(ALL dept) AS s2 523 | , SUM(DISTINCT dept) AS s3 524 | , SUM(dept/10) AS s4 525 | , SUM(dept)/10 AS s5 526 | .... 527 | 528 | FROM staff; 529 | 530 | _ANSWER_ 531 | [options="header",] 532 | |=== 533 | |S1 | S2 | S3 | S4 | S5 534 | |1459| 1459| 326| 134| 145 535 | |=== 536 | 537 | WARNING: The answers S4 and S5 above are different. This is because the division is done before the SUM in column S4, and after in column S5. In the former case, precision has been lost due to rounding of the original integer value and the result is arguably incorrect. When in doubt, use the S5 notation. 538 | 539 | ==== VAR or VARIANCE 540 | (((VAR))) (((VARIANCE))) 541 | Get the variance of a set of numeric values. If DISTINCT is used, duplicate values are ignored. If no rows match, the result is null. The output format is double. 542 | 543 | .VARIANCE function examples 544 | [source,sql] 545 | .... 546 | SELECT AVG(dept) AS a1 547 | , VARIANCE(dept) AS s1 548 | , DEC(VARIANCE(dept),4,1) AS s2 549 | , DEC(VARIANCE(ALL dept),4,1) AS s3 550 | , DEC(VARIANCE(DISTINCT dept),4,1) AS s4 551 | FROM staff; 552 | .... 553 | 554 | _ANSWER_ 555 | [options="header",] 556 | |=== 557 | |A1| V1 | V2 | V3 | V4 558 | |41| +5.533012244E+2| 553| 553| 582 559 | |=== 560 | 561 | ==== VARIANCE_SAMP 562 | (((VARIANCE_SAMP))) 563 | Returns the sample variance (division by [n-1]) of a set of numbers. 564 | 565 | ==== XMLAGG 566 | (((XMLAGG))) 567 | Returns an XML sequence containing an item for each non-null value in a set of XML values. 568 | 569 | ==== XMLGROUP 570 | (((XMLGROUP))) 571 | The XMLGROUP function returns an XML value with a single XQuery document node containing one top-level element node. This is an aggregate expression that will return a single-rooted XML document from a group of rows where each row is mapped to a row subelement. 572 | 573 | -------------------------------------------------------------------------------- /chapters_asciidoc/10 Table Functions.asciidoc: -------------------------------------------------------------------------------- 1 | == Table Functions 2 | (((Table functions))) 3 | A table function is very similar to a scalar function, except that it returns a set of rows and columns, rather than a single value. Here is an example: 4 | 5 | .Simple table function 6 | [source,sql] 7 | .... 8 | CREATE FUNCTION get_staff() 9 | RETURNS TABLE ( ID SMALLINT 10 | , name VARCHAR(9) 11 | , YR SMALLINT) 12 | RETURN 13 | SELECT id 14 | , name 15 | , years 16 | FROM staff; 17 | 18 | SELECT * 19 | FROM TABLE(get_staff()) AS s 20 | WHERE id < 40 21 | ORDER BY id; 22 | .... 23 | 24 | _ANSWER_ 25 | [options="header",] 26 | |=== 27 | |ID|NAME |YR 28 | |10|Sanders |7 29 | |20|Pernal |8 30 | |30|Marenghi|5 31 | |=== 32 | 33 | Note the following: 34 | 35 | * The TABLE keyword, the function name (obviously), the two sets of parenthesis , and a correlation name, are all required. 36 | * If the function has input parameters, they are all required, and their type must match. 37 | * Optionally, one can list all of the columns that are returned by the function, giving each an assigned name. 38 | 39 | Below is an example of a function that uses all of the above features: 40 | 41 | .Table function with parameters 42 | [source,sql] 43 | .... 44 | CREATE FUNCTION get_st(inval INTEGER) 45 | RETURNS 46 | TABLE ( id SMALLINT 47 | , name VARCHAR(9) 48 | , yr SMALLINT) 49 | RETURN 50 | SELECT id 51 | , name 52 | , years 53 | FROM staff 54 | WHERE id = inval; 55 | 56 | SELECT * 57 | FROM TABLE(get_st(30)) AS sss (id, nnn, yy) 58 | .... 59 | 60 | _ANSWER_ 61 | [options="header",] 62 | |=== 63 | |ID|NNN |YY 64 | |30|Marenghi| 5 65 | |=== 66 | 67 | Examples 68 | 69 | A table function returns a table, but it doesn't have to touch a table. To illustrate, the following function creates the data on the fly: 70 | 71 | .Table function that creates data 72 | [source,sql] 73 | .... 74 | CREATE FUNCTION make_data() 75 | RETURNS 76 | TABLE ( KY SMALLINT 77 | , DAT CHAR(5)) 78 | RETURN 79 | WITH temp1 (k#) AS 80 | (VALUES (1),(2),(3)) 81 | SELECT k# 82 | , DIGITS(SMALLINT(k#)) 83 | FROM temp1; 84 | 85 | SELECT * 86 | FROM TABLE(make_data()) AS ttt; 87 | .... 88 | 89 | _ANSWER_ 90 | [options="header",] 91 | |=== 92 | |KY|DAT 93 | |1 |00001 94 | |2 |00002 95 | |3 |00003 96 | |=== 97 | 98 | The next example uses compound SQL to first flag an error if one of the input values is too low, then find the maximum salary and related ID in the matching set of rows, then fetch the same rows - returning the two previously found values at the same time: 99 | 100 | IMPORTANT: This example uses an "!" as the stmt delimiter. 101 | 102 | .Table function with compound SQL 103 | [source,sql] 104 | .... 105 | CREATE FUNCTION staff_list(lo_key INTEGER 106 | , lo_sal INTEGER) 107 | RETURNS 108 | TABLE ( id SMALLINT 109 | , salary DECIMAL(7,2) 110 | , max_sal DECIMAL(7,2) 111 | , id_max SMALLINT) 112 | LANGUAGE SQL 113 | READS SQL DATA 114 | EXTERNAL ACTION 115 | DETERMINISTIC 116 | BEGIN ATOMIC 117 | DECLARE hold_sal DECIMAL(7,2) DEFAULT 0; 118 | DECLARE hold_key SMALLINT; 119 | IF lo_sal < 0 THEN 120 | SIGNAL SQLSTATE '75001' 121 | SET MESSAGE_TEXT = 'Salary too low'; 122 | END IF; 123 | FOR get_max AS 124 | SELECT id AS in_key 125 | , salary As in_sal 126 | FROM staff 127 | WHERE id >= lo_key 128 | DO 129 | IF in_sal > hold_sal THEN 130 | SET hold_sal = in_sal; 131 | SET hold_key = in_key; 132 | END IF; 133 | END FOR; 134 | RETURN 135 | SELECT id 136 | , salary 137 | , hold_sal 138 | , hold_key 139 | FROM staff 140 | WHERE id >= lo_key; 141 | END! 142 | 143 | 144 | SELECT * 145 | FROM TABLE(staff_list(66,1)) AS ttt 146 | WHERE id < 111 147 | ORDER BY id! 148 | .... 149 | 150 | _ANSWER_ 151 | [options="header",] 152 | |=== 153 | |ID |SALARY |MAX_SAL |ID_MAX 154 | |70 |76502.83|91150.00|140 155 | |80 |43504.60|91150.00|140 156 | |90 |38001.75|91150.00|140 157 | |100|78352.80|91150.00|140 158 | |110|42508.20|91150.00|140 159 | |=== 160 | 161 | 162 | === BASE_TABLE 163 | (((BASE_TABLE))) 164 | Returns both the object name and schema name of the object found after any alias chains have been resolved. 165 | 166 | === UNNEST 167 | (((UNNEST))) 168 | Returns a result table that includes a row for each element of the specified array. If there are multiple ordinary array arguments specified, the number of rows will match the array with the largest cardinality. 169 | 170 | === XMLTABLE 171 | (((XMLTABLE))) 172 | Returns a result table from the evaluation of XQuery expressions, possibly using specified input arguments as XQuery variables. Each sequence item in the result sequence of the row XQuery expression represents a row of the result table. 173 | 174 | -------------------------------------------------------------------------------- /chapters_asciidoc/11 Useful User-Defined Functions.asciidoc: -------------------------------------------------------------------------------- 1 | == Useful User-Defined Functions 2 | 3 | In this section we will describe some simple functions that are generally useful, and that people have asked for over the years. In addition to the functions listed here, there are also the following elsewhere in this book: 4 | 5 | * Check character input is a numeric value - <> 6 | * Convert numeric data to character (right justified) - <>. 7 | * Like-column predicate evaluation - <>. 8 | * Locate string in input, a block at a time - <>. 9 | * Pause SQL statement (by looping) for "n" seconds - <>. 10 | * <>. 11 | 12 | === Julian Date Functions 13 | (((Julian date))) 14 | The function below converts a Db2 date into a Julian date (format) value: 15 | 16 | .Convert Date into Julian Date 17 | [source,sql] 18 | .... 19 | CREATE FUNCTION julian_out(inval DATE) 20 | RETURNS 21 | CHAR(7) 22 | RETURN 23 | RTRIM(CHAR(YEAR(inval))) 24 | || 25 | SUBSTR(DIGITS(DAYOFYEAR(inval)),8); 26 | 27 | SELECT empno 28 | , CHAR(hiredate, ISO) AS h_date 29 | , JULIAN_OUT(hiredate) AS j_date 30 | FROM employee 31 | WHERE empno < '000050' 32 | ORDER BY empno; 33 | .... 34 | 35 | _ANSWER_ 36 | [options="header",] 37 | |=== 38 | |EMPNO |H_DATE |J_DATE 39 | |000010|1995-01-01|1995001 40 | |000020|2003-10-10|2003283 41 | |000030|2005-04-05|2005095 42 | |=== 43 | 44 | The next function does the opposite: 45 | 46 | .Convert Julian Date into Date 47 | [source,sql] 48 | .... 49 | CREATE FUNCTION julian_in(inval CHAR(7)) 50 | RETURNS 51 | DATE 52 | RETURN 53 | DATE('0001-01-01') 54 | + (INT(SUBSTR(inval,1,4)) - 1) YEARS 55 | + (INT(SUBSTR(inval,5,3)) - 1) DAYS; 56 | .... 57 | 58 | === Get Prior Date 59 | 60 | Imagine that one wanted to get all rows where some date is for the prior year - relative to the current year. This is easy to code: 61 | 62 | .Select rows where hire-date = prior year 63 | [source,sql] 64 | .... 65 | SELECT empno 66 | , hiredate 67 | FROM employee 68 | WHERE YEAR(hiredate) = YEAR(CURRENT DATE) - 1; 69 | .... 70 | 71 | === Get Prior Month 72 | 73 | One can use the DAYS function to get the same data for the prior day. But one cannot use the MONTH function to do the equivalent for the prior month because at the first of the year the month number goes back to one. 74 | 75 | One can address this issue by writing a simple function that multiplies the year-number by 12, and then adds the month-number: 76 | 77 | .Create year-month function 78 | [source,sql] 79 | .... 80 | CREATE FUNCTION year_month(inval DATE) 81 | RETURNS 82 | INTEGER 83 | RETURN 84 | (YEAR(inval) * 12) + MONTH(inval); 85 | .... 86 | 87 | We can use this function thus: 88 | 89 | .Select rows where hire-date = prior month 90 | [source,sql] 91 | .... 92 | SELECT empno 93 | , hiredate 94 | FROM employee 95 | WHERE YEAR_MONTH(hiredate) = YEAR_MONTH(CURRENT DATE) - 1; 96 | .... 97 | 98 | === Get Prior Week 99 | 100 | Selecting rows for the prior week is complicated by the fact that both the US and ISO definitions of a week begin at one at the start of the year (see <>). If however we choose to define a week as a set of seven contiguous days, regardless of the date, we can create a function to do the job. In the example below we shall assume that a week begins on a Sunday: 101 | 102 | .Create week-number function 103 | [source,sql] 104 | .... 105 | CREATE FUNCTION sunday_week(inval DATE) 106 | RETURNS 107 | INTEGER 108 | RETURN 109 | DAYS(inval) / 7; 110 | .... 111 | 112 | The next function assumes that a week begins on a Monday: 113 | 114 | .Create week-number function 115 | [source,sql] 116 | .... 117 | CREATE FUNCTION monday_week(inval DATE) 118 | RETURNS 119 | INTEGER 120 | RETURN 121 | (DAYS(inval) - 1) / 7; 122 | .... 123 | 124 | Both the above functions convert the input date into a day-number value, then subtract (if needed) to get to the right day of the week, then divide by seven to get a week-number. The result is the number of weeks since the beginning of the current era. The next query shows the two functions in action: 125 | 126 | .Use week-number functions 127 | [source,sql] 128 | .... 129 | WITH temp1 (num,dt) AS 130 | (VALUES (1, DATE('2004-12-29')) 131 | UNION ALL 132 | SELECT num + 1 133 | , dt + 1 DAY 134 | FROM temp1 135 | WHERE num < 15 136 | ), 137 | temp2 (dt, dy) AS 138 | (SELECT dt 139 | , SUBSTR(DAYNAME(dt),1,3) 140 | FROM temp1 141 | ) 142 | SELECT CHAR(dt, ISO) AS date 143 | , dy AS day 144 | , WEEK(dt) AS wk 145 | , WEEK_ISO(dt) AS is 146 | , sunday_week(dt) AS sun_wk 147 | , monday_week(dt) AS mon_wk 148 | FROM temp2 149 | ORDER BY 1; 150 | .... 151 | 152 | _ANSWER_ 153 | [options="header",] 154 | |=== 155 | |DATE |DAY|WK|IS|SUN_WK|MON_WK 156 | |2004-12-29|Wed|53|53|104563|104563 157 | |2004-12-30|Thu|53|53|104563|104563 158 | |2004-12-31|Fri|53|53|104563|104563 159 | |2005-01-01|Sat|1 |53|104563|104563 160 | |2005-01-02|Sun|2 |53|104564|104563 161 | |2005-01-03|Mon|2 |1 |104564|104564 162 | |2005-01-04|Tue|2 |1 |104564|104564 163 | |2005-01-05|Wed|2 |1 |104564|104564 164 | |2005-01-06|Thu|2 |1 |104564|104564 165 | |2005-01-07|Fri|2 |1 |104564|104564 166 | |2005-01-08|Sat|2 |1 |104564|104564 167 | |2005-01-09|Sun|3 |1 |104565|104564 168 | |2005-01-10|Mon|3 |2 |104565|104565 169 | |2005-01-11|Tue|3 |2 |104565|104565 170 | |2005-01-12|Wed|3 |2 |104565|104565 171 | |=== 172 | 173 | [[generating.numbers]] 174 | ==== Generating Numbers 175 | (((Generating numbers))) 176 | The next function returns a table of rows. Each row consists of a single integer value , starting at zero, and going up to the number given in the input. At least one row is always returned. If the input value is greater than zero, the number of rows returned equals the input value plus one: 177 | 178 | .Create num-list function 179 | [source,sql] 180 | .... 181 | CREATE FUNCTION NumList(max_num INTEGER) 182 | RETURNS 183 | TABLE(num INTEGER) 184 | LANGUAGE SQL 185 | RETURN 186 | WITH temp1 (num) AS 187 | (VALUES (0) 188 | UNION ALL 189 | SELECT num + 1 190 | FROM temp1 191 | WHERE num < max_num 192 | ) 193 | SELECT num 194 | FROM temp1; 195 | .... 196 | 197 | Below are some queries that use the above function: 198 | 199 | [source,sql] 200 | .... 201 | SELECT * 202 | FROM TABLE(NumList(-1)) AS xxx; 203 | .... 204 | 205 | _ANSWER_ 206 | 207 | [cols="",options="header",] 208 | |=== 209 | |1 210 | |0 211 | |=== 212 | 213 | [source,sql] 214 | .... 215 | SELECT * 216 | FROM TABLE(NumList(+0)) AS xxx; 217 | .... 218 | 219 | [cols="",options="header",] 220 | |=== 221 | |1 222 | |0 223 | |=== 224 | 225 | [source,sql] 226 | .... 227 | SELECT * 228 | FROM TABLE(NumList(+3)) AS xxx; 229 | .... 230 | 231 | [cols="",options="header",] 232 | |=== 233 | |1 234 | |0 235 | |1 236 | |2 237 | |3 238 | |=== 239 | 240 | .Using num-list function 241 | [source,sql] 242 | .... 243 | SELECT * 244 | FROM TABLE(NumList(CAST(NULL AS INTEGER))) AS xxx; 245 | .... 246 | 247 | [cols="",options="header",] 248 | |=== 249 | |1 250 | |0 251 | |=== 252 | 253 | NOTE: If this function did not always return one row, we might have to use a left-outer-join when joining to it. Otherwise the calling row might disappear from the answer-set because no row was returned. 254 | 255 | To illustrate the function's usefulness, consider the following query, which returns the start and end date for a given set of activities: 256 | 257 | .Select activity start & end date 258 | [source,sql] 259 | .... 260 | SELECT actno 261 | , emstdate 262 | , emendate 263 | , DAYS(emendate) - DAYS(emstdate) AS #days 264 | FROM emp_act act 265 | WHERE empno = '000260' 266 | AND projno = 'AD3113' 267 | AND actno < 100 268 | AND emptime = 0.5 269 | ORDER BY actno; 270 | .... 271 | 272 | _ANSWER_ 273 | [options="header",] 274 | |=== 275 | |ACTNO|EMSTDATE |EMENDATE |#DAYS 276 | |70 |2002-06-15|2002-07-01|16 277 | |80 |2002-03-01|2002-04-15|45 278 | |=== 279 | 280 | Imagine that we wanted take the above output, and generate a row for each day between the start and end dates. To do this we first have to calculate the number of days between a given start and end, and then join to the function using that value: 281 | 282 | .Generate one row per date between start & end dates (1 of 2) 283 | [source,sql] 284 | .... 285 | SELECT actno 286 | , #days 287 | , num 288 | , emstdate + num DAYS AS new_date 289 | FROM 290 | (SELECT actno 291 | , emstdate 292 | , emendate 293 | , DAYS(emendate) - DAYS(emstdate) AS #days 294 | FROM emp_act act 295 | WHERE empno = '000260' 296 | AND projno = 'AD3113' 297 | AND actno < 100 298 | AND emptime = 0.5 299 | ) AS aaa 300 | , TABLE(NumList(#days)) AS ttt 301 | ORDER BY actno 302 | , num; 303 | .... 304 | 305 | _ANSWER_ 306 | [options="header",] 307 | |=== 308 | |ACTNO|#DAYS|NUM|NEW_DATE 309 | |70 |16 |0 |2002-06-15 310 | |70 |16 |1 |2002-06-16 311 | |70 |16 |2 |2002-06-17 312 | |70 |16 |3 |2002-06-18 313 | |70 |16 |4 |2002-06-19 314 | |70 |16 |5 |2002-06-20 315 | |70 |16 |6 |2002-06-21 316 | |70 |16 |7 |2002-06-22 317 | |70 |16 |8 |2002-06-23 318 | |70 |16 |9 |2002-06-24 319 | |70 |16 |10 |2002-06-25 320 | | | | |etc... 321 | |=== 322 | 323 | In the above query the #days value equals the number of days between the start and end dates. If the two dates equal, the #days value will be zero. In this case we will still get a row because the function will return a single zero value. If this were not the case (i.e. the function returned no rows if the input value was less than one), we would have to code a left-outer-join with a fake ON statement: 324 | 325 | .Generate one row per date between start & end dates (2 of 2) 326 | [source,sql] 327 | .... 328 | SELECT actno 329 | , #days 330 | , num 331 | , emstdate + num DAYS AS new_date 332 | FROM 333 | (SELECT actno 334 | , emstdate 335 | , emendate 336 | , DAYS(emendate)- DAYS(emstdate) AS #days 337 | FROM emp_act act 338 | WHERE empno = '000260' 339 | AND projno = 'AD3113' 340 | AND actno < 100 341 | AND emptime = 0.5 342 | ) AS aaa 343 | LEFT OUTER JOIN 344 | TABLE(NumList(#days)) AS ttt 345 | ON 1 = 1 346 | ORDER BY actno 347 | , num; 348 | .... 349 | 350 | [options="header",] 351 | |=== 352 | |ACTNO|#DAYS|NUM|NEW_DATE 353 | |70 |16 |0 |2002-06-15 354 | |70 |16 |1 |2002-06-16 355 | |70 |16 |2 |2002-06-17 356 | |70 |16 |3 |2002-06-18 357 | |70 |16 |4 |2002-06-19 358 | |70 |16 |5 |2002-06-20 359 | |70 |16 |6 |2002-06-21 360 | |70 |16 |7 |2002-06-22 361 | |70 |16 |8 |2002-06-23 362 | |70 |16 |9 |2002-06-24 363 | |70 |16 |10 |2002-06-25 364 | | | | |etc... 365 | |=== 366 | 367 | [[check.data.value.type]] 368 | === Check Data Value Type 369 | 370 | The following function checks to see if an input value is character, where character is defined as meaning that all bytes are "A" through "Z" or blank. It converts (if possible) all bytes to blank using the TRANSLATE function, and then checks to see if the result is blank: 371 | 372 | .Check if input value is character 373 | [source,sql] 374 | .... 375 | CREATE FUNCTION ISCHAR (inval VARCHAR(250)) 376 | RETURNS 377 | SMALLINT 378 | LANGUAGE SQL 379 | RETURN 380 | CASE 381 | WHEN TRANSLATE(UPPER(inval),' ','ABCDEFGHIJKLMNOPQRSTUVWXYZ') = ' ' THEN 1 382 | ELSE 0 383 | END; 384 | .... 385 | 386 | The next function is similar to the prior, except that it looks to see if all bytes in the input are in the range of "0" through "9", or blank: 387 | 388 | .Check if input value is numeric 389 | [source,sql] 390 | .... 391 | CREATE FUNCTION ISNUM (inval VARCHAR(250)) 392 | RETURNS 393 | SMALLINT 394 | LANGUAGE SQL 395 | RETURN 396 | CASE 397 | WHEN TRANSLATE(inval,' ','01234567890') = ' ' THEN 1 398 | ELSE 0 399 | END; 400 | .... 401 | 402 | Below is an example of the above two functions in action: 403 | 404 | .Example of functions in use 405 | [source,sql] 406 | .... 407 | WITH temp (indata) AS 408 | (VALUES ('ABC') 409 | , ('123') 410 | , ('3.4') 411 | , ('-44') 412 | , ('A1 ') 413 | , (' ') 414 | ) 415 | SELECT indata AS indata 416 | , ISCHAR(indata) AS c 417 | , ISNUM(indata) AS n 418 | FROM temp; 419 | .... 420 | 421 | _ANSWER_ 422 | [options="header",] 423 | |=== 424 | |INDATA|C|N 425 | |ABC |1|0 426 | |123 |0|1 427 | |3.4 |0|0 428 | |-44 |0|0 429 | |A1 |0|0 430 | | |1|1 431 | |=== 432 | 433 | The above ISNUM function is a little simplistic. It doesn't check for all-blanks, or embedded blanks, decimal input, or sign indicators. The next function does all of this, and also indicates what type of number was found: 434 | 435 | .Check if input value is numeric 436 | [source,sql] 437 | .... 438 | CREATE FUNCTION ISNUM2 (inval VARCHAR(255)) 439 | RETURNS 440 | CHAR(4) 441 | LANGUAGE SQL 442 | RETURN 443 | CASE 444 | WHEN inval = ' ' THEN ' ' 445 | WHEN LOCATE(' ',RTRIM(LTRIM(inval))) > 0 THEN ' ' 446 | WHEN TRANSLATE(inval,' ','01234567890') = inval THEN ' ' 447 | WHEN TRANSLATE(inval,' ','01234567890') = ' ' THEN 'INT ' 448 | WHEN TRANSLATE(inval,' ','+01234567890') = ' ' 449 | AND LOCATE('+',LTRIM(inval)) = 1 450 | AND LENGTH(REPLACE(inval,'+','')) = LENGTH(inval) - 1 THEN 'INT+' 451 | WHEN TRANSLATE(inval,' ','-01234567890') = ' ' 452 | AND LOCATE('-',LTRIM(inval)) = 1 453 | AND LENGTH(REPLACE(inval,'-','')) = LENGTH(inval) - 1 THEN 'INT-' 454 | WHEN TRANSLATE(inval,' ','.01234567890') = ' ' 455 | AND LENGTH(REPLACE(inval,'.','')) = LENGTH(inval) - 1 THEN 'DEC ' 456 | WHEN TRANSLATE(inval,' ','+.01234567890') = ' ' 457 | AND LOCATE('+',LTRIM(inval)) = 1 458 | AND LENGTH(REPLACE(inval,'+','')) = LENGTH(inval) - 1 459 | AND LENGTH(REPLACE(inval,'.','')) = LENGTH(inval) - 1 THEN 'DEC+' 460 | WHEN TRANSLATE(inval,' ','-.01234567890') = ' ' 461 | AND LOCATE('-',LTRIM(inval)) = 1 462 | AND LENGTH(REPLACE(inval,'-','')) = LENGTH(inval) - 1 463 | AND LENGTH(REPLACE(inval,'.','')) = LENGTH(inval) - 1 THEN 'DEC-' 464 | ELSE ' ' 465 | END; 466 | .... 467 | 468 | The first three WHEN checks above are looking for non-numeric input: 469 | 470 | * The input is blank. 471 | * The input has embedded blanks. 472 | * The input does not contain any digits. 473 | 474 | The final five WHEN checks look for a specific types of numeric input. They are all similar in design, so we can use the last one (looking of negative decimal input) to illustrate how they all work: 475 | 476 | * Check that the input consists only of digits, dots, the minus sign, and blanks. 477 | * Check that the minus sign is the left-most non-blank character. 478 | * Check that there is only one minus sign in the input. 479 | * Check that there is only one dot in the input. 480 | 481 | Below is an example of the above function in use: 482 | 483 | .Example of function in use 484 | [source,sql] 485 | .... 486 | WITH temp (indata) AS 487 | (VALUES ('ABC') 488 | , ('123') 489 | , ('3.4') 490 | , ('-44') 491 | , ('+11') 492 | , ('-1-') 493 | , ('12+') 494 | , ('+.1') 495 | , ('-0.') 496 | , (' ') 497 | , ('1 1') 498 | , (' . ') 499 | ) 500 | SELECT indata AS indata 501 | , ISNUM2(indata) AS type 502 | , CASE 503 | WHEN ISNUM2(indata) <> '' THEN DEC(indata,5,2) 504 | ELSE NULL 505 | END AS number 506 | FROM temp; 507 | .... 508 | 509 | _ANSWER_ 510 | [options="header",] 511 | |=== 512 | |INDATA|TYPE|NUMBER 513 | |ABC | |- 514 | |123 |INT |123.00 515 | |3.4 |DEC ||3.40 516 | |-44 |INT |-44.00 517 | |+11 |INT+|11.00 518 | |-1- | |- 519 | |12+ | |- 520 | |+.1 |DEC+|0.10 521 | |-0. |DEC |0.00 522 | | | |- 523 | |1 1 | |- 524 | |. | |- 525 | |=== 526 | 527 | === Hash Function 528 | 529 | The following hash function is a little crude, but it works. It accepts a VARCHAR string as input, then walks the string and, one byte at a time, manipulates a floating point number. At the end of the process the floating point value is translated into BIGINT. 530 | 531 | IMPORTANT: This example uses an "!" as the stmt delimiter. 532 | 533 | .Create HASH_STRING function 534 | [source,sql] 535 | .... 536 | CREATE FUNCTION HASH_STRING (instr VARCHAR(30000)) 537 | RETURNS 538 | BIGINT 539 | DETERMINISTIC 540 | CONTAINS SQL 541 | NO EXTERNAL ACTION 542 | BEGIN ATOMIC 543 | DECLARE inlen SMALLINT; 544 | DECLARE curbit SMALLINT DEFAULT 1; 545 | DECLARE outnum DOUBLE DEFAULT 0; 546 | SET inlen = LENGTH(instr); 547 | WHILE curbit <= inlen 548 | DO 549 | SET outnum = (outnum * 123) + ASCII(SUBSTR(instr,curbit)); 550 | IF outnum > 1E10 THEN 551 | SET outnum = outnum / 1.2345E6; 552 | END IF; 553 | SET curbit = curbit + 1; 554 | END WHILE; 555 | RETURN BIGINT(TRANSLATE(CHAR(outnum),'01','.E')); 556 | END! 557 | .... 558 | 559 | Below is an example of the function in use: 560 | 561 | .HASH_STRING function usage 562 | [source,sql] 563 | .... 564 | SELECT id 565 | , name 566 | , HASH_STRING(name) AS hash_val 567 | FROM staff s 568 | WHERE id < 70 569 | ORDER BY id! 570 | .... 571 | 572 | _ANSWER_ 573 | [options="header",] 574 | |=== 575 | |ID|NAME |HASH_VAL 576 | |10|Sanders |203506538768383718 577 | |20|Pernal |108434258721263716 578 | |30|Marenghi|201743899927085914 579 | |40|O'Brien |202251277018590318 580 | |50|Hanes |103496977706763914 581 | |60|Quigley |202990889019520318 582 | |=== 583 | 584 | One way to judge a hash function is to look at the number of distinct values generated for a given number of input strings. Below is a very simple test: 585 | 586 | .HASH_FUNCTION test 587 | [source,sql] 588 | .... 589 | WITH 590 | temp1 (col1) AS 591 | (VALUES (1) 592 | UNION ALL 593 | SELECT col1 + 1 594 | FROM temp1 595 | WHERE col1 < 100000 596 | ) 597 | SELECT COUNT(*) AS #rows 598 | , COUNT(DISTINCT HASH_STRING(CHAR(col1))) AS #hash1 599 | , COUNT(DISTINCT HASH_STRING(DIGITS(col1))) AS #hash2 600 | FROM temp1! 601 | .... 602 | 603 | ANSWER 604 | [options="header",] 605 | |=== 606 | |#ROWS |#HASH1|#HASH2 607 | |100000|100000|100000 608 | |=== 609 | 610 | 611 | -------------------------------------------------------------------------------- /chapters_asciidoc/15 Union Intersect Except.asciidoc: -------------------------------------------------------------------------------- 1 | [[union.chapter]] 2 | == Union, Intersect, and Except 3 | 4 | A UNION, EXCEPT, or INTERCEPT expression combines sets of columns into new sets of columns. An illustration of what each operation does with a given set of data is shown below: 5 | 6 | .Examples of Union, Except, and Intersect 7 | .... 8 | R1 R1 R1 R1 R1 R1 R1 9 | UNION UNION INTERSECT INTERSECT EXCEPT EXCEPT MINUS 10 | R2 ALL R2 ALL R2 ALL R2 11 | R1 R2 R2 R2 R2 12 | -- -- ----- ----- --------- ----- ------ ------ ----- 13 | A A A A A A E A E 14 | A A B A B A C 15 | A B C A C B C 16 | B B D A B E 17 | B B E A C 18 | C C B 19 | C D B 20 | C B 21 | E B 22 | B 23 | C 24 | C 25 | C 26 | C 27 | D 28 | E 29 | .... 30 | 31 | WARNING: Unlike the UNION and INTERSECT operations, the EXCEPT statement is not commutative. This means that "A EXCEPT B" is not the same as "B EXCEPT A". 32 | 33 | _Sample Views_ 34 | 35 | .Query sample views 36 | [source,sql] 37 | .... 38 | CREATE VIEW R1 (R1) 39 | AS VALUES ('A'), ('A'), ('A'), ('B'), ('B'), ('C'), ('C'), ('C'), ('E'); 40 | 41 | CREATE VIEW R2 (R2) 42 | AS VALUES ('A'), ('A'), ('B'), ('B'), ('B'), ('C'), ('D'); 43 | 44 | 45 | SELECT R1 46 | FROM R1 47 | ORDER BY R1; 48 | 49 | SELECT R2 50 | FROM R2 51 | ORDER BY R2; 52 | .... 53 | 54 | _ANSWER_ 55 | [options="header",] 56 | |=== 57 | |R1|R2 58 | |A |A 59 | |A |A 60 | |A |B 61 | |B |B 62 | |B |B 63 | |C |C 64 | |C |D 65 | |C | 66 | |E | 67 | |=== 68 | 69 | *Usage Notes* 70 | 71 | [[union--union-all]] 72 | === Union & Union All 73 | 74 | A UNION operation combines two sets of columns and removes duplicates. The UNION ALL expression does the same but does not remove the duplicates. 75 | -Union and Union All SQL 76 | [source,sql] 77 | .... 78 | SELECT R1 79 | FROM R1 80 | UNION 81 | SELECT R2 82 | FROM R2 83 | ORDER BY 1; 84 | 85 | SELECT R1 86 | FROM R1 87 | UNION ALL 88 | SELECT R2 89 | FROM R2 90 | ORDER BY 1; 91 | .... 92 | 93 | [options="header",] 94 | |=== 95 | |R1|R2|UNION|UNION ALL 96 | |A |A |A |A 97 | |A |A |B |A 98 | |A |B |C |A 99 | |B |B |D |A 100 | |B |B |E |A 101 | |C |C | |B 102 | |C |D | |B 103 | |C | | |B 104 | |E | | |B 105 | | | | |B 106 | | | | |C 107 | | | | |C 108 | | | | |C 109 | | | | |C 110 | | | | |D 111 | | | | |E 112 | |=== 113 | 114 | NOTE: Recursive SQL requires that there be a UNION ALL phrase between the two main parts of the statement. The UNION ALL, unlike the UNION, allows for duplicate output rows which is what often comes out of recursive processing. 115 | 116 | ===Intersect & Intersect All 117 | 118 | An INTERSECT operation retrieves the matching set of distinct values (not rows) from two columns. The INTERSECT ALL returns the set of matching individual rows. 119 | 120 | .Intersect and Intersect All SQL 121 | [source,sql] 122 | .... 123 | SELECT R1 124 | FROM R1 125 | INTERSECT 126 | SELECT R2 127 | FROM R2 128 | ORDER BY 1; 129 | 130 | SELECT R1 131 | FROM R1 132 | INTERSECT ALL 133 | SELECT R2 134 | FROM R2 135 | ORDER BY 1; 136 | .... 137 | 138 | [options="header",] 139 | |=== 140 | |R1|R2|INTERSECT|INTERSECT ALL 141 | |A |A |A |A 142 | |A |A |B |A 143 | |A |B |C |B 144 | |B |B | |B 145 | |B |B | |C 146 | |C |C | | 147 | |C |D | | 148 | |C | | | 149 | |E | | | 150 | |=== 151 | 152 | An INTERSECT and/or EXCEPT operation is done by matching ALL of the columns in the top and bottom result-sets. In other words, these are row, not column, operations. It is not possible to only match on the keys, yet at the same time, also fetch non-key columns. To do this, one needs to use a sub-query. 153 | 154 | [[except-except-all--minus]] 155 | === Except, Except All & Minus 156 | 157 | An EXCEPT operation retrieves the set of distinct data values (not rows) that exist in the first table but not in the second. The EXCEPT ALL returns the set of individual rows that exist only in the first table. The word MINUS is a synonym for EXCEPT. 158 | 159 | .Except and Except All SQL (R1 on top) 160 | [source,sql] 161 | .... 162 | SELECT R1 163 | FROM R1 164 | EXCEPT 165 | SELECT R2 166 | FROM R2 167 | ORDER BY 1; 168 | 169 | SELECT R1 170 | FROM R1 171 | EXCEPT ALL 172 | SELECT R2 173 | FROM R2 174 | ORDER BY 1; 175 | .... 176 | 177 | [options="header",] 178 | |=== 179 | |R1|R2|R1 EXCEPT R2|R1 EXCEPT ALL R2 180 | |A |A |E |A 181 | |A |A | |C 182 | |A |B | |C 183 | |B |B | |E 184 | |B |B | | 185 | |C |C | | 186 | |C |D | | 187 | |C | | | 188 | |E | | | 189 | |=== 190 | 191 | Because the EXCEPT/MINUS operation is not commutative, using it in the reverse direction (i.e. R2 to R1 instead of R1 to R2) will give a different result: 192 | 193 | .Except and Except All SQL (R2 on top) 194 | [source,sql] 195 | .... 196 | SELECT R2 197 | FROM R2 198 | EXCEPT 199 | SELECT R1 200 | FROM R1 201 | ORDER BY 1; 202 | 203 | SELECT R2 204 | FROM R2 205 | EXCEPT ALL 206 | SELECT R1 207 | FROM R1 208 | ORDER BY 1; 209 | .... 210 | 211 | [options="header",] 212 | |=== 213 | |R1|R2|R2 EXCEPT R1|R2 EXCEPT ALL R1 214 | |A |A |D |B 215 | |A |A | |D 216 | |A |B | | 217 | |B |B | | 218 | |B |B | | 219 | |C |C | | 220 | |C |D | | 221 | |C | | | 222 | |E | | | 223 | |=== 224 | 225 | NOTE: Only the EXCEPT/MINUS operation is not commutative. Both the UNION and the INTERSECT operations work the same regardless of which table is on top or on bottom. 226 | 227 | ==== Precedence Rules 228 | 229 | When multiple operations are done in the same SQL statement, there are precedence rules: 230 | 231 | * Operations in parenthesis are done first. 232 | * INTERSECT operations are done before either UNION or EXCEPT. 233 | * Operations of equal worth are done from top to bottom. 234 | 235 | The next example illustrates how parenthesis can be used change the processing order: 236 | 237 | [source,sql] 238 | .... 239 | SELECT R1 240 | FROM R1 241 | UNION 242 | SELECT R2 243 | FROM R2 244 | EXCEPT 245 | SELECT R2 246 | FROM R2 247 | ORDER BY 1; 248 | .... 249 | 250 | _ANSWER_ 251 | 252 | [options="header",] 253 | |=== 254 | |E 255 | |=== 256 | 257 | .Use of parenthesis in Union 258 | [source,sql] 259 | .... 260 | (SELECT R1 261 | FROM R1 262 | UNION 263 | SELECT R2 264 | FROM R2 265 | ) 266 | EXCEPT 267 | SELECT R2 268 | FROM R2 269 | ORDER BY 1; 270 | .... 271 | 272 | _ANSWER_ 273 | 274 | [options="header",] 275 | |=== 276 | |E 277 | |=== 278 | 279 | .Use of parenthesis in Union 280 | [source,sql] 281 | .... 282 | SELECT R1 283 | FROM R1 284 | UNION 285 | (SELECT R2 286 | FROM R2 287 | EXCEPT 288 | SELECT R2 289 | FROM R2 290 | ) 291 | ORDER BY 1; 292 | .... 293 | 294 | _ANSWER_ 295 | 296 | [options="header",] 297 | |=== 298 | |A 299 | |B 300 | |C 301 | |E 302 | |=== 303 | 304 | ==== Unions and Views 305 | 306 | Imagine that one has a series of tables that track sales data, with one table for each year. One can define a view that is the UNION ALL of these tables, so that a user would see them as a single object. Such a view can support inserts, updates, and deletes, as long as each table in the view has a constraint that distinguishes it from all the others. Below is an example: 307 | 308 | .Define view to combine yearly tables 309 | [source,sql] 310 | .... 311 | CREATE TABLE sales_data_2002 312 | ( sales_date DATE NOT NULL 313 | , daily_seq# INTEGER NOT NULL 314 | , cust_id INTEGER NOT NULL 315 | , amount DEC(10, 2) NOT NULL 316 | , invoice# INTEGER NOT NULL 317 | , sales_rep CHAR(10) NOT NULL 318 | , CONSTRAINT C CHECK (YEAR(sales_date) = 2002) 319 | , PRIMARY KEY (sales_date, daily_seq#) 320 | ); 321 | 322 | CREATE TABLE sales_data_2003 323 | ( sales_date DATE NOT NULL 324 | , daily_seq# INTEGER NOT NULL 325 | , cust_id INTEGER NOT NULL 326 | , amount DEC(10,2) NOT NULL 327 | , invoice# INTEGER NOT NULL 328 | , sales_rep CHAR(10) NOT NULL 329 | , CONSTRAINT C CHECK (YEAR(sales_date) = 2003) 330 | , PRIMARY KEY (sales_date, daily_seq#)); 331 | 332 | CREATE VIEW sales_data AS 333 | SELECT * 334 | FROM sales_data_2002 335 | UNION ALL 336 | SELECT * 337 | FROM sales_data_2003; 338 | .... 339 | 340 | Below is some SQL that changes the contents of the above view: 341 | 342 | .Insert, update, and delete using view 343 | [source,sql] 344 | .... 345 | INSERT INTO sales_data VALUES 346 | ('2002-11-22',1,123,100.10,996,'SUE') 347 | , ('2002-11-22',2,123,100.10,997,'JOHN') 348 | , ('2003-01-01',1,123,100.10,998,'FRED') 349 | , ('2003-01-01',2,123,100.10,999,'FRED'); 350 | 351 | UPDATE sales_data 352 | SET amount = amount / 2 353 | WHERE sales_rep = 'JOHN'; 354 | 355 | DELETE 356 | FROM sales_data 357 | WHERE sales_date = '2003-01-01' 358 | AND daily_seq# = 2; 359 | .... 360 | 361 | Below is the view contents, after the above is run: 362 | .View contents after insert, update, delete 363 | [options="header",] 364 | |=== 365 | |SALES_DATE|DAILY_SEQ#|CUST_ID|AMOUNT|INVOICE#|SALES_REP 366 | |01/01/2003|1 |123 |100.10|998 |FRED 367 | |11/22/2002|1 |123 |100.10|996 |SUE 368 | |11/22/2002|2 |123 |50.05 |997 |JOHN 369 | |=== 370 | 371 | 372 | -------------------------------------------------------------------------------- /chapters_asciidoc/18 Temporary Tables.asciidoc: -------------------------------------------------------------------------------- 1 | == Temporary Tables 2 | 3 | === Introduction 4 | 5 | How one defines a temporary table depends in part upon how often, and for how long, one intends to use it: 6 | 7 | * Within a query, single use. 8 | * Within a query, multiple uses. 9 | * For multiple queries in one unit of work. 10 | * For multiple queries, over multiple units of work, in one thread. 11 | 12 | === Single Use in Single Statement 13 | 14 | If one intends to use a temporary table just once, it can be defined as a nested table expression. In the following example, we use a temporary table to sequence the matching rows in the STAFF table by descending salary. We then select the 2nd through 3rd rows: 15 | 16 | .Nested Table Expression 17 | [source,sql] 18 | .... 19 | SELECT id 20 | , salary 21 | FROM (SELECT s.* 22 | , ROW_NUMBER() OVER(ORDER BY salary DESC) AS sorder 23 | FROM staff s 24 | WHERE id < 200 25 | ) AS xxx 26 | WHERE sorder BETWEEN 2 AND 3 27 | ORDER BY id; 28 | .... 29 | 30 | _ANSWER_ 31 | [options="header",] 32 | |=== 33 | |ID |SALARY 34 | |50 |20659.80 35 | |140|21150.00 36 | |=== 37 | 38 | NOTE: A fullselect in parenthesis followed by a correlation name (see above) is also called a nested table expression. 39 | 40 | Here is another way to express the same: 41 | 42 | .Common Table Expression 43 | [source,sql] 44 | .... 45 | WITH xxx (id, salary, sorder) AS 46 | (SELECT ID 47 | , salary 48 | , ROW_NUMBER() OVER(ORDER BY salary DESC) AS sorder 49 | FROM staff 50 | WHERE id < 200 51 | ) 52 | SELECT id 53 | , salary 54 | FROM xxx 55 | WHERE sorder BETWEEN 2 AND 3 56 | ORDER BY id; 57 | .... 58 | 59 | _ANSWER_ 60 | [options="header",] 61 | |=== 62 | |ID |SALARY 63 | |50 |20659.80 64 | |140|21150.00 65 | |=== 66 | 67 | === Multiple Use in Single Statement 68 | 69 | Imagine that one wanted to get the percentage contribution of the salary in some set of rows in the STAFF table - compared to the total salary for the same. The only way to do this is to access the matching rows twice; Once to get the total salary (i.e. just one row), and then again to join the total salary value to each individual salary - to work out the percentage. 70 | 71 | Selecting the same set of rows twice in a single query is generally unwise because repeating the predicates increases the likelihood of typos being made. In the next example, the desired rows are first placed in a temporary table. Then the sum salary is calculated and placed in another temporary table. Finally, the two temporary tables are joined to get the percentage: 72 | 73 | .Common Table Expression 74 | [source,sql] 75 | .... 76 | WITH rows_wanted AS 77 | (SELECT * 78 | FROM staff 79 | WHERE id < 100 80 | AND UCASE(name) LIKE '%T%') 81 | , sum_salary AS 82 | (SELECT SUM(salary) AS sum_sal 83 | FROM rows_wanted) 84 | SELECT id 85 | , name 86 | , salary 87 | , sum_sal 88 | , INT((salary * 100) / sum_sal) AS pct 89 | FROM rows_wanted 90 | , sum_salary 91 | ORDER BY id; 92 | .... 93 | 94 | _ANSWER_ 95 | [options="header",] 96 | |=== 97 | |ID|NAME |SALARY |SUM_SAL |PCT 98 | |70|Rothman|16502.83|34504.58|47 99 | |90|Koonitz|18001.75|34504.58|52 100 | |=== 101 | 102 | ==== Multiple Use in Multiple Statements 103 | 104 | To refer to a temporary table in multiple SQL statements in the same thread, one has to define a declared global temporary table. An example follows: 105 | 106 | .Declared Global Temporary Table 107 | [source,sql] 108 | .... 109 | DECLARE GLOBAL TEMPORARY TABLE session.fred 110 | ( dept SMALLINT NOT NULL 111 | , avg_salary DEC(7, 2)NOT NULL 112 | , num_emps SMALLINT NOT NULL) 113 | ON COMMIT PRESERVE ROWS; 114 | 115 | COMMIT; 116 | 117 | INSERT INTO session.fred 118 | SELECT dept 119 | , AVG(salary) 120 | , COUNT(*) 121 | FROM staff 122 | WHERE id > 200 123 | GROUP BY dept; 124 | 125 | COMMIT; 126 | 127 | SELECT COUNT(*) AS cnt 128 | FROM session.fred; 129 | 130 | DELETE FROM session.fred 131 | WHERE dept > 80; 132 | 133 | SELECT * 134 | FROM session.fred; 135 | .... 136 | 137 | _ANSWER#1_ 138 | 139 | [cols="",options="header",] 140 | |=== 141 | |CNT 142 | |4 143 | |=== 144 | 145 | _ANSWER#2_ 146 | [options="header",] 147 | |=== 148 | |DEPT|AVG_SALARY|NUM_EMPS 149 | |10 |20168.08 |3 150 | |51 |15161.43 |3 151 | |66 |17215.24 |5 152 | |=== 153 | 154 | Unlike an ordinary table, a declared global temporary table is not defined in the Db2 catalogue. Nor is it sharable by other users. It only exists for the duration of the thread (or less) and can only be seen by the person who created it. For more information, see <>. 155 | 156 | ==== Temporary Tables - in Statement 157 | 158 | Three general syntaxes are used to define temporary tables in a query: 159 | 160 | * Use a WITH phrase at the top of the query to define a common table expression. 161 | * Define a fullselect in the FROM part of the query. 162 | * Define a fullselect in the SELECT part of the query. 163 | 164 | The following three queries, which are logically equivalent, illustrate the above syntax styles. Observe that the first two queries are explicitly defined as left outer joins, while the last one is implicitly a left outer join: 165 | 166 | .Identical query (1 of 3) - using Common Table Expression 167 | [source,sql] 168 | .... 169 | WITH staff_dept AS 170 | (SELECT dept AS dept# 171 | , MAX(salary) AS max_sal 172 | FROM staff 173 | WHERE dept < 50 174 | GROUP BY dept 175 | ) 176 | SELECT id 177 | , dept 178 | , salary 179 | , max_sal 180 | FROM staff 181 | LEFT OUTER JOIN staff_dept 182 | ON dept = dept# 183 | WHERE name LIKE 'S%' 184 | ORDER BY id; 185 | .... 186 | 187 | _ANSWER_ 188 | [options="header",] 189 | |=== 190 | |ID |DEPT|SALARY |MAX_SAL 191 | |10 |20 |18357.50|18357.50 192 | |190|20 |14252.75|18357.50 193 | |200|42 |11508.60|18352.80 194 | |220|51 |17654.50| 195 | |=== 196 | 197 | .Identical query (2 of 3) - using fullselect in FROM 198 | [source,sql] 199 | .... 200 | SELECT id 201 | , dept 202 | , salary 203 | , max_sal 204 | FROM staff 205 | LEFT OUTER JOIN 206 | (SELECT dept AS dept# 207 | , MAX(salary) AS max_sal 208 | FROM staff 209 | WHERE dept < 50 210 | GROUP BY dept) AS STAFF_dept 211 | ON dept = dept# 212 | WHERE name LIKE 'S%' 213 | ORDER BY id; 214 | .... 215 | 216 | _ANSWER_ 217 | [options="header",] 218 | |=== 219 | |ID |DEPT|SALARY |MAX_SAL 220 | |10 |20 |18357.50|18357.50 221 | |190|20 |14252.75|18357.50 222 | |200|42 |11508.60|18352.80 223 | |220|51 |17654.50| 224 | |=== 225 | 226 | .Identical query (3 of 3) - using fullselect in SELECT 227 | [source,sql] 228 | .... 229 | SELECT id 230 | , dept 231 | , salary 232 | , (SELECT MAX(salary) 233 | FROM staff s2 234 | WHERE s1.dept = s2.dept 235 | AND s2.dept < 50 236 | GROUP BY dept) AS max_sal 237 | FROM staff s1 238 | WHERE name LIKE 'S%' 239 | ORDER BY id; 240 | .... 241 | 242 | _ANSWER_ 243 | [options="header",] 244 | |=== 245 | |ID |DEPT|SALARY |MAX_SAL 246 | |10 |20 |18357.50|18357.50 247 | |190|20 |14252.75|18357.50 248 | |200|42 |11508.60|18352.80 249 | |220|51 |17654.50| 250 | |=== 251 | 252 | [[common.table.expression]] 253 | === Common Table Expression 254 | 255 | A common table expression is a named temporary table that is retained for the duration of a SQL statement. There can be many temporary tables in a single SQL statement. Each must have a unique name and be defined only once. All references to a temporary table (in a given SQL statement run) return the same result. This is unlike tables, views, or aliases, which are derived each time they are called. Also unlike tables, views, or aliases, temporary tables never contain indexes. 256 | Certain rules apply to common table expressions: 257 | 258 | * Column names must be specified if the expression is recursive, or if the query invoked returns duplicate column names. 259 | * The number of column names (if any) that are specified must match the number of columns returned. 260 | * If there is more than one common-table-expression, latter ones (only) can refer to the output from prior ones. Cyclic references are not allowed. 261 | * A common table expression with the same name as a real table (or view) will replace the real table for the purposes of the query. The temporary and real tables cannot be referred to in the same query. 262 | * Temporary table names must follow standard Db2 table naming standards. 263 | * Each temporary table name must be unique within a query. 264 | * Temporary tables cannot be used in sub-queries. 265 | 266 | ==== Select Examples 267 | 268 | In this first query, we don't have to list the field names (at the top) because every field already has a name (given in the SELECT): 269 | 270 | .Common Table Expression, using named fields 271 | [source,sql] 272 | .... 273 | WITH temp1 AS 274 | (SELECT MAX(name) AS max_name 275 | , MAX(dept) AS max_dept 276 | FROM staff) 277 | SELECT * 278 | FROM temp1; 279 | .... 280 | 281 | _ANSWER_ 282 | [options="header",] 283 | |=== 284 | |MAX_NAME |MAX_DEPT 285 | |Yamaguchi|84 286 | |=== 287 | 288 | In this next example, the fields being selected are unnamed, so names have to be specified in the WITH statement: 289 | 290 | .Common Table Expression, using unnamed fields 291 | [source,sql] 292 | .... 293 | WITH temp1 (max_name, max_dept) AS 294 | (SELECT MAX(name) 295 | , MAX(dept) 296 | FROM staff) 297 | SELECT * 298 | FROM temp1; 299 | .... 300 | 301 | _ANSWER_ 302 | [options="header",] 303 | |=== 304 | |MAX_NAME |MAX_DEPT 305 | |Yamaguchi|84 306 | |=== 307 | 308 | A single query can have multiple common-table-expressions. In this next example we use two expressions to get the department with the highest average salary: 309 | 310 | .Query with two common table expressions 311 | [source,sql] 312 | .... 313 | WITH temp1 AS 314 | (SELECT dept 315 | , AVG(salary) AS avg_sal 316 | FROM staff 317 | GROUP BY dept) 318 | , temp2 AS 319 | (SELECT MAX(avg_sal) AS max_avg 320 | FROM temp1) 321 | SELECT * 322 | FROM temp2; 323 | .... 324 | 325 | _ANSWER_ 326 | 327 | [cols="",options="header",] 328 | |=== 329 | |MAX_AVG 330 | |20865.8625 331 | |=== 332 | 333 | FYI, the exact same query can be written using nested table expressions thus: 334 | 335 | .Same as prior example, but using nested table expressions 336 | [source,sql] 337 | .... 338 | SELECT * 339 | FROM 340 | (SELECT MAX(avg_sal) AS max_avg 341 | FROM (SELECT dept 342 | , AVG(salary) AS avg_sal 343 | FROM staff 344 | GROUP BY dept 345 | ) AS temp1 346 | ) AS temp2; 347 | .... 348 | 349 | _ANSWER_ 350 | 351 | [cols="",options="header",] 352 | |=== 353 | |MAX_AVG 354 | |20865.8625 355 | |=== 356 | 357 | The next query first builds a temporary table, then derives a second temporary table from the first, and then joins the two temporary tables together. The two tables refer to the same set of rows, and so use the same predicates. But because the second table was derived from the first, these predicates only had to be written once. This greatly simplified the code: 358 | 359 | .Deriving second temporary table from first 360 | [source,sql] 361 | .... 362 | WITH temp1 AS 363 | (SELECT id 364 | , name 365 | , dept 366 | , salary 367 | FROM staff 368 | WHERE id < 300 369 | AND dept <> 55 370 | AND name LIKE 'S%' 371 | AND dept NOT IN 372 | (SELECT deptnumb 373 | FROM org 374 | WHERE division = 'SOUTHERN' 375 | OR location = 'HARTFORD' 376 | ) 377 | ) 378 | , temp2 AS 379 | (SELECT dept 380 | , MAX(salary) AS max_sal 381 | FROM temp1 382 | GROUP BY dept) 383 | SELECT t1.id 384 | , t1.dept 385 | , t1.salary 386 | , t2.max_sal 387 | FROM temp1 t1 388 | , temp2 t2 389 | WHERE t1.dept = t2.dept 390 | ORDER BY t1.id; 391 | .... 392 | 393 | _ANSWER_ 394 | [options="header",] 395 | |=== 396 | |ID |DEPT|SALARY |MAX_SAL 397 | |10 |20 |18357.50|18357.50 398 | |190|20 |14252.75|18357.50 399 | |200|42 |11508.60|11508.60 400 | |220|51 |17654.50|17654.50 401 | |=== 402 | 403 | === Insert Usage 404 | 405 | A common table expression can be used to an insert-select-from statement to build all or part of the set of rows that are inserted: 406 | 407 | .Insert using common table expression 408 | [source,sql] 409 | .... 410 | INSERT INTO staff 411 | WITH temp1 (max1) AS 412 | (SELECT MAX(id) + 1 413 | FROM staff) 414 | SELECT max1, 'A', 1, 'B', 2, 3, 4 415 | FROM temp1; 416 | .... 417 | 418 | As it happens, the above query can be written equally well in the raw: 419 | 420 | .Equivalent insert (to above) without common table expression 421 | [source,sql] 422 | .... 423 | INSERT INTO staff 424 | SELECT MAX(id) + 1, 'A', 1, 'B', 2, 3, 4 425 | FROM staff; 426 | .... 427 | 428 | === Full-Select 429 | 430 | A fullselect is an alternative way to define a temporary table. Instead of using a WITH clause at the top of the statement, the temporary table definition is embedded in the body of the SQL statement. Certain rules apply: 431 | 432 | * When used in a select statement, a fullselect can either be generated in the FROM part of the query - where it will return a temporary table, or in the SELECT part of the query where it will return a column of data. 433 | * When the result of a fullselect is a temporary table (i.e. in FROM part of a query), the table must be provided with a correlation name. 434 | * When the result of a fullselect is a column of data (i.e. in SELECT part of query), each reference to the temporary table must only return a single value. 435 | 436 | === Full-Select in FROM Phrase 437 | 438 | The following query uses a nested table expression to get the average of an average - in this case the average departmental salary (an average in itself) per division: 439 | 440 | .Nested column function usage 441 | [source,sql] 442 | .... 443 | SELECT division 444 | , DEC(AVG(dept_avg),7,2) AS div_dept 445 | , COUNT(*) AS #dpts 446 | , SUM(#emps) AS #emps 447 | FROM 448 | (SELECT division 449 | , dept 450 | , AVG(salary) AS dept_avg 451 | , COUNT(*) AS #emps 452 | FROM staff 453 | , org 454 | WHERE dept = deptnumb 455 | GROUP BY division 456 | , dept) AS xxx 457 | GROUP BY division; 458 | .... 459 | 460 | _ANSWER_ 461 | [options="header",] 462 | |=== 463 | |DIVISION |DIV_DEPT|#DPTS|#EMPS 464 | |Corporate|20865.86|1 |4 465 | |Eastern |15670.32|3 |13 466 | |Midwest |15905.21|2 |9 467 | |Western |16875.99|2 |9 468 | |=== 469 | 470 | The next query illustrates how multiple fullselects can be nested inside each other: 471 | 472 | .Nested fullselects 473 | [source,sql] 474 | .... 475 | SELECT id 476 | FROM (SELECT * 477 | FROM (SELECT id, years, salary 478 | FROM (SELECT * 479 | FROM (SELECT * 480 | FROM staff 481 | WHERE dept < 77) AS t1 482 | WHERE id < 300) AS t2 483 | WHERE job LIKE 'C%') AS t3 484 | WHERE salary < 18000) AS t4 485 | WHERE years < 5; 486 | .... 487 | 488 | _ANSWER_ 489 | 490 | [cols="",options="header",] 491 | |=== 492 | |ID 493 | |170 494 | |180 495 | |230 496 | |=== 497 | 498 | A very common usage of a fullselect is to join a derived table to a real table. In the following example, the average salary for each department is joined to the individual staff row: 499 | 500 | .Join fullselect to real table 501 | [source,sql] 502 | .... 503 | SELECT a.id 504 | , a.dept 505 | , a.salary 506 | , DEC(b.avgsal,7,2) AS avg_dept 507 | FROM staff a 508 | LEFT OUTER JOIN (SELECT dept AS dept 509 | , AVG(salary) AS avgsal 510 | FROM staff 511 | GROUP BY dept 512 | HAVING AVG(salary) > 16000) AS b 513 | ON a.dept = b.dept 514 | WHERE a.id < 40 515 | ORDER BY a.id; 516 | .... 517 | 518 | _ANSWER_ 519 | [options="header",] 520 | |=== 521 | |ID|DEPT|SALARY |AVG_DEPT 522 | |10|20 |18357.50|16071.52 523 | |20|20 |78171.25|16071.52 524 | |30|38 |77506.75| 525 | |=== 526 | 527 | [[table.function.usage]] 528 | === Table Function Usage 529 | 530 | If the fullselect query has a reference to a row in a table that is outside of the fullselect, then it needs to be written as a TABLE function call. In the next example, the preceding "A" table is referenced in the fullselect, and so the TABLE function call is required: 531 | 532 | .Fullselect with external table reference 533 | [source,sql] 534 | .... 535 | SELECT a.id 536 | , a.dept 537 | , a.salary 538 | , b.deptsal 539 | FROM staff a 540 | , TABLE (SELECT b.dept 541 | , SUM(b.salary) AS deptsal 542 | FROM staff b 543 | WHERE b.dept = a.dept 544 | GROUP BY b.dept) AS b 545 | WHERE a.id < 40 546 | ORDER BY a.id; 547 | .... 548 | 549 | _ANSWER_ 550 | [options="header",] 551 | |=== 552 | |ID|DEPT|SALARY |DEPTSAL 553 | |10|20 |18357.50|64286.10 554 | |20|20 |78171.25|64286.10 555 | |30|38 |77506.75|77285.55 556 | |=== 557 | 558 | Below is the same query written without the reference to the "A" table in the fullselect, and thus without a TABLE function call: 559 | 560 | .Fullselect without external table reference 561 | [source,sql] 562 | .... 563 | SELECT a.id 564 | , a.dept 565 | , a.salary 566 | , b.deptsal 567 | FROM staff a 568 | , (SELECT b.dept 569 | , SUM(b.salary) AS deptsal 570 | FROM staff b 571 | GROUP BY b.dept) AS b 572 | WHERE a.id < 40 573 | AND b.dept = a.dept 574 | ORDER BY a.id; 575 | .... 576 | 577 | _ANSWER_ 578 | [options="header",] 579 | |=== 580 | |ID|DEPT|SALARY |DEPTSAL 581 | |10|20 |18357.50|64286.10 582 | |20|20 |78171.25|64286.10 583 | |30|38 |77506.75|77285.55 584 | |=== 585 | 586 | Any externally referenced table in a fullselect must be defined in the query syntax (starting at the first FROM statement) before the fullselect. Thus, in the first example above, if the "A" table had been listed after the "B" table, then the query would have been invalid. 587 | 588 | === Full-Select in SELECT Phrase 589 | 590 | A fullselect that returns a single column and row can be used in the SELECT part of a query: 591 | 592 | .Use an uncorrelated Full-Select in a SELECT list 593 | [source,sql] 594 | .... 595 | SELECT id 596 | , salary 597 | , (SELECT MAX(salary) 598 | FROM staff) AS maxsal 599 | FROM staff a 600 | WHERE id < 60 601 | ORDER BY id; 602 | .... 603 | 604 | _ANSWER_ 605 | [options="header",] 606 | |=== 607 | |ID|SALARY |MAXSAL 608 | |10|18357.50|22959.20 609 | |20|78171.25|22959.20 610 | |30|77506.75|22959.20 611 | |40|18006.00|22959.20 612 | |50|20659.80|22959.20 613 | |=== 614 | 615 | A fullselect in the SELECT part of a statement must return only a single row, but it need not always be the same row. In the following example, the ID and SALARY of each employee is obtained - along with the max SALARY for the employee's department. 616 | 617 | .Use a correlated Full-Select in a SELECT list 618 | [source,sql] 619 | .... 620 | SELECT id 621 | , salary 622 | , (SELECT MAX(salary) 623 | FROM staff b 624 | WHERE a.dept = b.dept) AS maxsal 625 | FROM staff a 626 | WHERE id < 60 627 | ORDER BY id; 628 | .... 629 | 630 | _ANSWER_ 631 | [options="header",] 632 | |=== 633 | |ID|SALARY |MAXSAL 634 | |10|18357.50|18357.50 635 | |20|78171.25|18357.50 636 | |30|77506.75|18006.00 637 | |40|18006.00|18006.00 638 | |50|20659.80|20659.80 639 | |=== 640 | 641 | .Use correlated and uncorrelated Full-Selects in a SELECT list 642 | [source,sql] 643 | .... 644 | SELECT id 645 | , dept 646 | , salary 647 | , (SELECT MAX(salary) 648 | FROM staff b 649 | WHERE b.dept = a.dept) 650 | , (SELECT MAX(salary) 651 | FROM staff) 652 | FROM staff a 653 | WHERE id < 60 654 | ORDER BY id; 655 | .... 656 | 657 | _ANSWER_ 658 | [options="header",] 659 | |=== 660 | |ID|DEPT|SALARY |4 |5 661 | |10|20 |18357.50|18357.50|22959.20 662 | |20|20 |78171.25|18357.50|22959.20 663 | |30|38 |77506.75|18006.00|22959.20 664 | |40|38 |18006.00|18006.00|22959.20 665 | |50|15 |20659.80|20659.80|22959.20 666 | |=== 667 | 668 | === INSERT Usage 669 | 670 | The following query uses both an uncorrelated and correlated fullselect in the query that builds the set of rows to be inserted: 671 | 672 | .Fullselect in INSERT 673 | [source,sql] 674 | .... 675 | INSERT INTO staff 676 | SELECT id + 1 677 | , (SELECT MIN(name) 678 | FROM staff) 679 | , (SELECT dept 680 | FROM staff s2 681 | WHERE s2.id = s1.id - 100) 682 | , 'A', 1, 2, 3 683 | FROM staff s1 684 | WHERE id = (SELECT MAX(id) 685 | FROM staff); 686 | .... 687 | 688 | === UPDATE Usage 689 | 690 | The following example uses an uncorrelated fullselect to assign a set of workers the average salary in the company - plus two thousand dollars. 691 | 692 | .Use uncorrelated Full-Select to give workers company AVG salary (+$2000) 693 | [source,sql] 694 | .... 695 | UPDATE staff a 696 | SET salary = 697 | (SELECT AVG(salary)+ 2000 698 | FROM staff) 699 | WHERE id < 60; 700 | .... 701 | 702 | _ANSWER_ 703 | [options="header",] 704 | |=== 705 | |ID|DEPT|SALARY BEFORE|SALARY AFTER 706 | |10|20 |18357.50 |18675.64 707 | |20|20 |78171.25 |18675.64 708 | |30|38 |77506.75 |18675.64 709 | |40|38 |18006.00 |18675.64 710 | |50|15 |20659.80 |18675.64 711 | |=== 712 | 713 | The next statement uses a correlated fullselect to assign a set of workers the average salary for their department - plus two thousand dollars. Observe that when there is more than one worker in the same department, that they all get the same new salary. This is because the fullselect is resolved before the first update was done, not after each. 714 | 715 | .Use correlated Full-Select to give workers department AVG salary (+$2000) 716 | [source,sql] 717 | .... 718 | UPDATE staff a 719 | SET salary = 720 | (SELECT AVG(salary) + 2000 721 | FROM staff b 722 | WHERE a.dept = b.dept) 723 | WHERE id < 60; 724 | .... 725 | 726 | _ANSWER_ 727 | [options="header",] 728 | |=== 729 | |ID|DEPT|SALARY BEFORE|SALARY AFTER 730 | |10|20 |18357.50 |18071.52 731 | |20|20 |78171.25 |18071.52 732 | |30|38 |77506.75 |17457.11 733 | |40|38 |18006.00 |17457.11 734 | |50|15 |20659.80 |17482.33 735 | |=== 736 | 737 | NOTE: A fullselect is always resolved just once. If it is queried using a correlated expression, then the data returned each time may differ, but the table remains unchanged. 738 | 739 | The next update is the same as the prior, except that two fields are changed: 740 | 741 | .Update two fields by referencing Full-Select 742 | [source,sql] 743 | .... 744 | UPDATE staff a 745 | SET (salary, years) = 746 | (SELECT AVG(salary) + 2000 747 | , MAX(years) 748 | FROM staff b 749 | WHERE a.dept = b.dept) 750 | WHERE id < 60; 751 | .... 752 | 753 | [[declared.global.temporary.tables]] 754 | === Declared Global Temporary Tables 755 | 756 | If we want to temporarily retain some rows for processing by subsequent SQL statements, we can use a Declared Global Temporary Table. A temporary table only exists until the thread is terminated (or sooner). It is not defined in the Db2 catalogue, and neither its definition nor its contents are visible to other users. Multiple users can declare the same temporary table at the same time. Each will be independently working with their own copy. 757 | 758 | *Usage Notes* 759 | 760 | For a complete description of this feature, see the SQL reference. Below are some key points: 761 | 762 | * The temporary table name can be any valid Db2 table name. The table qualifier, if provided, must be SESSION. If the qualifier is not provided, it is assumed to be SESSION. 763 | * If the temporary table has been previously defined in this session, the WITH REPLACE clause can be used to override it. Alternatively, one can DROP the prior instance. 764 | * An index can be defined on a global temporary table. The qualifier (i.e. SESSION) must be explicitly provided. 765 | * Any column type can be used in the table, except for: BLOB, CLOB, DBCLOB, LONG VARCHAR, LONG VARGRAPHIC, DATALINK, reference, and structured data types. 766 | * One can choose to preserve or delete (the default) the rows in the table when a commit occurs. Deleting the rows does not drop the table. 767 | * Standard identity column definitions can be used if desired. 768 | * Changes are not logged. 769 | 770 | ==== Sample SQL 771 | 772 | Below is an example of declaring a global temporary table by listing the columns: 773 | 774 | .Declare Global Temporary Table - define columns 775 | [source,sql] 776 | .... 777 | DECLARE GLOBAL TEMPORARY TABLE session.fred 778 | ( dept SMALLINT NOT NULL 779 | , avg_salary DEC(7, 2) NOT NULL 780 | , num_emps SMALLINT NOT NULL) 781 | ON COMMIT DELETE ROWS; 782 | .... 783 | 784 | In the next example, the temporary table is defined to have exactly the same columns as the existing STAFF table: 785 | 786 | .Declare Global Temporary Table - like another table 787 | [source,sql] 788 | .... 789 | DECLARE GLOBAL TEMPORARY TABLE session.fred 790 | LIKE staff INCLUDING COLUMN DEFAULTS 791 | WITH REPLACE 792 | ON COMMIT PRESERVE ROWS; 793 | .... 794 | 795 | In the next example, the temporary table is defined to have a set of columns that are returned by a particular select statement. The statement is not actually run at definition time, so any predicates provided are irrelevant: 796 | 797 | .Declare Global Temporary Table - like query output 798 | [source,sql] 799 | .... 800 | DECLARE GLOBAL TEMPORARY TABLE session.fred AS 801 | (SELECT dept 802 | , MAX(id) AS max_id 803 | , SUM(salary) AS sum_sal 804 | FROM staff 805 | WHERE name <> 'IDIOT' 806 | GROUP BY dept) 807 | DEFINITION ONLY 808 | WITH REPLACE; 809 | .... 810 | 811 | Indexes can be added to temporary tables in order to improve performance and/or to enforce uniqueness: 812 | 813 | .Temporary table with index 814 | [source,sql] 815 | .... 816 | DECLARE GLOBAL TEMPORARY TABLE session.fred 817 | LIKE staff 818 | INCLUDING COLUMN DEFAULTS 819 | WITH REPLACE ON COMMIT DELETE ROWS; 820 | 821 | CREATE UNIQUE INDEX session.fredx ON Session.fred (id); 822 | 823 | INSERT INTO session.fred 824 | SELECT * 825 | FROM staff 826 | WHERE id < 200; 827 | 828 | SELECT COUNT(*) 829 | FROM session.fred; --> Returns 19 830 | 831 | COMMIT; 832 | 833 | SELECT COUNT(*) 834 | FROM session.fred; --> Returns 0 835 | .... 836 | 837 | A temporary table has to be dropped to reuse the same name: 838 | 839 | .Dropping a temporary table 840 | [source,sql] 841 | .... 842 | DECLARE GLOBAL TEMPORARY TABLE session.fred 843 | ( dept SMALLINT NOT NULL 844 | , avg_salary DEC(7, 2) NOT NULL 845 | , num_emps SMALLINT NOT NULL) 846 | ON COMMIT DELETE ROWS; 847 | 848 | INSERT INTO session.fred 849 | SELECT dept 850 | , AVG(salary) 851 | , COUNT(*) 852 | FROM staff 853 | GROUP BY dept; 854 | 855 | SELECT COUNT(*) 856 | FROM session.fred; --> Returns 8 857 | 858 | DROP TABLE session.fred; 859 | 860 | DECLARE GLOBAL TEMPORARY TABLE session.fred 861 | (dept SMALLINT NOT NULL) 862 | ON COMMIT DELETE ROWS; 863 | 864 | SELECT COUNT(*) 865 | FROM session.fred; --> Return 0 866 | .... 867 | 868 | === Tablespace 869 | 870 | Before a user can create a declared global temporary table, a USER TEMPORARY tablespace that they have access to, has to be created. A typical definition follows: 871 | 872 | .Create USER TEMPORARY tablespace 873 | [source,sql] 874 | .... 875 | CREATE USER TEMPORARY TABLESPACE FRED 876 | MANAGED BY DATABASE 877 | USING (FILE 'C:\Db2\TEMPFRED\FRED1' 1000 878 | ,FILE 'C:\Db2\TEMPFRED\FRED2' 1000 879 | ,FILE 'C:\Db2\TEMPFRED\FRED3' 1000); 880 | 881 | GRANT USE OF TABLESPACE FRED TO PUBLIC; 882 | .... 883 | 884 | === Do NOT use to Hold Output 885 | 886 | In general, do not use a Declared Global Temporary Table to hold job output data, especially if the table is defined ON COMMIT PRESERVE ROWS. 887 | If the job fails halfway through, the contents of the temporary table will be lost. If, prior to the failure, the job had updated and then committed Production data, it may be impossible to recreate the lost output because the committed rows cannot be updated twice. 888 | 889 | 890 | -------------------------------------------------------------------------------- /chapters_asciidoc/20 Triggers.asciidoc: -------------------------------------------------------------------------------- 1 | [[triggers.chapter]] 2 | == Triggers 3 | (((Triggers))) 4 | A trigger initiates an action whenever a row, or set of rows, is changed. The change can be either an insert, update or delete. 5 | 6 | NOTE: The Db2 Application Development Guide: Programming Server Applications is an excellent source of information on using triggers. The SQL Reference has all the basics. 7 | 8 | === Trigger Types 9 | 10 | * A *BEFORE* trigger is run before the row is changed. It is typically used to change the values being entered (e.g. set a field to the current date), or to flag an error. It cannot be used to initiate changes in other tables. 11 | * An *AFTER* trigger is run after the row is changed. It can do everything a before trigger can do, plus modify data in other tables or systems (e.g. it can insert a row into an audit table after an update). 12 | * An *INSTEAD OF* trigger is used in a view to do something instead of the action that the user intended (e.g. do an insert instead of an update). There can be only one instead of trigger per possible DML type on a given view. 13 | 14 | NOTE: See the chapter titled <> for a sample application that uses INSTEAD OF triggers to record all changes to the data in a set of tables. 15 | 16 | === Action Type 17 | 18 | Each trigger applies to a single kind of DML action (i.e. insert, update, or delete). With the exception of instead of triggers, there can be as many triggers per action and per table as desired. An update trigger can be limited to changes to certain columns. 19 | 20 | *Object Type* 21 | 22 | * A table can have both BEFORE and AFTER triggers. The former have to be defined FOR EACH ROW. 23 | * A view can have INSTEAD OF triggers (up to three - one per DML type). 24 | 25 | *Referencing* 26 | 27 | In the body of the trigger the object being changed can be referenced using a set of optional correlation names: 28 | 29 | * *OLD* refers to each individual row before the change (does not apply to an insert). 30 | * *NEW* refers to each individual row after the change (does not apply to a delete). 31 | * *OLD_TABLE* refers to the set of rows before the change (does not apply to an insert). 32 | * *NEW_TABLE* refers to the set of rows after the change (does to apply to a delete). 33 | 34 | *Application Scope* 35 | 36 | * A trigger defined FOR EACH STATEMENT is invoked once per statement. 37 | * A trigger defined FOR EACH ROW is invoked once per individual row changed. 38 | 39 | NOTE: If one defines two FOR EACH ROW triggers, the first is applied for all rows before the second is run. To do two separate actions per row, one at a time, one has to define a single trigger that includes the two actions in a single compound SQL statement. 40 | 41 | *When Check* 42 | 43 | One can optionally include some predicates so that the body of the trigger is only invoked when certain conditions are true. 44 | 45 | *Trigger Usage* 46 | 47 | A trigger can be invoked whenever one of the following occurs: 48 | 49 | * A row in a table is inserted, updated, or deleted. 50 | * An (implied) row in a view is inserted, updated, or deleted. 51 | * A referential integrity rule on a related table causes a cascading change (i.e. delete or set null) to the triggered table. 52 | * A trigger on an unrelated table or view is invoked - and that trigger changes rows in the triggered table. 53 | 54 | If no rows are changed, a trigger defined FOR EACH ROW is not run, while a trigger defined FOR EACH STATEMENT is still run. To prevent the latter from doing anything when this happens, add a suitable WHEN check. 55 | 56 | [[trigger.examples]] 57 | === Trigger Examples 58 | 59 | This section uses a set of simple sample tables to illustrate general trigger usage. 60 | 61 | ==== Sample Tables 62 | 63 | .Sample Tables 64 | [source,sql] 65 | .... 66 | CREATE TABLE cust_balance 67 | ( cust# INTEGER NOT NULL 68 | GENERATED ALWAYS AS IDENTITY 69 | , status CHAR(2) NOT NULL 70 | , balance DECIMAL(18,2) NOT NULL 71 | , num_trans INTEGER NOT NULL 72 | , cur_ts TIMESTAMP NOT NULL 73 | , PRIMARY KEY (cust#)); 74 | 75 | -- Every state of a row in the balance table will be recorded in the history table. 76 | CREATE TABLE cust_history 77 | ( cust# INTEGER NOT NULL 78 | , trans# INTEGER NOT NULL 79 | , balance DECIMAL(18,2) NOT NULL 80 | , bgn_ts TIMESTAMP NOT NULL 81 | , end_ts TIMESTAMP NOT NULL 82 | , PRIMARY KEY (cust#, bgn_ts)); 83 | 84 | -- Every valid change to the balance table will be recorded in the transaction table. 85 | CREATE TABLE cust_trans 86 | ( min_cust# INTEGER 87 | , max_cust# INTEGER 88 | , rows_tot INTEGER NOT NULL 89 | , change_val DECIMAL(18,2) 90 | , change_type CHAR(1) NOT NULL 91 | , cur_ts TIMESTAMP NOT NULL 92 | , PRIMARY KEY (cur_ts)); 93 | .... 94 | 95 | === Before Row Triggers - Set Values 96 | 97 | The first trigger below overrides whatever the user enters during the insert, and before the row is inserted, sets both the cur-ts and number-of-trans columns to their correct values: 98 | 99 | .Before insert trigger - set values 100 | [source,sql] 101 | .... 102 | CREATE TRIGGER cust_bal_ins1 103 | NO CASCADE BEFORE INSERT 104 | ON cust_balance 105 | REFERENCING NEW AS nnn 106 | FOR EACH ROW 107 | MODE Db2SQL 108 | SET nnn.cur_ts = CURRENT TIMESTAMP 109 | , nnn.num_trans = 1; 110 | .... 111 | 112 | The following trigger does the same before an update: 113 | 114 | .Before update trigger - set values 115 | [source,sql] 116 | .... 117 | CREATE TRIGGER cust_bal_upd1 118 | NO CASCADE BEFORE UPDATE 119 | ON cust_balance 120 | REFERENCING NEW AS nnn 121 | OLD AS ooo 122 | FOR EACH ROW 123 | MODE Db2SQL 124 | SET nnn.cur_ts = CURRENT TIMESTAMP 125 | , nnn.num_trans = ooo.num_trans + 1; 126 | .... 127 | 128 | === Before Row Trigger - Signal Error 129 | 130 | The next trigger will flag an error (and thus fail the update) if the customer balance is reduced by too large a value: 131 | 132 | .Before Trigger - flag error 133 | [source,sql] 134 | .... 135 | CREATE TRIGGER cust_bal_upd2 136 | NO CASCADE BEFORE UPDATE OF balance 137 | ON cust_balance 138 | REFERENCING NEW AS nnn 139 | OLD AS ooo 140 | FOR EACH ROW 141 | MODE Db2SQL 142 | WHEN (ooo.balance - nnn.balance > 1000) 143 | SIGNAL SQLSTATE VALUE '71001' 144 | SET MESSAGE_TEXT = 'Cannot withdraw > 1000'; 145 | .... 146 | 147 | === After Row Triggers - Record Data States 148 | 149 | The three triggers in this section record the state of the data in the customer table. The first is invoked after each insert. It records the new data in the customer-history table: 150 | 151 | .After Trigger - record insert 152 | [source,sql] 153 | .... 154 | CREATE TRIGGER cust_his_ins1 155 | AFTER INSERT ON cust_balance 156 | REFERENCING NEW AS nnn 157 | FOR EACH ROW 158 | MODE Db2SQL 159 | INSERT INTO cust_history 160 | VALUES (nnn.cust# 161 | , nnn.num_trans 162 | , nnn.balance 163 | , nnn.cur_ts 164 | , '9999-12-31-24.00.00'); 165 | .... 166 | 167 | The next trigger is invoked after every update of a row in the customer table. It first runs an update (of the old history row), and then does an insert. Because this trigger uses a compound SQL statement, it cannot use the semi-colon as the statement delimiter: 168 | 169 | .After Trigger - record update 170 | [source,sql] 171 | .... 172 | CREATE TRIGGER cust_his_upd1 173 | AFTER UPDATE ON cust_balance 174 | REFERENCING OLD AS ooo 175 | NEW AS nnn 176 | FOR EACH ROW 177 | MODE Db2SQL 178 | BEGIN ATOMIC 179 | UPDATE cust_history 180 | SET end_ts = CURRENT TIMESTAMP 181 | WHERE cust# = ooo.cust# 182 | AND bgn_ts = ooo.cur_ts; 183 | INSERT INTO cust_history 184 | VALUES (nnn.cust# 185 | , nnn.num_trans 186 | , nnn.balance 187 | , nnn.cur_ts 188 | , '9999-12-31-24.00.00'); 189 | END 190 | .... 191 | 192 | *Notes* 193 | 194 | * The above trigger relies on the fact that the customer-number cannot change (note: it is generated always) to link the two rows in the history table together. In other words, the old row will always have the same customer-number as the new row. 195 | * The above also trigger relies on the presence of the cust_bal_upd1 before trigger (see <>) to set the nnn.cur_ts value to the current timestamp. 196 | 197 | The final trigger records a delete by doing an update to the history table: 198 | 199 | .After Trigger - record delete 200 | [source,sql] 201 | .... 202 | CREATE TRIGGER cust_his_del1 203 | AFTER DELETE ON cust_balance 204 | REFERENCING OLD AS ooo 205 | FOR EACH ROW 206 | MODE Db2SQL 207 | UPDATE cust_history 208 | SET end_ts = CURRENT TIMESTAMP 209 | WHERE cust# = ooo.cust# 210 | AND bgn_ts = ooo.cur_ts; 211 | .... 212 | 213 | === After Statement Triggers - Record Changes 214 | 215 | The following three triggers record every type of change (i.e. insert, update, or delete) to any row, or set of rows (including an empty set) in the customer table. They all run an insert that records the type and number of rows changed: 216 | 217 | .After Trigger - record insert 218 | [source,sql] 219 | .... 220 | CREATE TRIGGER trans_his_ins1 221 | AFTER INSERT ON cust_balance 222 | REFERENCING NEW_TABLE AS newtab 223 | FOR EACH STATEMENT 224 | MODE Db2SQL 225 | INSERT INTO cust_trans 226 | SELECT MIN(cust#) 227 | , MAX(cust#) 228 | , COUNT(*) 229 | , SUM(balance) 230 | , 'I' 231 | , CURRENT TIMESTAMP 232 | FROM newtab; 233 | .... 234 | 235 | .After Trigger - record update 236 | [source,sql] 237 | .... 238 | CREATE TRIGGER trans_his_upd1 239 | AFTER UPDATE ON cust_balance 240 | REFERENCING OLD_TABLE AS oldtab 241 | NEW_TABLE AS newtab 242 | FOR EACH STATEMENT 243 | MODE Db2SQL 244 | INSERT INTO cust_trans 245 | SELECT MIN(nt.cust#) 246 | , MAX(nt.cust#) 247 | , COUNT(*) 248 | , SUM(nt.balance - ot.balance) 249 | , 'U' 250 | , CURRENT TIMESTAMP 251 | FROM oldtab ot 252 | , newtab nt 253 | WHERE ot.cust# = nt.cust#; 254 | .... 255 | 256 | .After Trigger - record delete 257 | [source,sql] 258 | .... 259 | CREATE TRIGGER trans_his_del1 260 | AFTER DELETE ON cust_balance 261 | REFERENCING OLD_TABLE AS oldtab 262 | FOR EACH STATEMENT 263 | MODE Db2SQL 264 | INSERT INTO cust_trans 265 | SELECT MIN(cust#) 266 | , MAX(cust#) 267 | , COUNT(*) 268 | , SUM(balance) 269 | , 'D' 270 | , CURRENT TIMESTAMP 271 | FROM oldtab; 272 | .... 273 | 274 | *Notes* 275 | 276 | * If the DML statement changes no rows, the OLD or NEW table referenced by the trigger will be empty, but still exist, and a SELECT COUNT(*) on the (empty) table will return a zero, which will then be inserted. 277 | * Any DML statements that failed (e.g. stopped by the before trigger), or that were subsequently rolled back, will not be recorded in the transaction table. 278 | 279 | ==== Examples of Usage 280 | 281 | The following DML statements were run against the customer table: 282 | 283 | .Sample DML statements 284 | [source,sql] 285 | .... 286 | INSERT INTO cust_balance (status, balance) VALUES ('C',123.45); 287 | INSERT INTO cust_balance (status, balance) VALUES ('C',000.00); 288 | INSERT INTO cust_balance (status, balance) VALUES ('D', -1.00); 289 | UPDATE cust_balance 290 | SET balance = balance + 123 291 | WHERE cust# <= 2; 292 | UPDATE cust_balance 293 | SET balance = balance * -1 294 | WHERE cust# = -1; 295 | UPDATE cust_balance 296 | SET balance = balance - 123 297 | WHERE cust# = 1; 298 | DELETE FROM cust_balance 299 | WHERE cust# = 3; 300 | .... 301 | 302 | === Tables After DML 303 | 304 | At the end of the above, the three tables had the following data: 305 | 306 | .Customer-balance table rows 307 | [options="header",] 308 | |=== 309 | |CUST#|STATUS|BALANCE|NUM_TRANS|CUR_TS 310 | |1 |C |123.45 |3 |2005-05-31-19.58.46.096000 311 | |2 |C |123.00 |2 |2005-05-31-19.58.46.034000 312 | |=== 313 | 314 | .Customer-history table rows 315 | [options="header",] 316 | |=== 317 | |CUST#| TRANS#| BALANCE| BGN_TS | END_TS 318 | |1 | 1 | 123.45 | 2005-05-31-19.58.45.971000 | 2005-05-31-19.58.46.034000 319 | |1 | 2 | 246.45 | 2005-05-31-19.58.46.034000 | 2005-05-31-19.58.46.096000 320 | |1 | 3 | 123.45 | 2005-05-31-19.58.46.096000 | 9999-12-31-24.00.00.000000 321 | |2 | 1 | 0.00 | 2005-05-31-19.58.45.987000 | 2005-05-31-19.58.46.034000 322 | |2 | 2 | 123.00 | 2005-05-31-19.58.46.034000 | 9999-12-31-24.00.00.000000 323 | |3 | 1 | -1.00 | 2005-05-31-19.58.46.003000 |2005-05-31-19.58.46.096003 324 | |=== 325 | 326 | .Customer-transaction table rows 327 | [options="header",] 328 | |=== 329 | |MIN_CUST#| MAX_CUST#| ROWS |CHANGE_VAL| CHANGE_TYPE |CUR_TS 330 | |1 | 1 | 1 | 123.45 | I | 2005-05-31-19.58.45.971000 331 | |2 | 2 | 1 | 0.00 | I | 2005-05-31-19.58.45.987000 332 | |3 | 3 | 1 | -1.00 | I | 2005-05-31-19.58.46.003000 333 | |1 | 2 | 2 | 246.00 | U | 2005-05-31-19.58.46.034000 334 | |- | - | 0 | - | U | 2005-05-31-19.58.46.065000 335 | |1 | 1 | 1 | -123.00 | U | 2005-05-31-19.58.46.096000 336 | |3 | 3 | 1 | 1.00 | D | 2005-05-31-19.58.46.096003 337 | |=== 338 | 339 | 340 | -------------------------------------------------------------------------------- /chapters_asciidoc/21 Protecting Your Data.asciidoc: -------------------------------------------------------------------------------- 1 | [[protecting.your.data]] 2 | == Protecting Your Data 3 | 4 | There is no use having a database if the data in it is not valid. This chapter introduces some of the tools that exist in Db2 to enable one to ensure the validity of the data in your application. 5 | 6 | *Issues Covered* 7 | 8 | * Enforcing field uniqueness. 9 | * Enforcing field value ranges. 10 | * Generating key and values. 11 | * Maintaining summary columns. 12 | * Enforcing relationships between and within tables. 13 | * Creating columns that have current timestamp of last change. 14 | 15 | *Issues Not Covered* 16 | 17 | * Data access authorization. 18 | * Recovery and backup. 19 | 20 | === Sample Application 21 | 22 | Consider the following two tables, which make up a very simple application: 23 | 24 | .Sample application tables 25 | [source,sql] 26 | .... 27 | CREATE TABLE customer_balance 28 | ( cust_id INTEGER 29 | , cust_name VARCHAR(20) 30 | , cust_sex CHAR(1) 31 | , num_sales SMALLINT 32 | , total_sales DECIMAL(12, 2) 33 | , master_cust_id INTEGER 34 | , cust_insert_ts TIMESTAMP 35 | , cust_update_ts TIMESTAMP); 36 | 37 | CREATE TABLE us_sales 38 | ( invoice# INTEGER 39 | , cust_id INTEGER 40 | , sale_value DECIMAL(18, 2) 41 | , sale_insert_ts TIMESTAMP 42 | , sale_update_ts TIMESTAMP); 43 | .... 44 | 45 | === Customer Balance Table 46 | 47 | We want Db2 to enforce the following business rules: 48 | 49 | * CUST_ID will be a unique positive integer value, always ascending, never reused, and automatically generated by Db2. This field cannot be updated by a user. 50 | * CUST_NAME has the customer name. It can be anything, but not blank. 51 | * CUST_SEX must be either "M" or "F". 52 | * NUM_SALES will have a count of the sales (for the customer), as recorded in the related US-sales table. The value will be automatically maintained by Db2. It cannot be updated directly by a user. 53 | * TOTAL_SALES will have the sum sales (in US dollars) for the customer. The value will be automatically updated by Db2. It cannot be updated directly by a user. 54 | * MASTER_CUST_ID will have, if there exists, the customer-ID of the customer that this customer is a dependent of. If there is no master customer, the value is null. If the master customer is deleted, this row will also be deleted (if possible). 55 | * CUST_INSERT_TS has the timestamp when the row was inserted. The value is automatically generated by Db2. Any attempt to change will induce an error. 56 | * CUST_UPDATE_TS has the timestamp when the row, or a dependent US_SALES row, was last updated by a user. The value is automatically generated by Db2. Any attempt to change directly will induce an error. 57 | * A row can only be deleted when there are no corresponding rows in the US-sales table (i.e. for the same customer). 58 | 59 | *US Sales Table* 60 | 61 | We want Db2 to enforce the following business rules: 62 | 63 | * INVOICE#: will be a unique ascending integer value. The uniqueness will apply to the US-sales table, plus any international sales tables (i.e. to more than one table). 64 | * CUST_ID is the customer ID, as recorded in the customer-balance table. No row can be inserted into the US-sales table except that there is a corresponding row in the customerbalance table. Once inserted, this value cannot be updated. 65 | * SALE_VALUE is the value of the sale, in US dollars. When a row is inserted, this value is added to the related total-sales value in the customer-balance table. If the value is subsequently updated, the total-sales value is maintained in sync. 66 | * SALE_INSERT_TS has the timestamp when the row was inserted. The value is automatically generated by Db2. Any attempt to change will induce an error. 67 | * SALE_UPDATE_TS has the timestamp when the row was last updated. The value is automatically generated by Db2. Any attempt to change will induce an error. 68 | * Deleting a row from the US-sales table has no impact on the customer-balance table (i.e. the total-sales is not decremented). But a row can only be deleted from the latter when there are no more related rows in the US-sales table. 69 | 70 | === Enforcement Tools 71 | 72 | To enforce the above business rules, we are going to have to use: 73 | 74 | * Unique indexes. 75 | * Secondary non-unique indexes (needed for performance). 76 | * Primary and foreign key definitions. 77 | * User-defined distinct data types. 78 | * Nulls-allowed and not-null columns. 79 | * Column value constraint rules. 80 | * Before and after triggers. 81 | * Generated row change timestamps. 82 | * Distinct Data Types 83 | 84 | Two of the fields are to contain US dollars, the implication being the data in these columns should not be combined with columns that contain Euros, or Japanese Yen, or my shoe size. To this end, we will define a distinct data type for US dollars: 85 | 86 | .Create US-dollars data type 87 | [source,sql] 88 | .... 89 | CREATE DISTINCT TYPE us_dollars 90 | AS decimal(18, 2) WITH COMPARISONS; 91 | .... 92 | 93 | See <> for a more detailed discussion of this topic. 94 | 95 | === Customer-Balance Table 96 | 97 | Now that we have defined the data type, we can create our first table: 98 | 99 | .Customer-Balance table DDL 100 | [source,sql] 101 | .... 102 | CREATE TABLE customer_balance 103 | ( cust_id INTEGER NOT NULL 104 | GENERATED ALWAYS AS IDENTITY 105 | ( START WITH 1 106 | , INCREMENT BY 1 107 | , NO CYCLE 108 | , NO CACHE) 109 | , cust_name VARCHAR(20) NOT NULL 110 | , cust_sex CHAR(1) NOT NULL 111 | , num_sales SMALLINT NOT NULL 112 | , total_sales us_dollars NOT NULL 113 | , master_cust_id INTEGER 114 | , cust_insert_ts TIMESTAMP NOT NULL 115 | , cust_update_ts TIMESTAMP NOT NULL 116 | , PRIMARY KEY (cust_id) 117 | , CONSTRAINT c1 CHECK (cust_name <> '') 118 | , CONSTRAINT c2 CHECK (cust_sex = 'F' OR cust_sex = 'M') 119 | , CONSTRAINT c3 FOREIGN KEY (master_cust_id) 120 | REFERENCES customer_balance (cust_id) 121 | ON DELETE CASCADE); 122 | .... 123 | 124 | The following business rules are enforced above: 125 | 126 | * The customer-ID is defined as an identity column (see <>), which means that the value is automatically generated by Db2 using the rules given. The field cannot be updated by the user. 127 | * The customer-ID is defined as the primary key, which automatically generates a unique index on the field, and also enables us to reference the field using a referential integrity rule. Being a primary key prevents updates, but we had already prevented them because the field is an identity column. 128 | * The total-sales column uses the type us-dollars. 129 | * Constraints C1 and C2 enforce two data validation rules. 130 | * Constraint C3 relates the current row to a master customer, if one exists. Furthermore, if the master customer is deleted, this row is also deleted. 131 | * All of the columns, except for the master-customer-id, are defined as NOT NULL, which means that a value must be provided. 132 | We still have several more business rules to enforce - relating to automatically updating fields and/or preventing user updates. These will be enforced using triggers. 133 | 134 | === US-Sales Table 135 | 136 | Now for the related US-sales table: 137 | 138 | .US-Sales table DDL 139 | [source,sql] 140 | .... 141 | CREATE TABLE us_sales 142 | ( invoice# INTEGER NOT NULL 143 | , cust_id INTEGER NOT NULL 144 | , sale_value us_dollars NOT NULL 145 | , sale_insert_ts TIMESTAMP NOT NULL 146 | , sale_update_ts TIMESTAMP NOT NULL 147 | GENERATED ALWAYS 148 | FOR EACH ROW ON UPDATE 149 | AS ROW CHANGE TIMESTAMP 150 | 151 | , PRIMARY KEY (invoice#) 152 | , CONSTRAINT u1 CHECK (sale_value > us_dollars(0)) 153 | , CONSTRAINT u2 FOREIGN KEY (cust_id) 154 | REFERENCES customer_balance 155 | ON DELETE RESTRICT); 156 | 157 | COMMIT; 158 | 159 | CREATE INDEX us_sales_cust ON us_sales (cust_id); 160 | .... 161 | 162 | The following business rules are enforced above: 163 | 164 | * The invoice# is defined as the primary key, which automatically generates a unique index on the field, and also prevents updates. 165 | * The sale-value uses the type us-dollars. 166 | * Constraint U1 checks that the sale-value is always greater than zero. 167 | * Constraint U2 checks that the customer-ID exists in the customer-balance table, and also prevents rows from being deleted from the latter if there is a related row in this table. 168 | * All of the columns are defined as NOT NULL, so a value must be provided for each. 169 | * A secondary non-unique index is defined on customer-ID, so that deletes to the customerbalance table (which require checking this table for related customer-ID rows) are as efficient as possible. 170 | * The CUST_UPDATE_TS column is generated always (by Db2) and gets a unique value that is the current timestamp. 171 | 172 | ==== Generated Always Timestamp Columns 173 | 174 | A TIMESTAMP column that is defined as GENERATED ALWAYS will get a value that is unique for all rows in the table. This value will usually be the CURRENT TIMESTAMP of the last insert or update of the row. However, if more than row was inserted or updated in a single stmt, the secondary rows (updated) will get a value that is equal to the CURRENT TIMESTAMP special register, plus "n" microseconds, where "n" goes up in steps of 1. One consequence of the above logic is that some rows changed will get a timestamp value that is ahead of the CURRENT TIMESTAMP special register. This can cause problems if one is relying on this value to find all rows that were changed before the start of the query. To illustrate, imagine that one inserted multiple rows (in a single insert) into the US_SALES table, and then immediately ran the following query: 175 | 176 | .Select run after multi-row insert 177 | [source,sql] 178 | .... 179 | SELECT * 180 | FROM us_sales 181 | WHERE sale_update_ts <= CURRENT TIMESTAMP; 182 | .... 183 | 184 | In some environments (e.g. Windows) the CURRENT TIMESTAMP special register value may be the same from one stmt to the next. If this happens, the above query will find the first row just inserted, but not any subsequent rows, because their SALE_UPDATE_TS value will be greater than the CURRENT TIMESTAMP special register. 185 | 186 | Certain restrictions apply: 187 | 188 | * Only one TIMESTAMP column can be defined GENERATED ALWAYS per table. The column must be defined NOT NULL. 189 | * The TIMESTAMP column is updated, even if no other value in the row changes. So if one does an update that sets SALE_VALUE = SALE_VALUE + 0, the SALE_UPDATE_TS column will be updated on all matching rows. 190 | 191 | The ROW CHANGE TIMESTAMP special register can be used get the last time that the row was updated, even when one does not know the name of the column that holds this data: 192 | 193 | .Row change timestamp usage 194 | [source,sql] 195 | .... 196 | SELECT ROW CHANGE TIMESTAMP FOR us_sales 197 | FROM us_sales 198 | WHERE invoice# = 5; 199 | .... 200 | 201 | The (unique) TIMESTAMP value obtained above can be used to validate that the target row has not been updated when a subsequent UPDATE is done: 202 | 203 | .Update that checks for intervening updates 204 | [source,sql] 205 | .... 206 | UPDATE us_sales 207 | SET sale_value = DECIMAL(sale_value) + 1 208 | WHERE invoice# = 5 209 | AND ROW CHANGE TIMESTAMP for us_sales = '2007-11-10-01.02.03'; 210 | .... 211 | 212 | ==== Triggers 213 | 214 | Triggers can sometimes be quite complex little programs. If coded incorrectly, they can do an amazing amount of damage. As such, it pays to learn quite a lot before using them. Below are some very brief notes, but please refer to the official Db2 documentation for a more detailed description. See also <> for a brief chapter on triggers. Individual triggers are defined on a table, and for a particular type of DML statement: 215 | 216 | * Insert 217 | * Update 218 | * Delete 219 | 220 | A trigger can be invoked once per: 221 | 222 | * Row changed. 223 | * Statement run. 224 | 225 | A trigger can be invoked: 226 | 227 | * Before the change is made. 228 | * After the change is made. 229 | 230 | Before triggers change input values before they are entered into the table and/or flag an error. After triggers do things after the row is changed. They may make more changes (to the target table, or to other tables), induce an error, or invoke an external program. SQL statements that select the changes made by DML (see <>) cannot see the changes made by an after trigger if those changes impact the rows just changed. 231 | The action of one "after" trigger can invoke other triggers, which may then invoke other triggers, and so on. Before triggers cannot do this because they can only act upon the input values of the DML statement that invoked them. When there are multiple triggers for a single table/action, each trigger is run for all rows before the next trigger is invoked - even if defined "for each row". Triggers are invoked in the order that they were created. 232 | 233 | ==== Customer-Balance - Insert Trigger 234 | 235 | For each row inserted into the Customer-Balance table we need to do the following: 236 | 237 | * Set the num-sales to zero. 238 | * Set the total-sales to zero. 239 | * Set the update-timestamp to the current timestamp. 240 | * Set the insert-timestamp to the current timestamp. 241 | 242 | All of this can be done using a simple before trigger: 243 | 244 | .Set values during insert 245 | [source,sql] 246 | .... 247 | CREATE TRIGGER cust_balance_ins1 248 | NO CASCADE BEFORE INSERT 249 | ON customer_balance 250 | REFERENCING NEW AS nnn 251 | FOR EACH ROW 252 | MODE Db2SQL 253 | SET nnn.num_sales = 0 254 | , nnn.total_sales = 0 255 | , nnn.cust_insert_ts = CURRENT TIMESTAMP 256 | , nnn.cust_update_ts = CURRENT TIMESTAMP; 257 | .... 258 | 259 | ==== Customer-Balance - Update Triggers 260 | 261 | For each row updated in the Customer-Balance table we need to do: 262 | 263 | * Set the update-timestamp to the current timestamp. 264 | * Prevent updates to the insert-timestamp, or sales fields. 265 | * We can use the following trigger to maintain the update-timestamp: 266 | 267 | .Set update-timestamp during update 268 | [source,sql] 269 | .... 270 | CREATE TRIGGER cust_balance_upd1 271 | NO CASCADE BEFORE UPDATE OF cust_update_ts 272 | ON customer_balance 273 | REFERENCING NEW AS nnn 274 | FOR EACH ROW 275 | MODE Db2SQL 276 | SET nnn.cust_update_ts = CURRENT TIMESTAMP; 277 | .... 278 | 279 | We can prevent updates to the insert-timestamp with the following trigger: 280 | 281 | .Prevent update of insert-timestamp 282 | [source,sql] 283 | .... 284 | CREATE TRIGGER cust_balance_upd2 285 | NO CASCADE BEFORE UPDATE OF cust_insert_ts 286 | ON customer_balance 287 | FOR EACH ROW 288 | MODE Db2SQL 289 | SIGNAL SQLSTATE VALUE '71001' 290 | SET MESSAGE_TEXT = 'Cannot update CUST insert-ts'; 291 | .... 292 | 293 | We don't want users to update the two sales counters directly. But the two fields do have to be updated (by a trigger) whenever there is a change to the us-sales table. The solution is to have a trigger that prevents updates if there is no corresponding row in the us-sales table where the update-timestamp is greater than or equal to the current timestamp: 294 | 295 | .Prevent update of sales fields 296 | [source,sql] 297 | .... 298 | CREATE TRIGGER cust_balance_upd3 299 | NO CASCADE BEFORE UPDATE OF num_sales 300 | , total_sales 301 | ON customer_balance 302 | REFERENCING NEW AS nnn 303 | FOR EACH ROW 304 | MODE Db2SQL 305 | WHEN (CURRENT TIMESTAMP > (SELECT MAX(sss.sale_update_ts) 306 | FROM us_sales sss 307 | WHERE nnn.cust_id = sss.cust_id)) 308 | SIGNAL SQLSTATE VALUE '71001' 309 | SET MESSAGE_TEXT = 'Feilds only updated via US-Sales'; 310 | .... 311 | 312 | ==== US-Sales - Insert Triggers 313 | 314 | For each row inserted into the US-sales table we need to do the following: 315 | 316 | * Determine the invoice-number, which is unique over multiple tables. 317 | * Set the update-timestamp to the current timestamp. 318 | * Set the insert-timestamp to the current timestamp. 319 | * Add the sale-value to the existing total-sales in the customer-balance table. 320 | * Increment the num-sales counter in the customer-balance table. 321 | 322 | The invoice-number is supposed to be unique over several tables, so we cannot generate it using an identity column. Instead, we have to call the following external sequence: 323 | 324 | .Define sequence 325 | [source,sql] 326 | .... 327 | CREATE SEQUENCE us_sales_seq AS INTEGER 328 | START WITH 1 329 | INCREMENT BY 1 330 | NO CYCLE 331 | NO CACHE 332 | ORDER; 333 | .... 334 | 335 | Once we have the above, the following trigger will take of the first three items: 336 | 337 | .Insert trigger 338 | [source,sql] 339 | .... 340 | CREATE TRIGGER us_sales_ins1 341 | NO CASCADE BEFORE INSERT 342 | ON us_sales 343 | REFERENCING NEW AS nnn 344 | FOR EACH ROW 345 | MODE Db2SQL 346 | SET nnn.invoice# = NEXTVAL FOR us_sales_seq 347 | , nnn.sale_insert_ts = CURRENT TIMESTAMP; 348 | .... 349 | 350 | We need to use an "after" trigger to maintain the two related values in the Customer-Balance table. This will invoke an update to change the target row: 351 | 352 | .Propagate change to Customer-Balance table 353 | [source,sql] 354 | .... 355 | CREATE TRIGGER sales_to_cust_ins1 356 | AFTER INSERT ON us_sales 357 | REFERENCING NEW AS nnn 358 | FOR EACH ROW 359 | MODE Db2SQL 360 | UPDATE customer_balance ccc 361 | SET ccc.num_sales = ccc.num_sales + 1 362 | , ccc.total_sales = DECIMAL(ccc.total_sales) + DECIMAL(nnn.sale_value) 363 | WHERE ccc.cust_id = nnn.cust_id; 364 | .... 365 | 366 | ==== US-Sales - Update Triggers 367 | 368 | For each row updated in the US-sales table we need to do the following: 369 | 370 | * Prevent the customer-ID or insert-timestamp from being updated. 371 | * Propagate the change to the sale-value to the total-sales in the customer-balance table. 372 | 373 | The next trigger prevents updates to the Customer-ID and insert-timestamp: 374 | 375 | .Prevent updates to selected columns 376 | [source,sql] 377 | .... 378 | CREATE TRIGGER us_sales_upd2 379 | NO CASCADE BEFORE UPDATE OF cust_id 380 | , sale_insert_ts 381 | ON us_sales 382 | FOR EACH ROW 383 | MODE Db2SQL 384 | SIGNAL SQLSTATE VALUE '71001' 385 | SET MESSAGE_TEXT = 'Can only update sale_value'; 386 | .... 387 | 388 | We need to use an "after" trigger to maintain sales values in the Customer-Balance table: 389 | 390 | .Propagate change to Customer-Balance table 391 | [source,sql] 392 | .... 393 | CREATE TRIGGER sales_to_cust_upd1 394 | AFTER UPDATE OF sale_value 395 | ON us_sales 396 | REFERENCING NEW AS nnn 397 | OLD AS ooo 398 | FOR EACH ROW 399 | MODE Db2SQL 400 | UPDATE customer_balance ccc 401 | SET ccc.total_sales = DECIMAL(ccc.total_sales) 402 | - DECIMAL(ooo.sale_value) 403 | + DECIMAL(nnn.sale_value) 404 | WHERE ccc.cust_id = nnn.cust_id; 405 | .... 406 | 407 | === Conclusion 408 | 409 | The above application will now have logically consistent data. There is, of course, nothing to prevent an authorized user from deleting all rows, but whatever rows are in the two tables will obey the business rules that we specified at the start. 410 | 411 | Tools Used 412 | 413 | * Primary key - to enforce uniqueness, prevent updates, enable referential integrity. 414 | * Unique index - to enforce uniqueness. 415 | * Non-unique index - for performance during referential integrity check. 416 | * Sequence object - to automatically generate key values for multiple tables. 417 | * Identity column - to automatically generate key values for 1 table. 418 | * Not-null columns - to prevent use of null values. 419 | * Column constraints - to enforce basic domain-range rules. 420 | * Distinct types - to prevent one type of data from being combined with another type. 421 | * Referential integrity - to enforce relationships between rows/tables, and to enable cascading deletes when needed. 422 | * Before triggers - to prevent unwanted changes and set certain values. 423 | * After triggers - to propagate valid changes. 424 | * Automatically generated timestamp value that is always the current timestamp or (in the case of a multi-row update), the current timestamp plus a few microseconds. 425 | 426 | 427 | -------------------------------------------------------------------------------- /chapters_asciidoc/22 Recording Changes.asciidoc: -------------------------------------------------------------------------------- 1 | [[retaining.a.record]] 2 | == Retaining a Record 3 | 4 | NOTE: This chapter was written back in the versions before V9.7. It is helpful showing how to use triggers for a specific use case but if you want to implement such a scenario in Db2 you should use the "Time Travel" feature. A chapter about the "Time Travel" will be written in one of the new versions of the book. 5 | 6 | This chapter will describe a rather complex table/view/trigger schema that will enable us to offer several features that are often asked for: 7 | 8 | * Record every change to the data in an application (auditing). 9 | * Show the state of the data, as it was, at any point in the past (historical analysis). 10 | * Follow the sequence of changes to any item (e.g. customer) in the database. 11 | * Do "what if" analysis by creating virtual copies of the real world, and then changing them as desired, without affecting the real-world data. 12 | 13 | Some sample code to illustrate the above concepts will be described below. 14 | 15 | === Schema Design 16 | 17 | *Recording Changes* 18 | 19 | Below is a very simple table that records relevant customer data: 20 | 21 | .Customer table 22 | [source,sql] 23 | .... 24 | CREATE TABLE customer 25 | ( cust# INTEGER NOT NULL 26 | , cust_name CHAR(10) 27 | , cust_mgr CHAR(10) 28 | , PRIMARY KEY(cust#)); 29 | .... 30 | 31 | One can insert, update, and delete rows in the above table. The latter two actions destroy data, and so are incompatible with using this table to see all (prior) states of the data. One way to record all states of the above table is to create a related customer-history table, and then to use triggers to copy all changes in the main table to the history table. Below is one example of such a history table: 32 | 33 | .Customer-history table 34 | [source,sql] 35 | .... 36 | CREATE TABLE customer_his 37 | ( cust# INTEGER NOT NULL 38 | , cust_name CHAR(10) 39 | , cust_mgr CHAR(10) 40 | , cur_ts TIMESTAMP NOT NULL 41 | , cur_actn CHAR(1) NOT NULL 42 | , cur_user VARCHAR(10) NOT NULL 43 | , prv_cust# INTEGER 44 | , prv_ts TIMESTAMP 45 | , PRIMARY KEY(cust#, cur_ts)); 46 | 47 | CREATE UNIQUE INDEX customer_his_x1 48 | ON customer_his(cust#, prv_ts, cur_ts); 49 | .... 50 | 51 | NOTE: The secondary index shown above will make the following view processing, which looks for a row that replaces the current, much more efficient. 52 | 53 | === Table Design 54 | 55 | The history table has the same fields as the original Customer table, plus the following: 56 | 57 | * CUR-TS: The current timestamp of the change. 58 | * CUR-ACTN: The type of change (i.e. insert, update, or delete). 59 | * CUR-USER: The user who made the change (for auditing purposes). 60 | * PRV-CUST#: The previous customer number. This field enables one follow the sequence of changes for a given customer. The value is null if the action is an insert. 61 | * PRV-TS: The timestamp of the last time the row was changed (null for inserts). 62 | 63 | Observe that this history table does not have an end-timestamp. Rather, each row points back to the one that it (optionally) replaces. One advantage of such a schema is that there can be a many-to-one relationship between any given row, and the row, or rows, that replace it. When we add versions into the mix, this will become important. 64 | 65 | === Triggers 66 | (((Triggers))) 67 | Below is the relevant insert trigger. It replicates the new customer row in the history table, along with the new fields. Observe that the two "previous" fields are set to null: 68 | 69 | .Insert trigger 70 | [source,sql] 71 | .... 72 | CREATE TRIGGER customer_ins 73 | AFTER INSERT ON customer 74 | REFERENCING NEW AS nnn 75 | FOR EACH ROW 76 | MODE Db2SQL 77 | INSERT INTO customer_his 78 | VALUES (nnn.cust# 79 | , nnn.cust_name 80 | , nnn.cust_mgr 81 | , CURRENT TIMESTAMP 82 | , 'I' 83 | , USER 84 | , NULL 85 | , NULL); 86 | .... 87 | 88 | Below is the update trigger. Because the customer table does not have a record of when it was last changed, we have to get this value from the history table - using a sub-query to find the most recent row: 89 | 90 | .Update trigger 91 | [source,sql] 92 | .... 93 | CREATE TRIGGER customer_upd 94 | AFTER UPDATE ON customer 95 | REFERENCING NEW AS nnn 96 | OLD AS ooo 97 | FOR EACH ROW 98 | MODE Db2SQL 99 | INSERT INTO customer_his 100 | VALUES (nnn.cust# 101 | , nnn.cust_name 102 | , nnn.cust_mgr 103 | , CURRENT TIMESTAMP 104 | , 'U' 105 | , USER 106 | , ooo.cust# 107 | , (SELECT MAX(cur_ts) 108 | FROM customer_his hhh 109 | WHERE ooo.cust# = hhh.cust#)); 110 | .... 111 | 112 | Below is the delete trigger. It is similar to the update trigger, except that the action is different and we are under no obligation to copy over the old non-key-data columns - but we can if we wish: 113 | 114 | .Delete trigger 115 | [source,sql] 116 | .... 117 | CREATE TRIGGER customer_del 118 | AFTER DELETE ON customer 119 | REFERENCING OLD AS ooo 120 | FOR EACH ROW 121 | MODE Db2SQL 122 | INSERT INTO customer_his 123 | VALUES (ooo.cust# 124 | , NULL 125 | , NULL 126 | , CURRENT TIMESTAMP 127 | , 'D' 128 | , USER 129 | , ooo.cust# 130 | , (SELECT MAX(cur_ts) 131 | FROM customer_his hhh 132 | WHERE ooo.cust# = hhh.cust#)); 133 | .... 134 | 135 | === Views 136 | 137 | We are now going to define a view that will let the user query the customer-history table – as if it were the ordinary customer table, but to look at the data as it was at any point in the past. To enable us to hide all the nasty SQL that is required to do this, we are going to ask that the user first enter a row into a profile table that has two columns: 138 | 139 | * The user's Db2 USER value. 140 | * The point in time at which the user wants to see the customer data. 141 | 142 | Here is the profile table definition: 143 | 144 | .Profile table 145 | [source,sql] 146 | .... 147 | CREATE TABLE profile 148 | ( user_id VARCHAR(10) NOT NULL 149 | , bgn_ts TIMESTAMP NOT NULL DEFAULT '9999-12-31-24.00.00' 150 | , PRIMARY KEY(user_id)); 151 | .... 152 | 153 | Below is a view that displays the customer data, as it was at the point in time represented by the timestamp in the profile table. The view shows all customer-history rows, as long as: 154 | 155 | * The action was not a delete. 156 | * The current-timestamp is <= the profile timestamp. 157 | * There does not exist any row that "replaces" the current row (and that row has a current timestamp that is <= to the profile timestamp). 158 | 159 | Now for the code: 160 | 161 | .View of Customer history 162 | [source,sql] 163 | .... 164 | CREATE VIEW customer_vw AS 165 | SELECT hhh.* 166 | , ppp.bgn_ts 167 | FROM customer_his hhh 168 | , profile ppp 169 | WHERE ppp.user_id = USER 170 | AND hhh.cur_ts <= ppp.bgn_ts 171 | AND hhh.cur_actn <> 'D' 172 | AND NOT EXISTS 173 | (SELECT * 174 | FROM customer_his nnn 175 | WHERE nnn.prv_cust# = hhh.cust# 176 | AND nnn.prv_ts = hhh.cur_ts 177 | AND nnn.cur_ts <= ppp.bgn_ts); 178 | .... 179 | 180 | The above sample schema shows just one table, but it can easily be extended to support every table is a very large application. One could even write some scripts to make the creation of the history tables, triggers, and views, all but automatic. 181 | 182 | === Limitations 183 | 184 | The above schema has the following limitations: 185 | 186 | * Every data table has to have a unique key. 187 | * The cost of every insert, update, and delete, is essentially doubled. 188 | * Data items that are updated very frequently (e.g. customer daily balance) may perform poorly when queried because many rows will have to be processed in order to find the one that has not been replaced. 189 | * The view uses the USER special register, which may not be unique per actual user. 190 | 191 | === Multiple Versions of the World 192 | 193 | The next design is similar to the previous, but we are also going to allow users to both see and change the world - as it was in the past, and as it is now, without affecting the real-world data. These extra features require a much more complex design: 194 | 195 | * We cannot use a base table and a related history table, as we did above. Instead we have just the latter, and use both views and INSTEAD OF triggers to make the users think that they are really seeing and/or changing the former. 196 | * We need a version table - to record when the data in each version (i.e. virtual copy of the real world) separates from the real world data. 197 | * Data integrity features, like referential integrity rules, have to be hand-coded in triggers, rather that written using standard Db2 code. 198 | 199 | ==== Version Table 200 | 201 | The following table has one row per version created: 202 | 203 | .Version table 204 | [source,sql] 205 | .... 206 | CREATE TABLE version 207 | ( vrsn INTEGER NOT NULL 208 | , vrsn_bgn_ts TIMESTAMP NOT NULL 209 | , CONSTRAINT version1 CHECK(vrsn >= 0) 210 | , CONSTRAINT version2 CHECK(vrsn < 1000000000) 211 | , PRIMARY KEY(vrsn)); 212 | .... 213 | 214 | The following rules apply to the above: 215 | 216 | * Each version has a unique number. Up to one billion can be created. 217 | * Each version must have a begin-timestamp, which records at what point in time it separates from the real world. This value must be <= the current time. 218 | * Rows cannot be updated or deleted in this table - only inserted. This rule is necessary to ensure that we can always trace all changes - in every version. 219 | * The real-world is deemed to have a version number of zero, and a begin-timestamp value of high-values. 220 | 221 | ==== Profile Table 222 | 223 | The following profile table has one row per user (i.e. USER special register) that reads from or changes the data tables. It records what version the user is currently using (note: the version timestamp data is maintained using triggers): 224 | 225 | .Profile table 226 | [source,sql] 227 | .... 228 | CREATE TABLE profile 229 | ( user_id VARCHAR(10) NOT NULL 230 | , vrsn INTEGER NOT NULL 231 | , vrsn_bgn_ts TIMESTAMP NOT NULL 232 | , CONSTRAINT profile1 FOREIGN KEY(vrsn) 233 | REFERENCES version(vrsn) 234 | ON DELETE RESTRICT 235 | , PRIMARY KEY(user_id)); 236 | .... 237 | 238 | ==== Customer (data) Table 239 | 240 | Below is a typical data table. This one holds customer data: 241 | 242 | .Customer table 243 | [source,sql] 244 | .... 245 | CREATE TABLE customer_his 246 | ( cust# INTEGER NOT NULL 247 | , cust_name CHAR(10) NOT NULL 248 | , cust_mgr CHAR(10) 249 | , cur_ts TIMESTAMP NOT NULL 250 | , cur_vrsn INTEGER NOT NULL 251 | , cur_actn CHAR(1) NOT NULL 252 | , cur_user VARCHAR(10) NOT NULL 253 | , prv_cust# INTEGER 254 | , prv_ts TIMESTAMP 255 | , prv_vrsn INTEGER 256 | , CONSTRAINT customer1 FOREIGN KEY(cur_vrsn) 257 | REFERENCES version(vrsn) 258 | ON DELETE RESTRICT 259 | , CONSTRAINT customer2 CHECK(cur_actn IN ('I','U','D')) 260 | , PRIMARY KEY(cust#,cur_vrsn,cur_ts)); 261 | 262 | CREATE INDEX customer_x2 263 | ON customer_his(prv_cust# 264 | , prv_ts 265 | , prv_vrsn); 266 | .... 267 | 268 | Note the following: 269 | 270 | * The first three fields are the only ones that the user will see. 271 | * The users will never update this table directly. They will make changes to a view of the table, which will then invoke INSTEAD OF triggers. 272 | * The foreign key check (on version) can be removed - if it is forbidden to ever delete any version. This check stops the removal of versions that have changed data. 273 | * The constraint on CUR_ACTN is just a double-check - to make sure that the triggers that will maintain this table do not have an error. It can be removed, if desired. 274 | * The secondary index will make the following view more efficient. 275 | 276 | The above table has the following hidden fields: 277 | 278 | * CUR-TS: The current timestamp of the change. 279 | * CUR-VRSN: The version in which change occurred. Zero implies reality. 280 | * CUR-ACTN: The type of change (i.e. insert, update, or delete). 281 | * CUR-USER: The user who made the change (for auditing purposes). 282 | * PRV-CUST#: The previous customer number. This field enables one follow the sequence of changes for a given customer. The value is null if the action is an insert. 283 | * PRV-TS: The timestamp of the last time the row was changed (null for inserts). 284 | * PRV-VRNS: The version of the row being replaced (null for inserts). 285 | 286 | ==== Views 287 | 288 | The following view displays the current state of the data in the above customer table – based on the version that the user is currently using: 289 | 290 | .Customer view - 1 of 2 291 | [source,sql] 292 | .... 293 | CREATE VIEW customer_vw AS 294 | SELECT * 295 | FROM customer_his hhh 296 | , profile ppp 297 | WHERE ppp.user_id = USER 298 | AND hhh.cur_actn <> 'D' 299 | AND ( (ppp.vrsn = 0 AND hhh.cur_vrsn = 0) 300 | OR (ppp.vrsn > 0 AND hhh.cur_vrsn = 0 AND hhh.cur_ts < ppp.vrsn_bgn_ts) 301 | OR (ppp.vrsn > 0 AND hhh.cur_vrsn = ppp.vrsn) 302 | ) 303 | AND NOT EXISTS 304 | (SELECT * 305 | FROM customer_his nnn 306 | WHERE nnn.prv_cust# = hhh.cust# 307 | AND nnn.prv_ts = hhh.cur_ts 308 | AND nnn.prv_vrsn = hhh.cur_vrsn 309 | AND ( (ppp.vrsn = 0 AND nnn.cur_vrsn = 0) 310 | OR (ppp.vrsn > 0 AND nnn.cur_vrsn = 0 AND nnn.cur_ts < ppp.vrsn_bgn_ts) 311 | OR (ppp.vrsn > 0 AND nnn.cur_vrsn = ppp.vrsn) 312 | ) 313 | ); 314 | .... 315 | 316 | The above view shows all customer rows, as long as: 317 | 318 | * The action was not a delete. 319 | * The version is either zero (i.e. reality), or the user's current version. 320 | * If the version is reality, then the current timestamp is < the version begin-timestamp (as duplicated in the profile table). 321 | * There does not exist any row that "replaces" the current row (and that row has a current timestamp that is <= to the profile (version) timestamp). 322 | 323 | To make things easier for the users, we will create another view that sits on top of the above view. This one only shows the business fields: 324 | 325 | .Customer view - 2 of 2 326 | [source,sql] 327 | .... 328 | CREATE VIEW customer AS 329 | SELECT cust# 330 | , cust_name 331 | , cust_mgr 332 | FROM customer_vw; 333 | .... 334 | 335 | All inserts, updates, and deletes, are done against the above view, which then propagates down to the first view, whereupon they are trapped by INSTEAD OF triggers. The changes are then applied (via the triggers) to the underlying tables. 336 | 337 | ==== Insert Trigger 338 | 339 | The following ((INSTEAD OF trigger)) traps all inserts to the first view above, and then applies the insert to the underlying table - with suitable modifications: 340 | 341 | .Insert trigger 342 | [source,sql] 343 | .... 344 | CREATE TRIGGER customer_ins 345 | INSTEAD OF INSERT ON customer_vw 346 | REFERENCING NEW AS nnn 347 | FOR EACH ROW 348 | MODE Db2SQL 349 | INSERT INTO customer_his 350 | VALUES(nnn.cust# 351 | , nnn.cust_name 352 | , nnn.cust_mgr 353 | , CURRENT TIMESTAMP 354 | , (SELECT vrsn 355 | FROM profile 356 | WHERE user_id = USER) 357 | , CASE 358 | WHEN 0 < (SELECT COUNT(*) 359 | FROM customer 360 | WHERE cust# = nnn.cust#) 361 | THEN RAISE_ERROR('71001','ERROR: Duplicate cust#') 362 | ELSE 'I' 363 | END 364 | , USER 365 | , NULL 366 | , NULL 367 | , NULL); 368 | .... 369 | 370 | Observe the following: 371 | 372 | * The basic customer data is passed straight through. 373 | * The current timestamp is obtained from Db2. 374 | * The current version is obtained from the user's profile-table row. 375 | * A check is done to see if the customer number is unique. One cannot use indexes to enforce such rules in this schema, so one has to code accordingly. 376 | * The previous fields are all set to null. 377 | 378 | ==== Update Trigger 379 | 380 | The following INSTEAD OF trigger traps all updates to the first view above, and turns them into an insert to the underlying table - with suitable modifications: 381 | 382 | .Update trigger 383 | [source,sql] 384 | .... 385 | CREATE TRIGGER customer_upd 386 | INSTEAD OF UPDATE ON customer_vw 387 | REFERENCING NEW AS nnn 388 | OLD AS ooo 389 | FOR EACH ROW 390 | MODE Db2SQL 391 | INSERT INTO customer_his 392 | VALUES (nnn.cust# 393 | , nnn.cust_name 394 | , nnn.cust_mgr 395 | , CURRENT TIMESTAMP 396 | , ooo.vrsn 397 | , CASE 398 | WHEN nnn.cust# <> ooo.cust# 399 | THEN RAISE_ERROR('72001','ERROR: Cannot change cust#') 400 | ELSE 'U' 401 | END 402 | , ooo.user_id 403 | , ooo.cust# 404 | , ooo.cur_ts 405 | , ooo.cur_vrsn); 406 | .... 407 | 408 | In this particular trigger, updates to the customer number (i.e. business key column) are not allowed. This rule is not necessary, it simply illustrates how one would write such code if one so desired. 409 | 410 | ==== Delete Trigger 411 | 412 | The following INSTEAD OF trigger traps all deletes to the first view above, and turns them into an insert to the underlying table - with suitable modifications: 413 | 414 | .Delete trigger 415 | [source,sql] 416 | .... 417 | CREATE TRIGGER customer_del 418 | INSTEAD OF DELETE ON customer_vw 419 | REFERENCING OLD AS ooo 420 | FOR EACH ROW 421 | MODE Db2SQL 422 | INSERT INTO customer_his 423 | VALUES (ooo.cust# 424 | , ooo.cust_name 425 | , ooo.cust_mgr 426 | , CURRENT TIMESTAMP 427 | , ooo.vrsn 428 | , 'D' 429 | , ooo.user_id 430 | , ooo.cust# 431 | , ooo.cur_ts 432 | , ooo.cur_vrsn); 433 | .... 434 | 435 | === Summary 436 | 437 | The only thing that the user need see in the above schema in the simplified (second) view that lists the business data columns. They would insert, update, and delete the rows in this view as if they were working on a real table. Under the covers, the relevant INSTEAD OF trigger would convert whatever they did into a suitable insert to the underlying table. 438 | 439 | This schema supports the following: 440 | 441 | * To do "what if" analysis, all one need do is insert a new row into the version table – with a begin timestamp that is the current time. This insert creates a virtual copy of every table in the application, which one can then update as desired. 442 | * To do historical analysis, one simply creates a version with a begin-timestamp that is at some point in the past. Up to 443 | one billion versions are currently supported. 444 | * To switch between versions, all one need do is update one's row in the profile table. 445 | * One can use recursive SQL (not shown here) to follow the sequence of changes to any particular item, in any particular version. 446 | 447 | This schema has the following limitations: 448 | 449 | * Every data table has to have a unique (business) key. 450 | * Data items that are updated very frequently (e.g. customer daily balance) may perform poorly when queried because many rows will have to be processed in order to find the one that has not been replaced. 451 | * The views use the USER special register, which may not be unique per actual user. 452 | * Data integrity features, like referential integrity rules, cascading deletes, and unique key checks, have to be hand-coded in the INSTEAD OF triggers. 453 | * Getting the triggers right is quite hard. If the target application has many tables, it might be worthwhile to first create a suitable data-dictionary, and then write a script that generates as much of the code as possible. 454 | 455 | 456 | -------------------------------------------------------------------------------- /chapters_asciidoc/23 Using SQL to Make SQL.asciidoc: -------------------------------------------------------------------------------- 1 | == Using SQL to Make SQL 2 | 3 | This chapter describes how to use SQL to make SQL. For example, one might want to make DDL statements to create views on a set of tables. 4 | 5 | === Export Command 6 | (((Export command))) 7 | The following query will generate a set of queries that will count the rows in each of the selected Db2 catalogue views: 8 | 9 | .Generate SQL to count rows 10 | [source,sql] 11 | .... 12 | SELECT 'SELECT COUNT(*) FROM ' 13 | CONCAT RTRIM(tabschema) 14 | CONCAT '.' 15 | CONCAT tabname 16 | CONCAT ';' 17 | FROM syscat.tables 18 | WHERE tabschema = 'SYSCAT' 19 | AND tabname LIKE 'N%' 20 | ORDER BY tabschema 21 | , tabname; 22 | .... 23 | 24 | _ANSWER_ 25 | 26 | .... 27 | SELECT COUNT(*) FROM SYSCAT.NAMEMAPPINGS; 28 | SELECT COUNT(*) FROM SYSCAT.NODEGROUPDEF; 29 | SELECT COUNT(*) FROM SYSCAT.NODEGROUPS; 30 | .... 31 | 32 | If we wrap the above inside an EXPORT statement, and define no character delimiter, we will be able to create a file with the above answer - and nothing else. This could in turn be run as if were some SQL statement that we had written: 33 | 34 | .Export generated SQL statements 35 | [source,sql] 36 | .... 37 | EXPORT TO C:\FRED.TXT OF DEL 38 | MODIFIED BY NOCHARDEL 39 | SELECT 'SELECT COUNT(*) FROM ' 40 | CONCAT RTRIM(tabschema) 41 | CONCAT '.' 42 | CONCAT tabname 43 | CONCAT ';' 44 | FROM syscat.tables 45 | WHERE tabschema = 'SYSCAT' 46 | AND tabname LIKE 'N%' 47 | ORDER BY tabschema 48 | , tabname; 49 | .... 50 | 51 | === Export Command Notes 52 | 53 | The key EXPORT options used above are: 54 | 55 | * The file name is "C\FRED.TXT". 56 | * The data is sent to a delimited (i.e. DEL) file. 57 | * The delimited output file uses no character delimiter (i.e. NOCHARDEL). 58 | 59 | The remainder of this chapter will assume that we are using the EXPORT command, and will describe various ways to generate more elaborate SQL statements. 60 | 61 | === SQL to Make SQL 62 | 63 | The next query is the same as the prior two, except that we have added the table name to each row of output: 64 | 65 | .Generate SQL to count rows 66 | [source,sql] 67 | .... 68 | SELECT 'SELECT ''' 69 | CONCAT tabname 70 | CONCAT ''', COUNT(*) FROM ' 71 | CONCAT RTRIM(tabschema) 72 | CONCAT '.' 73 | CONCAT tabname 74 | CONCAT ';' 75 | FROM syscat.tables 76 | WHERE tabschema = 'SYSCAT' 77 | AND tabname LIKE 'N%' 78 | ORDER BY tabschema 79 | , tabname; 80 | .... 81 | 82 | _ANSWER_ 83 | 84 | .... 85 | SELECT 'NAMEMAPPINGS', COUNT(*) FROM SYSCAT.NAMEMAPPINGS; 86 | SELECT 'NODEGROUPDEF', COUNT(*) FROM SYSCAT.NODEGROUPDEF; 87 | SELECT 'NODEGROUPS', COUNT(*) FROM SYSCAT.NODEGROUPS; 88 | .... 89 | 90 | We can make more readable output by joining the result set to four numbered rows, and then breaking the generated query down into four lines: 91 | 92 | .Generate SQL to count rows 93 | [source,sql] 94 | .... 95 | WITH temp1 (num) AS 96 | (VALUES (1), (2), (3), (4)) 97 | SELECT CASE num 98 | WHEN 1 THEN 'SELECT ''' || tabname || ''' AS tname' 99 | WHEN 2 THEN ' , COUNT(*)' || ' AS #rows' 100 | WHEN 3 THEN 'FROM ' || RTRIM(tabschema) || '.' || tabname || ';' 101 | WHEN 4 THEN '' 102 | END 103 | FROM syscat.tables 104 | , temp1 105 | WHERE tabschema = 'SYSCAT' 106 | AND tabname LIKE 'N%' 107 | ORDER BY tabschema 108 | , tabname 109 | , num; 110 | .... 111 | 112 | ANSWER 113 | 114 | [source,sql] 115 | .... 116 | SELECT 'NAMEMAPPINGS' AS tname 117 | , COUNT(*) AS #rows 118 | FROM SYSCAT.NAMEMAPPINGS; 119 | SELECT 'NODEGROUPDEF' AS tname 120 | , COUNT(*) AS #rows 121 | FROM SYSCAT.NODEGROUPDEF; 122 | SELECT 'NODEGROUPS' AS tname 123 | , COUNT(*) AS #rows 124 | FROM SYSCAT.NODEGROUPS; 125 | .... 126 | 127 | So far we have generated separate SQL statements for each table that matches. But imagine that instead we wanted to create a single statement that processed all tables. For example, we might want to know the sum of the rows in all of the matching tables. There are two ways to do this, but neither of them are very good: 128 | 129 | * We can generate a single large query that touches all of the matching tables. A query can be up to 2MB long, so we could reliably use this technique as long as we had less than about 5,000 tables to process. 130 | * We can declare a global temporary table, then generate insert statements (one per matching table) that insert a count of the rows in the table. After running the inserts, we can sum the counts in the temporary table. 131 | 132 | The next example generates a single query that counts all of the rows in the matching tables: 133 | 134 | .Generate SQL to count rows (all tables)_ 135 | [source,sql] 136 | .... 137 | WITH temp1 (num) AS 138 | (VALUES (1), (2), (3), (4)) 139 | SELECT CASE num 140 | WHEN 1 THEN 'SELECT SUM(C1)' 141 | when 2 then 'FROM (' 142 | WHEN 3 THEN 'SELECT COUNT(*) AS C1 FROM ' 143 | CONCAT RTRIM(tabschema) 144 | CONCAT '.' 145 | CONCAT tabname 146 | CONCAT CASE dd 147 | WHEN 1 THEN '' 148 | ELSE ' UNION ALL' 149 | END 150 | WHEN 4 THEN ') AS xxx;' 151 | END 152 | FROM (SELECT tab.* 153 | , ROW_NUMBER() OVER(ORDER BY tabschema ASC 154 | , tabname ASC) AS aa 155 | , ROW_NUMBER() OVER(ORDER BY tabschema DESC 156 | , tabname DESC) AS dd 157 | FROM syscat.tables tab 158 | WHERE tabschema = 'SYSCAT' 159 | AND tabname LIKE 'N%') AS xxx 160 | , emp1 161 | WHERE (num <= 2 AND aa = 1) 162 | OR (num = 3) 163 | OR (num = 4 AND dd = 1) 164 | ORDER BY tabschema ASC 165 | , tabname ASC 166 | , num ASC; 167 | .... 168 | 169 | ANSWER 170 | 171 | [source,sql] 172 | .... 173 | SELECT SUM(C1) 174 | FROM (SELECT COUNT(*) AS C1 FROM SYSCAT.NAMEMAPPINGS UNION ALL 175 | SELECT COUNT(*) AS C1 FROM SYSCAT.NODEGROUPDEF UNION ALL 176 | SELECT COUNT(*) AS C1 FROM SYSCAT.NODEGROUPS 177 | ) AS xxx; 178 | .... 179 | 180 | The above query works as follows: 181 | 182 | * A temporary table (i.e. temp1) is generated with one column and four rows. 183 | * A nested table expression (i.e. xxx) is created with the set of matching rows (tables). 184 | * Within the nested table expression the ROW_NUMBER function is used to define two new columns. The first will have the value 1 for the first matching row, and the second will have the value 1 for the last matching row. 185 | * The xxx and temp1 tables are joined. Two new rows (i.e. num <= 2) are added to the front, and one new row (i.e. num = 4) is added to the back. 186 | * The first two new rows (i.e. num = 1 and 2) are used to make the first part of the generated query. 187 | * The last new row (i.e. num = 4) is used to make the tail end of the generated query. 188 | * All other rows (i.e. num = 3) are used to create the core of the generated query. 189 | 190 | In the above query no SQL is generated if no rows (tables) match. 191 | Alternatively, we might want to generate a query that returns zero if no rows match. 192 | 193 | 194 | -------------------------------------------------------------------------------- /chapters_asciidoc/27 Time Travel.asciidoc: -------------------------------------------------------------------------------- 1 | [[time.travel]] 2 | == Time Travel 3 | (((Time travel))) 4 | 5 | This chapter gives an overview on the time travel feature in Db2. It is based on an article by Jan-Eike Michels and Matthias Nicola published on October 18, 2012 on developerWorks [https://www.ibm.com/developerworks/data/library/techarticle/dm-1210temporaltablesdb2/index.html]. 6 | 7 | We don't go that much into detail, just show you how it works. The basic idea is: sometimes you need to keep track on how the data changes over time in the database. While it is possible to track the changes using old database features like triggers (as described in the chapter <>), you will get a very robust solution utilizing the native features of the database. The database solution target two different scenarios: 8 | 9 | - track all the changes to data (System-period) and 10 | - track the validity of data for some time interval (Application-period). 11 | 12 | You can have both at the same time defined for one table (Db2 call this a "Bitemporal" table), i.e., you let the database keep track of all changes and at the same time manage the business validity of the data for you. 13 | 14 | To show time travel in action let's take a similar table as we used in chapter <>: 15 | 16 | .MyCustomer table 17 | [source,sql] 18 | .... 19 | CREATE TABLE mycustomer 20 | ( cust# INTEGER NOT NULL 21 | , cust_name CHAR(10) 22 | , cust_mgr CHAR(10) 23 | , PRIMARY KEY(cust#)); 24 | .... 25 | 26 | If you query this table you will always get one manager (the last one) for the customer. If you need to know who was the manager for this customer im some date in the past, you just cannot do it. If this is a need in our business, we can profit from the time travel feature. To implement it for this table we will need the following steps: 27 | 28 | * add new columns for the table (start, end and transaction) with the following characteristics: 29 | ** system_begin TIMESTAMP(12) NOT NULL GENERATED ALWAYS AS ROW BEGIN 30 | ** system_end TIMESTAMP(12) NOT NULL GENERATED ALWAYS AS ROW END 31 | ** trans_start TIMESTAMP(12) GENERATED ALWAYS AS TRANSACTION START ID 32 | * tell the table that this columns will manage the time slices when the data was active in the database: 33 | ** PERIOD SYSTEM_TIME (system_begin, system_end) 34 | * define a new table to save the history data: 35 | ** CREATE TABLE mycustomer_history LIKE customer 36 | * instruct the database management system to activate the time travel feature for this object: 37 | ** ALTER TABLE mycustomer ADD VERSIONING USE HISTORY TABLE mycustomer_history 38 | 39 | .DDL to implement the history for mycustomer 40 | [source,sql] 41 | .... 42 | ALTER TABLE mycustomer 43 | ADD COLUMN system_begin TIMESTAMP(12) NOT NULL GENERATED ALWAYS AS ROW BEGIN IMPLICITLY HIDDEN 44 | ADD COLUMN system_end TIMESTAMP(12) NOT NULL GENERATED ALWAYS AS ROW END IMPLICITLY HIDDEN 45 | ADD COLUMN trans_start TIMESTAMP(12) GENERATED ALWAYS AS TRANSACTION START ID 46 | ADD PERIOD SYSTEM_TIME (system_begin, system_end); 47 | 48 | CREATE TABLE mycustomer_history LIKE mycustomer; 49 | 50 | ALTER TABLE mycustomer ADD VERSIONING USE HISTORY TABLE mycustomer_history; 51 | .... 52 | 53 | Now suppose we have the following time line in our company: 54 | 55 | .Events time line for time travel 56 | [options="header",cols="20%,80%"] 57 | |=== 58 | |Date |Event 59 | |01.01.2019|First customer is registered in the database. Name: Customer. Manager: Mgr 1 60 | |01.07.2019|Second customer is registered in the database. Name: Customer2. Manager: Mgr 1 61 | |01.12.2019|Third customer is registered in the database. Name: Customer3. Manager: Mgr 2 62 | |12.01.2020|Fourth customer is registerd in the database. Name: Customer4. Manager: Mgr 3 63 | |15.01.2020|Fourth customer is deleted from the database. 64 | |16.01.2020|Name of first customer is changed from Customer to Customer1 65 | |17.01.2020|Manager of second customer is changed from Mgr 1 to Mgr 2 66 | |18.01.2020|Manager of third customer is changed from Mgr 2 to Mgr 3 67 | |=== 68 | 69 | Now let us select the current data from our table: 70 | .Select current data from table 71 | [source,sql] 72 | .... 73 | SELECT * 74 | FROM mycustomer; 75 | .... 76 | 77 | .Current data 78 | [options="header"] 79 | |=== 80 | |CUST#|CUST_NAME|CUST_MGR 81 | |1 |Customer1|Mgr 1 82 | |2 |Customer2|Mgr 2 83 | |3 |Customer3|Mgr 3 84 | |=== 85 | 86 | We don't see Customer4 because she was already deleted from the database. If we want to see the data as it was on 12.1.2020, we can do it! 87 | 88 | .Select table data as it was on 12.1.2020 89 | [source,sql] 90 | .... 91 | SELECT * 92 | FROM mycustomer 93 | FOR SYSTEM_TIME AS OF '2020-01-12' 94 | .... 95 | 96 | .Data on 12.1.2020 97 | [options="header"] 98 | |=== 99 | |CUST#|CUST_NAME|CUST_MGR 100 | |1 |Customer |Mgr 1 101 | |2 |Customer2|Mgr 1 102 | |3 |Customer3|Mgr 2 103 | |4 |Customer4|Mgr 3 104 | |=== 105 | 106 | All the changes were done after this date, so we see changes in every single record! Because we defined the columns SYSTEM_BEGIN and SYSTEM_END as IMPLICITLY HIDDEN, we don't get them in the result set. If we want to see them we need to explicitly code their names in our select statement: 107 | 108 | .Select table data as it was on 12.1.2020, show all columns 109 | [source,sql] 110 | .... 111 | SELECT cust#, cust_name, cust_mgr, system_begin, system_end 112 | FROM mycustomer 113 | FOR SYSTEM_TIME AS OF '2020-01-12' 114 | .... 115 | 116 | .Table data as it was on 12.1.2020, show all columns 117 | [options="header",cols="15%,20%,15%,25%,25%"] 118 | |=== 119 | |CUST#|CUST_NAME|CUST_MGR|SYSTEM_BEGIN |SYSTEM_END 120 | |1 |Customer |Mgr 1 |2019-01-01 00:00:00.0|2020-01-16 00:00:00.0 121 | |2 |Customer2|Mgr 1 |2019-07-01 00:00:00.0|2020-01-17 00:00:00.0 122 | |3 |Customer3|Mgr 2 |2019-12-01 00:00:00.0|2020-01-18 00:00:00.0 123 | |4 |Customer4|Mgr 3 |2020-01-12 00:00:00.0|2020-01-15 00:00:00.0 124 | |=== 125 | 126 | Because the content of SYSTEM_END is always different from the default value of a "ROW END" column in the base table ('9999-12-30 00:00:00.0'), we know that all data came from the history table! 127 | 128 | NOTE: In the first version of the time travel feature IBM used '9999-12-31 00:00:00.0' as default value for the row end. That worked fine when you didn't work in different time zones! This is the reason why it changed to 9999-12-30: to avoid overflows. 129 | 130 | The history table is a normal table and you can query it. If you want to show all the events in the table mycustomer, you could write the following query: 131 | 132 | .Select all events (all data) from both tables 133 | [source,sql] 134 | .... 135 | select 'myCustomer' as Tablename, cust#, cust_name, cust_mgr, system_begin, system_end 136 | from mycustomer 137 | union all 138 | select 'myCustomer_History', cust#, cust_name, cust_mgr, system_begin, system_end 139 | from mycustomer_history 140 | order by system_begin; 141 | .... 142 | 143 | .All table data, order by start of event 144 | [options="header"] 145 | |=== 146 | |TABLENAME |CUST#|CUST_NAME|CUST_MGR|SYSTEM_BEGIN |SYSTEM_END 147 | |myCustomer_History|1 |Customer |Mgr 1 |2019-01-01 00:00:00.0|2020-01-16 00:00:00.0 148 | |myCustomer_History|2 |Customer2|Mgr 1 |2019-07-01 00:00:00.0|2020-01-17 00:00:00.0 149 | |myCustomer_History|3 |Customer3|Mgr 2 |2019-12-01 00:00:00.0|2020-01-18 00:00:00.0 150 | |myCustomer_History|4 |Customer4|Mgr 3 |2020-01-12 00:00:00.0|2020-01-15 00:00:00.0 151 | |myCustomer |1 |Customer1|Mgr 1 |2020-01-16 00:00:00.0|9999-12-30 00:00:00.0 152 | |myCustomer |2 |Customer2|Mgr 2 |2020-01-17 00:00:00.0|9999-12-30 00:00:00.0 153 | |myCustomer |3 |Customer3|Mgr 3 |2020-01-18 00:00:00.0|9999-12-30 00:00:00.0 154 | |=== 155 | 156 | Now we can answer the question we posted at the beginning: who was the manager Customer2 on Christmas in year 2019? 157 | 158 | .Select Manager for a specific date 159 | [source,sql] 160 | .... 161 | select cust_name, cust_mgr 162 | FROM mycustomer 163 | FOR SYSTEM_TIME AS OF '2019-12-25' 164 | .... 165 | 166 | .Result for a specific date 167 | [options="header"] 168 | |=== 169 | |CUST_NAME|CUST_MGR 170 | |Customer |Mgr 1 171 | |Customer2|Mgr 1 172 | |Customer3|Mgr 2 173 | |=== 174 | 175 | Now if some customer is unsatisfied because she didn't get a xmas gift, you can blame the right person. 176 | 177 | -------------------------------------------------------------------------------- /chapters_asciidoc/927 Appendix.asciidoc: -------------------------------------------------------------------------------- 1 | == Appendix 2 | 3 | === Db2 Sample Tables 4 | (((Db2 sample tables))) 5 | Sample table DDL follows. 6 | 7 | ==== ACT 8 | 9 | .ACT sample table – DDL 10 | [source,sql] 11 | .... 12 | CREATE TABLE ACT 13 | ( ACTNO SMALLINT NOT NULL 14 | , ACTKWD CHARACTER(6) NOT NULL 15 | , ACTDESC VARCHAR(20) NOT NULL) 16 | IN USERSPACE1; 17 | 18 | ALTER TABLE ACT 19 | ADD CONSTRAINT PK_ACT PRIMARY KEY (ACTNO); 20 | 21 | CREATE UNIQUE INDEX XACT2 22 | ON ACT(ACTNO ASC, ACTKWD ASC) 23 | ALLOW REVERSE SCANS; 24 | .... 25 | 26 | ==== CATALOG 27 | 28 | .CATALOG sample table – DDL 29 | [source,sql] 30 | .... 31 | CREATE TABLE CATALOG 32 | ( NAME VARCHAR(128) NOT NULL 33 | , CATLOG XML) 34 | IN IBMDB2SAMPLEXML; 35 | 36 | ALTER TABLE CATALOG 37 | ADD CONSTRAINT PK_CATALOG PRIMARY KEY (NAME); 38 | .... 39 | 40 | ==== CL_SCHED 41 | 42 | .CL_SCHED sample table – DDL 43 | [source,sql] 44 | .... 45 | CREATE TABLE CL_SCHED 46 | ( CLASS_CODE CHARACTER(7) 47 | , DAY SMALLINT 48 | , STARTING TIME 49 | , ENDING TIME) 50 | IN USERSPACE1; 51 | .... 52 | 53 | ==== CUSTOMER 54 | 55 | .CUSTOMER sample table – DDL 56 | [source,sql] 57 | .... 58 | CREATE TABLE CUSTOMER 59 | ( CID BIGINT NOT NULL 60 | , INFO XML 61 | , HISTORY XML) 62 | IN IBMDB2SAMPLEXML; 63 | 64 | ALTER TABLE CUSTOMER 65 | ADD CONSTRAINT PK_CUSTOMER PRIMARY KEY(CID); 66 | .... 67 | 68 | ==== DATA_FILE_NAMES 69 | 70 | .DATA_FILE_NAMES sample table – DDL 71 | [source,sql] 72 | .... 73 | CREATE TABLE DATA_FILE_NAMES 74 | ( DATA_FILE_NAME VARCHAR(40) NOT NULL 75 | , DB2_TABLE_NAME VARCHAR(40) NOT NULL 76 | , EXPORT_FILE_NAM CHARACTER(8) NOT NULL) 77 | IN IBMDB2SAMPLEREL; 78 | .... 79 | 80 | ==== DEPARTMENT 81 | 82 | .DEPARTMENT sample table – DDL 83 | [source,sql] 84 | .... 85 | CREATE TABLE DEPARTMENT 86 | ( DEPTNO CHARACTER(3) NOT NULL 87 | , DEPTNAME VARCHAR(36) NOT NULL 88 | , MGRNO CHARACTER(6) 89 | , ADMRDEPT CHARACTER(3) NOT NULL 90 | , LOCATION CHARACTER(16)) 91 | IN USERSPACE1; 92 | 93 | ALTER TABLE DEPARTMENT 94 | ADD CONSTRAINT PK_DEPARTMENT PRIMARY KEY(DEPTNO); 95 | 96 | CREATE INDEX XDEPT2 97 | ON DEPARTMENT(MGRNO ASC) 98 | ALLOW REVERSE SCANS; 99 | 100 | CREATE INDEX XDEPT3 101 | ON DEPARTMENT(ADMRDEPT ASC) 102 | ALLOW REVERSE SCANS; 103 | 104 | CREATE ALIAS DEPT FOR DEPARTMENT; 105 | .... 106 | 107 | ==== EMPLOYEE 108 | 109 | .EMPLOYEE sample table – DDL 110 | [source,sql] 111 | .... 112 | CREATE TABLE EMPLOYEE 113 | ( EMPNO CHARACTER(6) NOT NULL 114 | , FIRSTNME VARCHAR(12) NOT NULL 115 | , MIDINIT CHARACTER(1) 116 | , LASTNAME VARCHAR(15) NOT NULL 117 | , WORKDEPT CHARACTER(3) 118 | , PHONENO CHARACTER(4) 119 | , HIREDATE DATE 120 | , JOB CHARACTER(8) 121 | , EDLEVEL SMALLINT NOT NULL 122 | , SEX CHARACTER(1) 123 | , BIRTHDATE DATE 124 | , SALARY DECIMAL(9, 2) 125 | , BONUS DECIMAL(9, 2) 126 | , COMM DECIMAL(9, 2)) 127 | IN USERSPACE1; 128 | 129 | ALTER TABLE EMPLOYEE 130 | ADD CONSTRAINT PK_EMPLOYEE PRIMARY KEY (EMPNO); 131 | 132 | CREATE INDEX XEMP2 133 | ON EMPLOYEE(WORKDEPT ASC) 134 | ALLOW REVERSE SCANS; 135 | 136 | CREATE ALIAS EMP FOR EMPLOYEE; 137 | .... 138 | 139 | ==== EMPMDC 140 | 141 | .EMPMDC sample table – DDL 142 | [source,sql] 143 | .... 144 | CREATE TABLE EMPMDC 145 | ( EMPNO INTEGER 146 | , DEPT INTEGER 147 | , DIV INTEGER) 148 | IN IBMDB2SAMPLEREL; 149 | .... 150 | 151 | ==== EMPPROJACT 152 | 153 | .EMPPROJACT sample table – DDL 154 | [source,sql] 155 | .... 156 | CREATE TABLE EMPPROJACT 157 | ( EMPNO CHARACTER(6) NOT NULL 158 | , PROJNO CHARACTER(6) NOT NULL 159 | , ACTNO SMALLINT NOT NULL 160 | , EMPTIME DECIMAL(5, 2) 161 | , EMSTDATE DATE 162 | , EMENDATE DATE) 163 | IN USERSPACE1; 164 | 165 | CREATE ALIAS EMP_ACT FOR EMPPROJACT; 166 | CREATE ALIAS EMPACT FOR EMPPROJACT; 167 | .... 168 | 169 | ==== EMP_PHOTO 170 | 171 | .EMP_PHOTO sample table – DDL 172 | [source,sql] 173 | .... 174 | CREATE TABLE EMP_PHOTO 175 | ( EMPNO CHARACTER(6) NOT NULL 176 | , PHOTO_FORMAT VARCHAR(10) NOT NULL 177 | , PICTURE BLOB(102400) 178 | , EMP_ROWID CHARACTER(40) NOT NULL) 179 | IN USERSPACE1; 180 | 181 | ALTER TABLE EMP_PHOTO 182 | ADD CONSTRAINT PK_EMP_PHOTO PRIMARY KEY(EMPNO, PHOTO_FORMAT); 183 | .... 184 | 185 | ==== EMP_RESUME 186 | 187 | .EMP_RESUME sample table – DDL 188 | [source,sql] 189 | .... 190 | CREATE TABLE EMP_RESUME 191 | ( EMPNO CHARACTER(6) NOT NULL 192 | , RESUME_FORMAT VARCHAR(10) NOT NULL 193 | , RESUME CLOB(5120) 194 | , EMP_ROWID CHARACTER(40) NOT NULL) 195 | IN USERSPACE1; 196 | 197 | ALTER TABLE EMP_RESUME 198 | ADD CONSTRAINT PK_EMP_RESUME PRIMARY KEY(EMPNO, RESUME_FORMAT); 199 | .... 200 | 201 | ==== IN_TRAY 202 | 203 | .IN_TRAY sample table – DDL 204 | [source,sql] 205 | .... 206 | CREATE TABLE IN_TRAY 207 | ( RECEIVED TIMESTAMP 208 | , SOURCE CHARACTER(8) 209 | , SUBJECT CHARACTER(64) 210 | , NOTE_TEXT VARCHAR(3000)) 211 | IN USERSPACE1; 212 | .... 213 | 214 | .INVENTORY sample table – DDL 215 | [source,sql] 216 | .... 217 | CREATE TABLE INVENTORY 218 | ( PID VARCHAR(10) NOT NULL 219 | , QUANTITY INTEGER 220 | , LOCATION VARCHAR(128)) 221 | IN IBMDB2SAMPLEXML; 222 | 223 | ALTER TABLE INVENTORY 224 | ADD CONSTRAINT PK_INVENTORY PRIMARY KEY(PID); 225 | .... 226 | 227 | ==== ORG 228 | 229 | .ORG sample table – DDL 230 | [source,sql] 231 | .... 232 | CREATE TABLE ORG 233 | ( DEPTNUMB SMALLINT NOT NULL 234 | , DEPTNAME VARCHAR(14) 235 | , MANAGER SMALLINT 236 | , DIVISION VARCHAR(10) 237 | , LOCATION VARCHAR(13)) 238 | IN USERSPACE1; 239 | .... 240 | 241 | ==== PRODUCT 242 | 243 | .PRODUCT sample table – DDL 244 | [source,sql] 245 | .... 246 | CREATE TABLE PRODUCT 247 | ( PID VARCHAR(10) NOT NULL 248 | , NAME VARCHAR(128) 249 | , PRICE DECIMAL(30,2) 250 | , PROMOPRICE DECIMAL(30, 2) 251 | , PROMOSTART DATE 252 | , PROMOEND DATE 253 | , DESCRIPTION XML) 254 | IN IBMDB2SAMPLEXML; 255 | 256 | ALTER TABLE PRODUCT 257 | ADD CONSTRAINT PK_PRODUCT PRIMARY KEY(PID); 258 | .... 259 | 260 | ==== PRODUCTSUPPLIER 261 | 262 | .PRODUCTSUPPLIER sample table – DDL 263 | [source,sql] 264 | .... 265 | CREATE TABLE PRODUCTSUPPLIER 266 | ( PID VARCHAR(10) NOT NULL 267 | , SID VARCHAR(10) NOT NULL) 268 | IN IBMDB2SAMPLEXML; 269 | .... 270 | 271 | ==== PROJACT 272 | 273 | .PROJACT sample table – DDL 274 | [source,sql] 275 | .... 276 | CREATE TABLE PROJACT 277 | ( PROJNO CHARACTER(6) NOT NULL 278 | , ACTNO SMALLINT NOT NULL 279 | , ACSTAFF DECIMAL(5, 2) 280 | , ACSTDATE DATE NOT NULL 281 | , ACENDATE DATE) 282 | IN USERSPACE1; 283 | 284 | ALTER TABLE PROJACT 285 | ADD CONSTRAINT PK_PROJACT PRIMARY KEY(PROJNO, ACTNO, ACSTDATE); 286 | .... 287 | 288 | ==== PROJECT 289 | 290 | .PROJECT sample table – DDL 291 | [source,sql] 292 | .... 293 | CREATE TABLE PROJECT 294 | ( PROJNO CHARACTER(6) NOT NULL 295 | , PROJNAME VARCHAR(24) NOT NULL 296 | , DEPTNO CHARACTER(3) NOT NULL 297 | , RESPEMP CHARACTER(6) NOT NULL 298 | , PRSTAFF DECIMAL(5, 2) 299 | , PRSTDATE DATE 300 | , PRENDATE DATE 301 | , MAJPROJ CHARACTER(6)) 302 | IN USERSPACE1; 303 | 304 | ALTER TABLE PROJECT 305 | ADD CONSTRAINT PK_PROJECT PRIMARY KEY(PROJNO); 306 | 307 | CREATE INDEX XPROJ2 308 | ON PROJECT(RESPEMP ASC) 309 | ALLOW REVERSE SCANS; 310 | 311 | CREATE ALIAS PROJ FOR PROJECT; 312 | .... 313 | 314 | ==== PURCHASEORDER 315 | 316 | .PURCHASEORDER sample table – DDL 317 | [source,sql] 318 | .... 319 | CREATE TABLE PURCHASEORDER 320 | ( POID BIGINT NOT NULL 321 | , STATUS VARCHAR(10) NOT NULL 322 | , CUSTID BIGINT 323 | , ORDERDATE DATE 324 | , PORDER XML 325 | , COMMENTS VARCHAR(1000)) 326 | IN IBMDB2SAMPLEXML; 327 | 328 | ALTER TABLE PURCHASEORDER 329 | ADD CONSTRAINT PK_PURCHASEORDER PRIMARY KEY(POID); 330 | .... 331 | 332 | ==== SALES 333 | 334 | .SALES sample table – DDL 335 | [source,sql] 336 | .... 337 | CREATE TABLE SALES 338 | ( SALES_DATE DATE 339 | , SALES_PERSON VARCHAR(15) 340 | , REGION VARCHAR(15) 341 | , SALES INTEGER) 342 | IN USERSPACE1; 343 | .... 344 | 345 | ==== STAFF 346 | 347 | .STAFF sample table – DDL 348 | [source,sql] 349 | .... 350 | CREATE TABLE STAFF 351 | ( ID SMALLINT NOT NULL 352 | , NAME VARCHAR(9) 353 | , DEPT SMALLINT 354 | , JOB CHARACTER(5) 355 | , YEARS SMALLINT 356 | , SALARY DECIMAL(7, 2) 357 | , COMM DECIMAL(7,2)) 358 | IN USERSPACE1; 359 | .... 360 | 361 | ==== SUPPLIERS 362 | 363 | .SUPPLIERS sample table – DDL 364 | [source,sql] 365 | .... 366 | CREATE TABLE SUPPLIERS 367 | ( SID VARCHAR(10) NOT NULL 368 | , ADDR XML) 369 | IN IBMDb2SAMPLEXML; 370 | 371 | ALTER TABLE SUPPLIERS 372 | ADD CONSTRAINT PK_PRODUCTSUPPLIER PRIMARY KEY(SID); 373 | .... 374 | 375 | 376 | -------------------------------------------------------------------------------- /chapters_asciidoc/928 Appendix 2 Graeme Birchall.asciidoc: -------------------------------------------------------------------------------- 1 | == Thank you, Graeme Birchall! 2 | 3 | This chapter contains the last introduction, history and comments from Graeme Birchall in his "Db2 SQL Cookbook". It is a kind of tribute to him and his work. 4 | 5 | Db2 LUW V9.7 SQL Cookbook 6 | Graeme Birchall 7 | 16-Aug-2011 8 | 9 | === Preface Important! 10 | 11 | If you didn't get this document directly from my personal website, you may have got an older edition. The book is changed very frequently, so if you want the latest, go to the source. Also, the latest edition is usually the best book to have, as the examples are often much better. 12 | This is true even if you are using an older version of Db2. This Cookbook is written for Db2 for LUW (i.e. Linux, Unix, Windows). It is not suitable for Db2 for z/OS unless you are running Db2 8 in new-function-mode, or (even better) Db2 9. 13 | 14 | === Acknowledgments 15 | 16 | I did not come up with all of the ideas presented in this book. Many of the best examples were provided by readers, friends, and/or coworkers too numerous to list. Thanks also to the many people at IBM for their (strictly unofficial) assistance. 17 | 18 | === Disclaimer & Copyright 19 | 20 | DISCLAIMER: This document is a best effort on my part. However, I screw up all the time, so it would be extremely unwise to trust the contents in its entirety. I certainly don't. And if you do something silly based on what I say, life is tough. COPYRIGHT: You can make as many copies of this book as you wish. And I encourage you to give it to others. But you cannot charge for it (other than to recover reproduction costs), nor claim the material as your own, nor replace my name with another. You are also encouraged to use the related class notes for teaching. In this case, you can charge for your time and materials - and your expertise. But you cannot charge any licensing fee, nor claim an exclusive right of use. In other words, you can pretty well do anything you want. And if you find the above too restrictive, just let me know. TRADEMARKS: Lots of words in this document, like "Db2", are registered trademarks of the IBM Corporation. Lots of other words, like "Windows", are registered trademarks of the Microsoft Corporation. 21 | Acrobat is a registered trademark of the Adobe Corporation. 22 | 23 | === Tools Used 24 | 25 | This book was written on a Dell PC that came with oodles of RAM. All testing was done in Db2 V9.7 Express-C for Windows. Word for Windows was used to write the document. Adobe Acrobat was used to make the PDF file. 26 | 27 | === Book Binding 28 | 29 | This book looks best when printed on a doubled sided laser printer and then suitably bound. To this end, I did some experiments a few years ago to figure out how to bind books cheaply using commonly available materials. I came up with what I consider to be a very satisfactory solution that is fully documented on <>. 30 | 31 | === Author / Book 32 | 33 | Author: Email: Graeme_Birchall@verizon.net 34 | Web: http://mysite.verizon.net/Graeme_Birchall/[http://mysite.verizon.net/Graeme_Birchall/] 35 | Title: Db2 9.7 SQL Cookbook 36 | © Date: 16-Aug-2011 37 | 38 | === Preface 39 | 40 | ==== Author 41 | 42 | ===== Notes Book History 43 | 44 | This book originally began a series of notes for my own use. After a while, friends began to ask for copies, and enemies started to steal it, so I decided to tidy everything up and give it away. Over the years, new chapters have been added as Db2 has evolved, and as I have found new ways to solve problems. Hopefully, this process will continue for the foreseeable future. 45 | 46 | [[why.free]] 47 | ==== Why Free 48 | 49 | This book is free because I want people to use it. The more people that use it, and the more that it helps them, the more inclined I am to keep it up to date. For these reasons, if you find this book to be useful, please share it with others. This book is free, rather than formally published, because I want to deliver the best product that I can. If I had a publisher, I would have the services of an editor and a graphic designer, but I would not be able to get to market so quickly, and when a product changes as quickly as Db2 does, timeliness is important. Also, giving it away means that I am under no pressure to make the book marketable. I simply include whatever I think might be useful. 50 | 51 | ==== Other Free Documents 52 | 53 | The following documents are also available for free from my web site: SAMPLE SQL: The complete text of the SQL statements in this Cookbook is available in an HTML file. Only the first and last few lines of the file have HTML tags, the rest is raw text, so it can easily be cut and paste into other files. 54 | CLASS OVERHEADS: Selected SQL examples from this book have been rewritten as class overheads. This enables one to use this material to teach Db2 SQL to others. Use this cookbook as the student notes. 55 | OLDER EDITIONS: This book is rewritten, and usually much improved, with each new version of Db2. Some of the older editions are available from my website. The others can be emailed upon request. However, the latest edition is the best, so you should probably use it, regardless of the version of Db2 that you have. 56 | 57 | ==== Answering Questions 58 | 59 | As a rule, I do not answer technical questions because I need to have a life. But I'm interested in hearing about interesting SQL problems, and also about any bugs in this book. However you may not get a prompt response, or any response. And if you are obviously an idiot, don't be surprised if I point out (for free, remember) that you are an idiot. 60 | 61 | ==== Software Whines 62 | 63 | This book is written using Microsoft Word for Windows. I've been using this software for many years, and it has generally been a bunch of bug-ridden junk. I do confess that it has been mildly more reliable in recent years. However, I could have written more than twice as much that was twice as good in half the time - if it weren't for all of the bugs in Word. 64 | 65 | Graeme 66 | 67 | [[graeme.birchall.book.editions]] 68 | ==== Graeme Birchall Book Editions Upload Dates 69 | 70 | [options="header",cols="30%,70%"] 71 | |=== 72 | |Date Published (Version) | Content 73 | |1996-05-08| First edition of the Db2 V2.1.1 SQL Cookbook was posted to my web site. This version was in Postscript Print File format. 74 | |1998-02-26| The Db2 V2.1.1 SQL Cookbook was converted to an Adobe Acrobat file and posted to my web site. Some minor cosmetic changes were made. 75 | |1998-08-19| First edition of Db2 UDB V5 SQL Cookbook posted. Every SQL statement was checked for V5, and there were new chapters on OUTER JOIN and GROUP BY. 76 | |1998-08-26| About 20 minor cosmetic defects were corrected in the V5 Cookbook. 77 | |1998-09-03| Another 30 or so minor defects were corrected in the V5 ookbook. 78 | |1998-10-24| The Cookbook was updated for Db2 UDB V5.2. 79 | |1998-10-25| About twenty minor typos and sundry cosmetic defects were fixed. 80 | |1998-12-03| This book was based on the second edition of the V5.2 upgrade. 81 | |1999-01-25| A chapter on Summary Tables (new in the Dec/98 fixpack) was added and all the SQL was checked for changes. 82 | |1999-01-28| Some more SQL was added to the new chapter on Summary Tables. 83 | |1999-02-15| The section of stopping recursive SQL statements was completely rewritten, and a new section was added on denormalizing hierarchical data structures. 84 | |1999-02-16| Minor editorial changes were made. 85 | |1999-03-16| Some bright spark at IBM pointed out that my new and improved section on stopping recursive SQL was all wrong. Damn. I undid everything. 86 | |1999-05-12| Minor editorial changes were made, and one new example (on getting multiple counts from one value) was added. |1999-09-16| Db2 V6.1 edition. All SQL was rechecked, and there were some minor additions - especially to summary tables, plus a chapter on "Db2 Dislikes". 87 | |1999-09-23| Some minor layout changes were made. 88 | |1999-10-06| Some bugs fixed, plus new section on index usage in summary tables. 89 | |2000-04-12| Some typos fixed, and a couple of new SQL tricks were added. 90 | |2000-09-19| Db2 V7.1 edition. All SQL was rechecked. The new areas covered are: OLAP functions (whole chapter), ISO functions, and identity columns. 91 | |2000-09-25| Some minor layout changes were made. 92 | |2000-10-26| More minor layout changes. 93 | |2001-01-03| Minor layout changes (to match class notes). 94 | |2001-02-06| Minor changes, mostly involving the RAND function. 95 | |2001-04-11| Document new features in latest fixpack. Also add a new chapter on Identity Columns and completely rewrite sub-query chapter. 96 | |2001-10-24| Db2 V7.2 fixpack 4 edition. Tested all SQL and added more examples, plus a new section on the aggregation function. 97 | |2002-03-11| Minor changes, mostly to section on precedence rules. 98 | |2002-08-20| Db2 V8.1 (beta) edition. A few new functions are added. New section on temporary tables. Identity Column and Join chapters rewritten. Whine chapter removed. 99 | |2003-01-02| Db2 V8.1 (post-Beta) edition. SQL rechecked. More examples added. 100 | |2003-07-11| New sections added on DML, temporary tables, compound SQL, and user defined functions. Halting recursion section changed to use ser-defined function. 101 | |2003-09-04| New sections on complex joins and history tables. 102 | |2003-10-02| Minor changes. Some more user-defined functions. 103 | |2003-11-20| Added "quick find" chapter. 104 | |2003-12-31| Tidied up the SQL in the Recursion chapter, and added a section on the merge statement. Completely rewrote the chapter on materialized query tables. 105 | |2004-02-04| Added select-from-DML section, and tidied up some code. Also managed to waste three whole days due to bugs in Microsoft Word. 106 | |2004-07-23| Rewrote chapter of identity column and sequences. Made DML separate chapter. Added chapters on protecting data and XML functions. Other minor changes. 107 | |2004-11-03| Upgraded to V8.2. Retested all SQL. Documented new SQL features. Some major hacking done on the GROUP BY chapter. 108 | |2005-04-15| Added short section on cursors, and a chapter on using SQL to make SQL. 109 | |2005-06-01| Added a chapter on triggers. 110 | |2005-11-11| Updated MQT table chapter and added bibliography. Other minor changes. 111 | |2005-12-01| Applied fixpack 10. Changed my website name. 112 | |2005-12-16| Added notes on isolation levels, data-type functions, transforming data. 113 | |2006-01-26| Fixed dumb bugs generated by WORD. What stupid software. Also wrote an awesome new section on joining meta-data to real data. 114 | |2006-02-17| Touched up the section on joining meta-data to real data. Other minor fixes. 115 | |2006-02-27| Added precedence rules for SQL statement processing, and a description of a simplified nested table expression. 116 | |2006-03-23| Added better solution to avoid fetching the same row twice. 117 | |2006-04-26| Added trigger that can convert HEX value to number. 118 | |2006-09-08| Upgraded to V9.1. Retested SQL. Removed the XML chapter as it is now obsolete. I'm still cogitating about XQuery. Looks hard. Added some awesome java code. 119 | |2006-09-13| Fixed some minor problems in the initial V9.1 book. 120 | |2006-10-17| Fixed a few cosmetic problems that were bugging me. 121 | |2006-11-06| Found out that IBM had removed the "UDB" from the Db2 product name, so I did the same. It is now just plain "Db2 V9". 122 | |2006-11-29| I goofed. Turns out Db2 is now called "Db2 9". I relabeled accordingly. 123 | |2006-12-15| Improved code to update or delete first "n" rows. 124 | |2007-02-22| Get unique timestamp values during multi-row insert. Other minor changes. 125 | |2007-11-20| Finished the Db2 V9.5 edition. Lots of changes! 126 | |2008-09-20| Fixed some minor problems. 127 | |2008-11-28| Fixed some minor problems. 128 | |2009-01-18| Fixed some minor problems, plus lots of bugs in Microsoft WORD! 129 | |2009-03-12| Converted to a new version of Adobe Acrobat, plus minor fixes. 130 | |2010-10-12| Finished initial V9.7 edition. Only minor changes. More to come. 131 | |2010-11-05| First batch of cute/deranged V9.7 SQL examples added. 132 | |2010-11-14| Fixed some minor typos. 133 | |2011-01-11| Added LIKE_COLUMN function. Removed bibliography. 134 | |2011-01-14| Added HASH function. Other minor edits. 135 | |2011-08-16| Fixed some minor problems. 136 | |=== 137 | 138 | [[book.binding]] 139 | === Book Binding 140 | 141 | Below is a quick-and-dirty technique for making a book out of this book. The object of the exercise is to have a manual that will last a long time, and that will also lie flat when opened up. All suggested actions are done at your own risk. 142 | 143 | ==== Tools Required 144 | 145 | * Printer, to print the book. 146 | * KNIFE, to trim the tape used to bind the book. 147 | * BINDER CLIPS, (1" size), to hold the pages together while gluing. To bind larger books, or to do multiple books in one go, use two or more cheap screw clamps. 148 | * CARDBOARD: Two pieces of thick card, to also help hold things together while gluing. 149 | 150 | ==== Consumables 151 | 152 | Ignoring the capital costs mentioned above, the cost of making a bound book should work out to about $4.00 per item, almost all of which is spent on the paper and toner. To bind an already printed copy should cost less than fifty cents. 153 | 154 | * PAPER and TONER, to print the book. 155 | * CARD STOCK, for the front and back covers. 156 | * GLUE, to bind the book. Cheap rubber cement will do the job. The glue must come with an applicator brush in the bottle. Sears hardware stores sell a more potent flavor called Duro Contact Cement that is quite a bit better. This is toxic stuff, so be careful. 157 | * CLOTH TAPE, (2" wide) to bind the spine. Pearl tape, available from Pearl stores, is fine. Wider tape will be required if you are not printing double-sided. 158 | * TIME: With practice, this process takes less than five minutes work per book. 159 | 160 | ==== Before you Start 161 | 162 | * Make that sure you have a well-ventilated space before gluing. 163 | * Practice binding on some old scraps of paper. 164 | * Kick all kiddies out off the room. 165 | 166 | ==== Instructions 167 | 168 | * Print the book - double-sided if you can. If you want, print the first and last pages on card stock to make suitable protective covers. 169 | * Jog the pages, so that they are all lined up along the inside spine. Make sure that every page is perfectly aligned, otherwise some pages won't bind. Put a piece of thick cardboard on either side of the set of pages to be bound. These will hold the pages tight during the gluing process. 170 | * Place binder clips on the top and bottom edges of the book (near the spine), to hold everything in place while you glue. One can also put a couple on the outside edge to stop the pages from splaying out in the next step. If the pages tend to spread out in the middle of the spine, put one in the centre of the spine, then work around it when gluing. Make sure there are no gaps between leafs, where the glue might soak in. 171 | * Place the book spine upwards. The objective here is to have a flat surface to apply the glue on. Lean the book against something if it does not stand up freely. 172 | * Put on gobs of glue. Let it soak into the paper for a bit, then put on some more. 173 | * Let the glue dry for at least half an hour. A couple of hours should be plenty. 174 | * Remove the binder clips that are holding the book together. Be careful because the glue does not have much structural strength. 175 | * Separate the cardboard that was put on either side of the book pages. To do this, carefully open the cardboard pages up (as if reading their inside covers), then run the knife down the glue between each board and the rest of the book. 176 | * Lay the book flat with the front side facing up. Be careful here because the rubber cement is not very strong. 177 | * Cut the tape to a length that is a little longer that the height of the book. 178 | * Put the tape on the book, lining it up so that about one quarter of an inch (of the tape width) is on the front side of the book. Press the tape down firmly (on the front side only) so that it is properly attached to the cover. Make sure that a little bit of tape sticks out of both the bottom and top ends of the spine. 179 | * Turn the book over (gently) and, from the rear side, wrap the cloth tape around the spine of the book. Pull the tape around so that it puts the spine under compression. 180 | * Trim excess tape at either end of the spine using a knife or pair of scissors. 181 | * Tap down the tape so that it is firmly attached to the book. 182 | * Let the book dry for a day. Then do the old "hold by a single leaf" test. Pick any page, and gently pull the page up into the air. The book should follow without separating from the page. 183 | 184 | ==== More Information 185 | 186 | The binding technique that I have described above is fast and easy, but rather crude. It would not be suitable if one was printing books for sale. There are plenty of other binding methods that take a little more skill and better gear that can be used to make "store-quality" books. Search the web for more information. 187 | 188 | 189 | 190 | -------------------------------------------------------------------------------- /chapters_asciidoc/998 References.asciidoc: -------------------------------------------------------------------------------- 1 | [bibliography] 2 | == References 3 | 4 | - [[[sql.reference]]] Db2 11.1 for Linux, UNIX, and Windows: SQL. IBM Corp. 1994, 2017 5 | 6 | 7 | -------------------------------------------------------------------------------- /chapters_asciidoc/999 Index.asciidoc: -------------------------------------------------------------------------------- 1 | [index] 2 | == Index 3 | 4 | Note: For technical reasons the index is only shown in the PDF format of this book. -------------------------------------------------------------------------------- /chapters_asciidoc/README.md: -------------------------------------------------------------------------------- 1 | # Content 2 | 3 | In this folder we save all chapters of the book. They are numbered and will come together as one document in the order of the numbers, i.e, the number of the file determines the order in the book. 4 | 5 | Writing conventions: 6 | + always write the text in English 7 | + keep it simple and stupid 8 | + use the Db2 sample database for your examples 9 | 10 | If you insert code, tag it as follows: 11 | 12 | [source, sql] 13 | .... 14 | SELECT ... 15 | .... 16 | 17 | If the output of your statements renders as a table, align all the columns to give them a better readability as text, for example: 18 | 19 | |=== 20 | |Column1 |Column2|Column3 21 | |ValueVeryLong |Val |- 22 | |=== 23 | 24 | If you want a concept, a word to come to the index, just put write it in double parenthesis: 25 | 26 | This is a ((word)) to index. 27 | 28 | ... more to come 29 | --------------------------------------------------------------------------------