├── DataCollectorTables.xlsx ├── LICENSE ├── README.md ├── bin ├── ahm_lag_alert.sh ├── load_vstb_tables.sh ├── purge_deleted_records.sh ├── update_statistics.sh └── vmart_vertica2vertica_parallel_load.bsh └── sql ├── ddl ├── setup_eeprof_views.sql ├── setup_vstb_tables.sql ├── setup_vstb_views_current.sql └── setup_vstb_views_historical.sql └── merge ├── load_vstb_tables.sql ├── purge_deleted_records.sql └── update_statistics.sql /DataCollectorTables.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/DougHarmon/v-sql-tb/9d7e6564c831c7119692a9812487ec780fcb36e4/DataCollectorTables.xlsx -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | GNU GENERAL PUBLIC LICENSE 2 | Version 2, June 1991 3 | 4 | Copyright (C) 1989, 1991 Free Software Foundation, Inc., 5 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA 6 | Everyone is permitted to copy and distribute verbatim copies 7 | of this license document, but changing it is not allowed. 8 | 9 | Preamble 10 | 11 | The licenses for most software are designed to take away your 12 | freedom to share and change it. By contrast, the GNU General Public 13 | License is intended to guarantee your freedom to share and change free 14 | software--to make sure the software is free for all its users. This 15 | General Public License applies to most of the Free Software 16 | Foundation's software and to any other program whose authors commit to 17 | using it. (Some other Free Software Foundation software is covered by 18 | the GNU Lesser General Public License instead.) You can apply it to 19 | your programs, too. 20 | 21 | When we speak of free software, we are referring to freedom, not 22 | price. Our General Public Licenses are designed to make sure that you 23 | have the freedom to distribute copies of free software (and charge for 24 | this service if you wish), that you receive source code or can get it 25 | if you want it, that you can change the software or use pieces of it 26 | in new free programs; and that you know you can do these things. 27 | 28 | To protect your rights, we need to make restrictions that forbid 29 | anyone to deny you these rights or to ask you to surrender the rights. 30 | These restrictions translate to certain responsibilities for you if you 31 | distribute copies of the software, or if you modify it. 32 | 33 | For example, if you distribute copies of such a program, whether 34 | gratis or for a fee, you must give the recipients all the rights that 35 | you have. You must make sure that they, too, receive or can get the 36 | source code. And you must show them these terms so they know their 37 | rights. 38 | 39 | We protect your rights with two steps: (1) copyright the software, and 40 | (2) offer you this license which gives you legal permission to copy, 41 | distribute and/or modify the software. 42 | 43 | Also, for each author's protection and ours, we want to make certain 44 | that everyone understands that there is no warranty for this free 45 | software. If the software is modified by someone else and passed on, we 46 | want its recipients to know that what they have is not the original, so 47 | that any problems introduced by others will not reflect on the original 48 | authors' reputations. 49 | 50 | Finally, any free program is threatened constantly by software 51 | patents. We wish to avoid the danger that redistributors of a free 52 | program will individually obtain patent licenses, in effect making the 53 | program proprietary. To prevent this, we have made it clear that any 54 | patent must be licensed for everyone's free use or not licensed at all. 55 | 56 | The precise terms and conditions for copying, distribution and 57 | modification follow. 58 | 59 | GNU GENERAL PUBLIC LICENSE 60 | TERMS AND CONDITIONS FOR COPYING, DISTRIBUTION AND MODIFICATION 61 | 62 | 0. This License applies to any program or other work which contains 63 | a notice placed by the copyright holder saying it may be distributed 64 | under the terms of this General Public License. The "Program", below, 65 | refers to any such program or work, and a "work based on the Program" 66 | means either the Program or any derivative work under copyright law: 67 | that is to say, a work containing the Program or a portion of it, 68 | either verbatim or with modifications and/or translated into another 69 | language. (Hereinafter, translation is included without limitation in 70 | the term "modification".) Each licensee is addressed as "you". 71 | 72 | Activities other than copying, distribution and modification are not 73 | covered by this License; they are outside its scope. The act of 74 | running the Program is not restricted, and the output from the Program 75 | is covered only if its contents constitute a work based on the 76 | Program (independent of having been made by running the Program). 77 | Whether that is true depends on what the Program does. 78 | 79 | 1. You may copy and distribute verbatim copies of the Program's 80 | source code as you receive it, in any medium, provided that you 81 | conspicuously and appropriately publish on each copy an appropriate 82 | copyright notice and disclaimer of warranty; keep intact all the 83 | notices that refer to this License and to the absence of any warranty; 84 | and give any other recipients of the Program a copy of this License 85 | along with the Program. 86 | 87 | You may charge a fee for the physical act of transferring a copy, and 88 | you may at your option offer warranty protection in exchange for a fee. 89 | 90 | 2. You may modify your copy or copies of the Program or any portion 91 | of it, thus forming a work based on the Program, and copy and 92 | distribute such modifications or work under the terms of Section 1 93 | above, provided that you also meet all of these conditions: 94 | 95 | a) You must cause the modified files to carry prominent notices 96 | stating that you changed the files and the date of any change. 97 | 98 | b) You must cause any work that you distribute or publish, that in 99 | whole or in part contains or is derived from the Program or any 100 | part thereof, to be licensed as a whole at no charge to all third 101 | parties under the terms of this License. 102 | 103 | c) If the modified program normally reads commands interactively 104 | when run, you must cause it, when started running for such 105 | interactive use in the most ordinary way, to print or display an 106 | announcement including an appropriate copyright notice and a 107 | notice that there is no warranty (or else, saying that you provide 108 | a warranty) and that users may redistribute the program under 109 | these conditions, and telling the user how to view a copy of this 110 | License. (Exception: if the Program itself is interactive but 111 | does not normally print such an announcement, your work based on 112 | the Program is not required to print an announcement.) 113 | 114 | These requirements apply to the modified work as a whole. If 115 | identifiable sections of that work are not derived from the Program, 116 | and can be reasonably considered independent and separate works in 117 | themselves, then this License, and its terms, do not apply to those 118 | sections when you distribute them as separate works. But when you 119 | distribute the same sections as part of a whole which is a work based 120 | on the Program, the distribution of the whole must be on the terms of 121 | this License, whose permissions for other licensees extend to the 122 | entire whole, and thus to each and every part regardless of who wrote it. 123 | 124 | Thus, it is not the intent of this section to claim rights or contest 125 | your rights to work written entirely by you; rather, the intent is to 126 | exercise the right to control the distribution of derivative or 127 | collective works based on the Program. 128 | 129 | In addition, mere aggregation of another work not based on the Program 130 | with the Program (or with a work based on the Program) on a volume of 131 | a storage or distribution medium does not bring the other work under 132 | the scope of this License. 133 | 134 | 3. You may copy and distribute the Program (or a work based on it, 135 | under Section 2) in object code or executable form under the terms of 136 | Sections 1 and 2 above provided that you also do one of the following: 137 | 138 | a) Accompany it with the complete corresponding machine-readable 139 | source code, which must be distributed under the terms of Sections 140 | 1 and 2 above on a medium customarily used for software interchange; or, 141 | 142 | b) Accompany it with a written offer, valid for at least three 143 | years, to give any third party, for a charge no more than your 144 | cost of physically performing source distribution, a complete 145 | machine-readable copy of the corresponding source code, to be 146 | distributed under the terms of Sections 1 and 2 above on a medium 147 | customarily used for software interchange; or, 148 | 149 | c) Accompany it with the information you received as to the offer 150 | to distribute corresponding source code. (This alternative is 151 | allowed only for noncommercial distribution and only if you 152 | received the program in object code or executable form with such 153 | an offer, in accord with Subsection b above.) 154 | 155 | The source code for a work means the preferred form of the work for 156 | making modifications to it. For an executable work, complete source 157 | code means all the source code for all modules it contains, plus any 158 | associated interface definition files, plus the scripts used to 159 | control compilation and installation of the executable. However, as a 160 | special exception, the source code distributed need not include 161 | anything that is normally distributed (in either source or binary 162 | form) with the major components (compiler, kernel, and so on) of the 163 | operating system on which the executable runs, unless that component 164 | itself accompanies the executable. 165 | 166 | If distribution of executable or object code is made by offering 167 | access to copy from a designated place, then offering equivalent 168 | access to copy the source code from the same place counts as 169 | distribution of the source code, even though third parties are not 170 | compelled to copy the source along with the object code. 171 | 172 | 4. You may not copy, modify, sublicense, or distribute the Program 173 | except as expressly provided under this License. Any attempt 174 | otherwise to copy, modify, sublicense or distribute the Program is 175 | void, and will automatically terminate your rights under this License. 176 | However, parties who have received copies, or rights, from you under 177 | this License will not have their licenses terminated so long as such 178 | parties remain in full compliance. 179 | 180 | 5. You are not required to accept this License, since you have not 181 | signed it. However, nothing else grants you permission to modify or 182 | distribute the Program or its derivative works. These actions are 183 | prohibited by law if you do not accept this License. Therefore, by 184 | modifying or distributing the Program (or any work based on the 185 | Program), you indicate your acceptance of this License to do so, and 186 | all its terms and conditions for copying, distributing or modifying 187 | the Program or works based on it. 188 | 189 | 6. Each time you redistribute the Program (or any work based on the 190 | Program), the recipient automatically receives a license from the 191 | original licensor to copy, distribute or modify the Program subject to 192 | these terms and conditions. You may not impose any further 193 | restrictions on the recipients' exercise of the rights granted herein. 194 | You are not responsible for enforcing compliance by third parties to 195 | this License. 196 | 197 | 7. If, as a consequence of a court judgment or allegation of patent 198 | infringement or for any other reason (not limited to patent issues), 199 | conditions are imposed on you (whether by court order, agreement or 200 | otherwise) that contradict the conditions of this License, they do not 201 | excuse you from the conditions of this License. If you cannot 202 | distribute so as to satisfy simultaneously your obligations under this 203 | License and any other pertinent obligations, then as a consequence you 204 | may not distribute the Program at all. For example, if a patent 205 | license would not permit royalty-free redistribution of the Program by 206 | all those who receive copies directly or indirectly through you, then 207 | the only way you could satisfy both it and this License would be to 208 | refrain entirely from distribution of the Program. 209 | 210 | If any portion of this section is held invalid or unenforceable under 211 | any particular circumstance, the balance of the section is intended to 212 | apply and the section as a whole is intended to apply in other 213 | circumstances. 214 | 215 | It is not the purpose of this section to induce you to infringe any 216 | patents or other property right claims or to contest validity of any 217 | such claims; this section has the sole purpose of protecting the 218 | integrity of the free software distribution system, which is 219 | implemented by public license practices. Many people have made 220 | generous contributions to the wide range of software distributed 221 | through that system in reliance on consistent application of that 222 | system; it is up to the author/donor to decide if he or she is willing 223 | to distribute software through any other system and a licensee cannot 224 | impose that choice. 225 | 226 | This section is intended to make thoroughly clear what is believed to 227 | be a consequence of the rest of this License. 228 | 229 | 8. If the distribution and/or use of the Program is restricted in 230 | certain countries either by patents or by copyrighted interfaces, the 231 | original copyright holder who places the Program under this License 232 | may add an explicit geographical distribution limitation excluding 233 | those countries, so that distribution is permitted only in or among 234 | countries not thus excluded. In such case, this License incorporates 235 | the limitation as if written in the body of this License. 236 | 237 | 9. The Free Software Foundation may publish revised and/or new versions 238 | of the General Public License from time to time. Such new versions will 239 | be similar in spirit to the present version, but may differ in detail to 240 | address new problems or concerns. 241 | 242 | Each version is given a distinguishing version number. If the Program 243 | specifies a version number of this License which applies to it and "any 244 | later version", you have the option of following the terms and conditions 245 | either of that version or of any later version published by the Free 246 | Software Foundation. If the Program does not specify a version number of 247 | this License, you may choose any version ever published by the Free Software 248 | Foundation. 249 | 250 | 10. If you wish to incorporate parts of the Program into other free 251 | programs whose distribution conditions are different, write to the author 252 | to ask for permission. For software which is copyrighted by the Free 253 | Software Foundation, write to the Free Software Foundation; we sometimes 254 | make exceptions for this. Our decision will be guided by the two goals 255 | of preserving the free status of all derivatives of our free software and 256 | of promoting the sharing and reuse of software generally. 257 | 258 | NO WARRANTY 259 | 260 | 11. BECAUSE THE PROGRAM IS LICENSED FREE OF CHARGE, THERE IS NO WARRANTY 261 | FOR THE PROGRAM, TO THE EXTENT PERMITTED BY APPLICABLE LAW. EXCEPT WHEN 262 | OTHERWISE STATED IN WRITING THE COPYRIGHT HOLDERS AND/OR OTHER PARTIES 263 | PROVIDE THE PROGRAM "AS IS" WITHOUT WARRANTY OF ANY KIND, EITHER EXPRESSED 264 | OR IMPLIED, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF 265 | MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE ENTIRE RISK AS 266 | TO THE QUALITY AND PERFORMANCE OF THE PROGRAM IS WITH YOU. SHOULD THE 267 | PROGRAM PROVE DEFECTIVE, YOU ASSUME THE COST OF ALL NECESSARY SERVICING, 268 | REPAIR OR CORRECTION. 269 | 270 | 12. IN NO EVENT UNLESS REQUIRED BY APPLICABLE LAW OR AGREED TO IN WRITING 271 | WILL ANY COPYRIGHT HOLDER, OR ANY OTHER PARTY WHO MAY MODIFY AND/OR 272 | REDISTRIBUTE THE PROGRAM AS PERMITTED ABOVE, BE LIABLE TO YOU FOR DAMAGES, 273 | INCLUDING ANY GENERAL, SPECIAL, INCIDENTAL OR CONSEQUENTIAL DAMAGES ARISING 274 | OUT OF THE USE OR INABILITY TO USE THE PROGRAM (INCLUDING BUT NOT LIMITED 275 | TO LOSS OF DATA OR DATA BEING RENDERED INACCURATE OR LOSSES SUSTAINED BY 276 | YOU OR THIRD PARTIES OR A FAILURE OF THE PROGRAM TO OPERATE WITH ANY OTHER 277 | PROGRAMS), EVEN IF SUCH HOLDER OR OTHER PARTY HAS BEEN ADVISED OF THE 278 | POSSIBILITY OF SUCH DAMAGES. 279 | 280 | END OF TERMS AND CONDITIONS 281 | 282 | How to Apply These Terms to Your New Programs 283 | 284 | If you develop a new program, and you want it to be of the greatest 285 | possible use to the public, the best way to achieve this is to make it 286 | free software which everyone can redistribute and change under these terms. 287 | 288 | To do so, attach the following notices to the program. It is safest 289 | to attach them to the start of each source file to most effectively 290 | convey the exclusion of warranty; and each file should have at least 291 | the "copyright" line and a pointer to where the full notice is found. 292 | 293 | {description} 294 | Copyright (C) {year} {fullname} 295 | 296 | This program is free software; you can redistribute it and/or modify 297 | it under the terms of the GNU General Public License as published by 298 | the Free Software Foundation; either version 2 of the License, or 299 | (at your option) any later version. 300 | 301 | This program is distributed in the hope that it will be useful, 302 | but WITHOUT ANY WARRANTY; without even the implied warranty of 303 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 304 | GNU General Public License for more details. 305 | 306 | You should have received a copy of the GNU General Public License along 307 | with this program; if not, write to the Free Software Foundation, Inc., 308 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 309 | 310 | Also add information on how to contact you by electronic and paper mail. 311 | 312 | If the program is interactive, make it output a short notice like this 313 | when it starts in an interactive mode: 314 | 315 | Gnomovision version 69, Copyright (C) year name of author 316 | Gnomovision comes with ABSOLUTELY NO WARRANTY; for details type `show w'. 317 | This is free software, and you are welcome to redistribute it 318 | under certain conditions; type `show c' for details. 319 | 320 | The hypothetical commands `show w' and `show c' should show the appropriate 321 | parts of the General Public License. Of course, the commands you use may 322 | be called something other than `show w' and `show c'; they could even be 323 | mouse-clicks or menu items--whatever suits your program. 324 | 325 | You should also get your employer (if you work as a programmer) or your 326 | school, if any, to sign a "copyright disclaimer" for the program, if 327 | necessary. Here is a sample; alter the names: 328 | 329 | Yoyodyne, Inc., hereby disclaims all copyright interest in the program 330 | `Gnomovision' (which makes passes at compilers) written by James Hacker. 331 | 332 | {signature of Ty Coon}, 1 April 1989 333 | Ty Coon, President of Vice 334 | 335 | This General Public License does not permit incorporating your program into 336 | proprietary programs. If your program is a subroutine library, you may 337 | consider it more useful to permit linking proprietary applications with the 338 | library. If this is what you want to do, use the GNU Lesser General 339 | Public License instead of this License. -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | v-sql-tb 2 | ========== 3 | 4 | Vertica SQL Toolbelt 5 | -------------------- 6 | Why is this needed? DBA's need to be able to: 7 | 8 | * Identify commonly used queries 9 | * Identify opportunities for SQL tuning 10 | * Identify resource utilization issues 11 | * Identify table/projection usage 12 | * Track table/projection disk space usage growth over time. 13 | 14 | Also, Developers and Data Architects may not have pseudosuperuser rights 15 | on the production database, but will want to know how their applications 16 | perform in production so that they can tune them. 17 | 18 | 19 | How is this done? 20 | ----------------- 21 | There are several monitoring tools that work with Linux/Vertica such as: 22 | 23 | * Management Console 24 | * Ganglia 25 | * Cacti 26 | 27 | This tool is designed to complement these monitoring tools. It creates a set of 28 | SQL tables to capture historical data from the v\_monitor and data collector tables. 29 | These tables are updated by SQL scripts, and a collection of diagnostic views 30 | sit on top of these tables to provide the DBA with insights into the Vertica database. 31 | 32 | Diagnostic Views 33 | ---------------- 34 | 35 | ###Current - Not sourced from history tables 36 | 37 | - **vProjectionUsage** 38 | - **vProjectionColumnSize** 39 | - **vRunningQueries** 40 | - **vLongRunningQueries** 41 | - **vQueryPlanProfiles** 42 | - **vMostCommonQueries** 43 | 44 | ###Historical - Combine current data with historical 45 | 46 | - **vProjectionSizeHistory** 47 | - **vProjectionUsageHistory** 48 | - **vLongRunningQueriesHistory** 49 | - **vProjectionGrowthOverTimeWeekly** 50 | 51 | 52 | Tables And Views Created in vstb schema 53 | --------------------------------------- 54 | 55 | ###Tables sourced from v_monitor schema 56 | 57 | - **execution\_engine\_profiles** 58 | - **query\_profiles** 59 | - **query\_plan\_profiles** 60 | - **query\_requests** 61 | - **query\_events** 62 | - **resource\_rejection\_details** 63 | - **user\_sessions** 64 | - **transactions** 65 | - **load\_streams** 66 | - **projection\_storage** 67 | - **projection\_usage** 68 | - **system\_resource\_usage** 69 | - **resource\_acquisitions** 70 | 71 | ###Tables sourced from Data Collector 72 | 73 | - **dc\_execution\_engine\_events** 74 | 75 | 76 | Directory Structure 77 | ------------------- 78 | 79 | - **/bin** - bash shell scripts, typically called through cron jobs 80 | - **/bin/ahm_lag_alert.sh** - raises an alert when ahm is 4 hours behind 81 | - **/bin/vmart_vertica2vertica_parallel_load.sh** - parallel loader for copying tables to Vertica from Vertica 82 | - **/sql** - sql scripts 83 | - **/sql/ddl** - one time setup (DDL) 84 | - **/sql/merge** - SQL scripts 85 | - **/sql/merge/load_vstb_tables.sql** - Loads historical tables in vstb schema 86 | - **/sql/merge/update_statistics.sql** - Updates stats on tables missing stats 87 | - **/sql/merge/purge_deleted_records.sql** - Purges deleted records from tables 88 | - **/log** - log files are stored here. You will need to create this. 89 | 90 | 91 | 92 | ## FAQ 93 | 94 | ###Why not modify the history retention parameter in the data collector tables? 95 | An alternative to creating custom history tables is to find the data collection 96 | table that make up the v_monitor objects and extend the history retention 97 | period for those tables. 98 | 99 | You can see how much history is retained in each data collector table by either 100 | querying the time field in each dc table or looking at this view: 101 | ``` 102 | SELECT * FROM v_monitor.data_collector ORDER BY 3,1; 103 | ``` 104 | 105 | You can use EXPLAIN to find the data collector tables used by each v_monitor table 106 | ``` 107 | EXPLAIN SELECT * FROM v_monitor.query_plan_profiles; 108 | ``` 109 | This package gives us the capability to save disk space by only capturing 110 | history for specific events. 111 | 112 | ###Why do you strip out carriage returns, line feeds and tabs from the query string? 113 | Stripping out these characters makes it possible to copy and paste the results 114 | into Excel using Excel's default parsing options. If we left those characters 115 | in then columns would be misaligned. You can reformat the SQL using an 116 | automated formatting tool such as the Poor Man's T-SQL Formatter 117 | plugin for notepad++. 118 | 119 | 120 | -------------------------------------------------------------------------------- /bin/ahm_lag_alert.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | #Monitor the lag in the Ancient History Mark (AHM) 3 | #If AHM >= $HOURS_BEHIND then send an email to $EMAIL_LIST 4 | export APPHOME=/home/dbadmin 5 | 6 | . $APPHOME/.bashrc 7 | 8 | 9 | export TODAY=$(date +%Y%m%d%H%M%S) 10 | 11 | 12 | #Parameters 13 | export HOURS_BEHIND=4 14 | export EMAIL_SENDER='admin_email@nospam.com' 15 | export EMAIL_LIST='user1@spamme.com,user2@spamme.com' 16 | export VSQL_HOST=localhost 17 | export VSQL_USER=dbadmin 18 | export VSQL_DATABASE=VMart 19 | 20 | export AHM_TIME=$(vsql -t -c 'SELECT GET_AHM_TIME()' | cut -c19-38) 21 | echo $AHM_TIME 22 | 23 | export CURRENT_TIME=$(vsql -t -c 'SELECT GETDATE()' | cut -c1-20) 24 | echo $CURRENT_TIME 25 | 26 | export LAG_HOURS=$(vsql -t -c "SELECT DATEDIFF(hour, '$AHM_TIME'::TIMESTAMP, GETDATE())") 27 | echo $LAG_HOURS 28 | 29 | 30 | 31 | if [ $LAG_HOURS -ge $HOURS_BEHIND ]; then 32 | /usr/sbin/sendmail "$EMAIL_LIST" < $LOGDIR/load_vstb_tables.${TODAY}.log 12 | -------------------------------------------------------------------------------- /bin/purge_deleted_records.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | export APPHOME=/home/dbadmin 4 | 5 | . $APPHOME/.bashrc 6 | 7 | export TODAY=$(date +%Y%m%d%H%M%S) 8 | export SQLDIR=$APPHOME/vstb/sql/merge 9 | export LOGDIR=$APPHOME/vstb/log 10 | export VSQLDIR=/opt/vertica/bin 11 | 12 | $VSQLDIR/vsql -f $SQLDIR/purge_deleted_records.sql > $LOGDIR/purge_deleted_records.${TODAY}.log 13 | -------------------------------------------------------------------------------- /bin/update_statistics.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | export APPHOME=/home/dbadmin 4 | 5 | . $APPHOME/.bashrc 6 | 7 | export TODAY=$(date +%Y%m%d%H%M%S) 8 | export SQLDIR=$APPHOME/vstb/sql/merge 9 | export LOGDIR=$APPHOME/vstb/log 10 | export VSQLDIR=/opt/vertica/bin 11 | 12 | $VSQLDIR/vsql -f $SQLDIR/update_statistics.sql > $LOGDIR/update_statistics.${TODAY}.log 13 | -------------------------------------------------------------------------------- /bin/vmart_vertica2vertica_parallel_load.bsh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | ################################################################################ 4 | # Parallel Loader for Vertica -- 5 | # Purpose: Loads data from one Vertica database to another using mutually 6 | # exclusive parallel streams. 7 | # Source Database is Vertica 8 | # Destination Database is Vertica 9 | # Secret Sauce: 10 | # 1. Parallel Load Streams 11 | # 2. Compress data via gzip on the source database server. 12 | # 13 | # For this demo we will use VMART 14 | # Create a destination table FT_Inventory in VMart through vsql: 15 | # CREATE TABLE FT_Inventory like public.inventory_fact including projections; 16 | # Script loads from public.inventory_fact into FT_Inventory 17 | # Set parameters appropriate for your database system 18 | ################################################################################ 19 | export TODAY=$(date +%Y%m%d%H%M%S) 20 | export VSQL_CLIENT=/opt/vertica/bin/vsql 21 | export START_TIME=$(vsql -t -c 'SELECT GETDATE()' | cut -c1-20) 22 | echo ${START_TIME} 23 | 24 | ################################################################################ 25 | # Source Database Parameters 26 | ################################################################################ 27 | export SHOST="localhost" 28 | export SDBNAME="VMart" 29 | export SUSER="dbadmin" 30 | export SPSWD="password" 31 | export VSQL_SRC=" -h "${SHOST}" -d "${SDBNAME}" -U "${SUSER}" -w "${SPSWD} 32 | 33 | ################################################################################ 34 | # Destination Database Parameters 35 | ################################################################################ 36 | export DHOST="localhost" 37 | export DDBNAME="VMart" 38 | export DUSER="dbadmin" 39 | export DPSWD="password" 40 | export VSQL_DST=" -h "${DHOST}" -d "${DDBNAME}" -U "${DUSER}" -w "${DPSWD} 41 | 42 | ################################################################################ 43 | # Define files and stream names 44 | ################################################################################ 45 | SQL_FILE_SRC="/tmp/dtl_src_"${TODAY} 46 | SQL_FILE_DST="/tmp/dtl_dst_"${TODAY} 47 | EXCEPTION_FILE="/tmp/exceptions_"${TODAY} 48 | REJECTION_FILE="/tmp/rejects_"${TODAY} 49 | STREAM_NAME="FT_Inv_"${TODAY} 50 | 51 | ################################################################################ 52 | # Build Load File 53 | ################################################################################ 54 | PARALLEL_STREAMS=4 55 | COUNTER=0 56 | 57 | 58 | while [ ${COUNTER} -lt ${PARALLEL_STREAMS} ]; do 59 | 60 | export EXTRACT_FILE=${SQL_FILE_SRC}"_"${COUNTER}".sql" 61 | echo "SELECT * FROM inventory_fact WHERE 1=1" >> ${EXTRACT_FILE} 62 | echo " AND MOD(HASH(date_key), "${PARALLEL_STREAMS}") = "${COUNTER}" ;" >> ${EXTRACT_FILE} 63 | 64 | export IMPORT_FILE=${SQL_FILE_DST}"_"${COUNTER}".sql" 65 | echo "COPY public.FT_Inventory FROM LOCAL STDIN GZIP DELIMITER E'\035' " > ${IMPORT_FILE} 66 | echo " EXCEPTIONS '"${EXCEPTION_FILE}"_"${COUNTER}".txt' " >> ${IMPORT_FILE} 67 | echo " REJECTED DATA '"${REJECTION_FILE}"_"${COUNTER}".txt' " >> ${IMPORT_FILE} 68 | echo " STREAM NAME '"${STREAM_NAME}"_"${COUNTER}"'" >> ${IMPORT_FILE} 69 | echo " DIRECT; " >> ${IMPORT_FILE} 70 | export IMPORT_STRING=$(cat ${IMPORT_FILE}) 71 | 72 | ${VSQL_CLIENT} ${VSQL_SRC} -F $'\035' -At -f ${EXTRACT_FILE} \ 73 | | gzip | \ 74 | ${VSQL_CLIENT} ${VSQL_DST} -c "${IMPORT_STRING}" & 75 | 76 | let COUNTER=COUNTER+1 77 | 78 | done 79 | 80 | wait 81 | 82 | export END_TIME=$(${VSQL_CLIENT} ${VSQL_DST} -t -c 'SELECT GETDATE()' | cut -c1-20) 83 | #echo ${END_TIME} 84 | 85 | export DURATION_SECONDS=$(${VSQL_CLIENT} ${VSQL_DST} -t -c\ 86 | "SELECT DATEDIFF(s, '{$START_TIME}'::TIMESTAMP, '{$END_TIME}'::TIMESTAMP);") 87 | #echo ${DURATION_SECONDS} 88 | 89 | 90 | ################################################################################ 91 | # Clean up by removing files. 92 | # Leave exception and reject files that contain data. 93 | ################################################################################ 94 | rm ${SQL_FILE_SRC}* 95 | rm ${SQL_FILE_DST}* 96 | find ${EXCEPTION_FILE}* -size 0 -print0 |xargs -0 rm 97 | find ${REJECTION_FILE}* -size 0 -print0 |xargs -0 rm 98 | 99 | ################################################################################ 100 | # Print Statistics 101 | ################################################################################ 102 | ${VSQL_CLIENT} ${VSQL_DST} -x \ 103 | -c "SELECT floor((1000*accepted_row_count/load_duration_ms)) AS RowsPerSecond, * "\ 104 | " FROM load_streams "\ 105 | " WHERE stream_name LIKE '"${STREAM_NAME}"%' ORDER BY stream_name DESC;" 106 | 107 | ${VSQL_CLIENT} ${VSQL_DST} \ 108 | -c "SELECT stream_name, floor((1000*accepted_row_count/load_duration_ms)) AS RowsPerSecond"\ 109 | " , accepted_row_count"\ 110 | " , floor(load_duration_ms/1000) load_duration_seconds"\ 111 | " , rejected_row_count"\ 112 | " FROM load_streams "\ 113 | " WHERE stream_name LIKE '"${STREAM_NAME}"%' "\ 114 | " UNION ALL"\ 115 | " SELECT ' TOTALS', floor(SUM(accepted_row_count+rejected_row_count)/${DURATION_SECONDS})"\ 116 | " ,SUM(accepted_row_count) accepted_row_count"\ 117 | " ,${DURATION_SECONDS} load_duration_seconds"\ 118 | " ,SUM(rejected_row_count) rejected_row_count"\ 119 | " FROM load_streams "\ 120 | " WHERE stream_name LIKE '"${STREAM_NAME}"%' ORDER BY 2 DESC ;" 121 | 122 | 123 | exit 124 | 125 | 126 | -------------------------------------------------------------------------------- /sql/ddl/setup_eeprof_views.sql: -------------------------------------------------------------------------------- 1 | -- Copyright (c) 2011 Vertica Systems, Inc. Billerica, Masschusetts USA 2 | 3 | -- Description: demo_eeprof_view.sql 4 | 5 | -- This example script is governed by the same terms as other utilities 6 | -- in /opt/vertica/scripts. See ‘Additional Terms for Vertica Support 7 | -- Utilities’ in the Vertica Software License. 8 | 9 | -- Create Date: 5/3/11 10 | 11 | -- The views included in this script assist with querying the execution_engine_profiles 12 | -- table. The views are created in the vstb schema which is not in the default search path. 13 | -- 14 | -- There is one view for each profiling counter -- for example eeprof_execution_time_us. 15 | -- Multiple profiling counter views can be easily joined together with "natural left outer join" 16 | -- where the leftmost view is a view that would include all operators such as eeprof_operators. 17 | -- 18 | -- The eeprof_execution_time_us_rank view provides an easy way to see the operators that 19 | -- have the highest execution times on each node. 20 | -- 21 | -- These views are not supported and may change in future releases. 22 | -- 23 | 24 | 25 | select add_vertica_options('BASIC', 'CREATE_SYSTEM_SCHEMA'); 26 | CREATE SCHEMA IF NOT EXISTS vstb; 27 | select clr_vertica_options('BASIC', 'CREATE_SYSTEM_SCHEMA'); 28 | 29 | -- one view per counter, phj counters are excluded 30 | 31 | CREATE OR REPLACE VIEW vstb.v_eeprof_bytes_received as 32 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 33 | counter_value as bytes_received, is_executing 34 | from execution_engine_profiles where counter_name = 'bytes received'; 35 | 36 | CREATE OR REPLACE VIEW vstb.v_eeprof_bytes_sent as 37 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 38 | counter_value as bytes_sent, is_executing 39 | from execution_engine_profiles where counter_name = 'bytes sent'; 40 | 41 | CREATE OR REPLACE VIEW vstb.v_eeprof_bytes_total as 42 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 43 | counter_value as bytes_total, is_executing 44 | from execution_engine_profiles where counter_name = 'bytes total'; 45 | 46 | CREATE OR REPLACE VIEW vstb.v_eeprof_clock_time_us as 47 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 48 | counter_value as clock_time_us, is_executing 49 | from execution_engine_profiles where counter_name = 'clock time (us)'; 50 | 51 | CREATE OR REPLACE VIEW vstb.v_eeprof_completed_merge_phases as 52 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 53 | counter_value as completed_merge_phases, is_executing 54 | from execution_engine_profiles where counter_name = 'completed merge phases'; 55 | 56 | CREATE OR REPLACE VIEW vstb.v_eeprof_cumulative_size_of_raw_temp_data_bytes as 57 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 58 | counter_value as cumulative_size_of_raw_temp_data_bytes, is_executing 59 | from execution_engine_profiles where counter_name = 'cumulative size of raw temp data (bytes)'; 60 | 61 | CREATE OR REPLACE VIEW vstb.v_eeprof_cumulative_size_of_temp_files_bytes as 62 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 63 | counter_value as cumulative_size_of_temp_files_bytes, is_executing 64 | from execution_engine_profiles where counter_name = 'cumulative size of temp files (bytes)'; 65 | 66 | CREATE OR REPLACE VIEW vstb.v_eeprof_current_size_of_temp_files_bytes as 67 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 68 | counter_value as current_size_of_temp_files_bytes, is_executing 69 | from execution_engine_profiles where counter_name = 'current size of temp files (bytes)'; 70 | 71 | CREATE OR REPLACE VIEW vstb.v_eeprof_execution_time_us as 72 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 73 | counter_value as execution_time_us, is_executing 74 | from execution_engine_profiles where counter_name = 'execution time (us)'; 75 | 76 | CREATE OR REPLACE VIEW vstb.v_eeprof_files_completed as 77 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 78 | counter_value as files_completed, is_executing 79 | from execution_engine_profiles where counter_name = 'files completed'; 80 | 81 | CREATE OR REPLACE VIEW vstb.v_eeprof_files_total as 82 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 83 | counter_value as files_total, is_executing 84 | from execution_engine_profiles where counter_name = 'files total'; 85 | 86 | CREATE OR REPLACE VIEW vstb.v_eeprof_input_queue_wait_us as 87 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 88 | counter_value as input_queue_wait_us, is_executing 89 | from execution_engine_profiles where counter_name = 'input queue wait (us)'; 90 | 91 | CREATE OR REPLACE VIEW vstb.v_eeprof_output_queue_wait_us as 92 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 93 | counter_value as output_queue_wait_us, is_executing 94 | from execution_engine_profiles where counter_name = 'output queue wait (us)'; 95 | 96 | CREATE OR REPLACE VIEW vstb.v_eeprof_read_bytes as 97 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 98 | counter_value as read_bytes, is_executing 99 | from execution_engine_profiles where counter_name = 'read_bytes'; 100 | 101 | CREATE OR REPLACE VIEW vstb.v_eeprof_receive_time_us as 102 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 103 | counter_value as receive_time_us, is_executing 104 | from execution_engine_profiles where counter_name = 'receive time (us)'; 105 | 106 | CREATE OR REPLACE VIEW vstb.v_eeprof_rows_produced as 107 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 108 | counter_value as rows_produced, is_executing 109 | from execution_engine_profiles where counter_name = 'rows produced'; 110 | 111 | CREATE OR REPLACE VIEW vstb.v_eeprof_estimated_rows_produced as 112 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 113 | counter_value as est_rows_produced, is_executing 114 | from execution_engine_profiles where counter_name = 'estimated rows produced'; 115 | 116 | CREATE OR REPLACE VIEW vstb.v_eeprof_rows_rejected as 117 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 118 | counter_value as rows_rejected, is_executing 119 | from execution_engine_profiles where counter_name = 'rows rejected'; 120 | 121 | CREATE OR REPLACE VIEW vstb.v_eeprof_send_time_us as 122 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 123 | counter_value as send_time_us, is_executing 124 | from execution_engine_profiles where counter_name = 'send time (us)'; 125 | 126 | CREATE OR REPLACE VIEW vstb.v_eeprof_total_merge_phases as 127 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 128 | counter_value as total_merge_phases, is_executing 129 | from execution_engine_profiles where counter_name = 'total merge phases'; 130 | 131 | CREATE OR REPLACE VIEW vstb.v_eeprof_WOS_bytes_acquired as 132 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 133 | counter_value as WOS_bytes_acquired, is_executing 134 | from execution_engine_profiles where counter_name = 'WOS bytes acquired'; 135 | 136 | CREATE OR REPLACE VIEW vstb.v_eeprof_WOS_bytes_written as 137 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 138 | counter_value as WOS_bytes_written, is_executing 139 | from execution_engine_profiles where counter_name = 'WOS bytes written'; 140 | 141 | CREATE OR REPLACE VIEW vstb.v_eeprof_memory_allocated_bytes as 142 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 143 | counter_value as memory_allocated_bytes, is_executing 144 | from execution_engine_profiles where counter_name = 'memory allocated (bytes)'; 145 | 146 | CREATE OR REPLACE VIEW vstb.v_eeprof_memory_reserved_bytes as 147 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 148 | counter_value as memory_reserved_bytes, is_executing 149 | from execution_engine_profiles where counter_name = 'memory reserved (bytes)'; 150 | 151 | CREATE OR REPLACE VIEW vstb.v_eeprof_file_handles as 152 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 153 | counter_value as file_handles, is_executing 154 | from execution_engine_profiles where counter_name = 'file handles'; 155 | 156 | CREATE OR REPLACE VIEW vstb.v_eeprof_written_rows as 157 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 158 | counter_value as written_rows, is_executing 159 | from execution_engine_profiles where counter_name = 'written rows'; 160 | 161 | CREATE OR REPLACE VIEW vstb.v_eeprof_chunk_longest_scan as 162 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 163 | counter_value as chunk_longest_scan, is_executing 164 | from execution_engine_profiles where counter_name = 'chunk longest scan'; 165 | 166 | CREATE OR REPLACE VIEW vstb.v_eeprof_chunk_rows_scanned_squared as 167 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 168 | counter_value as chunk_rows_scanned_squared, is_executing 169 | from execution_engine_profiles where counter_name = 'chunk rows scanned squared'; 170 | 171 | CREATE OR REPLACE VIEW vstb.v_eeprof_chunk_scans_run as 172 | select node_name, session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, 173 | counter_value as chunk_scans_run, is_executing 174 | from execution_engine_profiles where counter_name = 'chunk scans run'; 175 | 176 | 177 | 178 | -- view to get distinct operators 179 | 180 | CREATE OR REPLACE VIEW vstb.v_eeprof_operators as 181 | select distinct node_name, 182 | session_id, transaction_id, statement_id, operator_name, operator_id, path_id, baseplan_id, is_executing from execution_engine_profiles; 183 | 184 | -- view to combine all counter views into a single view 185 | 186 | CREATE OR REPLACE VIEW vstb.v_eeprof_counters as 187 | select to_hex(v_eeprof_operators.transaction_id) transaction_id_hex, * from 188 | vstb.v_eeprof_operators natural left outer join 189 | vstb.v_eeprof_bytes_received natural left outer join 190 | vstb.v_eeprof_bytes_sent natural left outer join 191 | vstb.v_eeprof_bytes_total natural left outer join 192 | vstb.v_eeprof_clock_time_us natural left outer join 193 | vstb.v_eeprof_completed_merge_phases natural left outer join 194 | vstb.v_eeprof_cumulative_size_of_raw_temp_data_bytes natural left outer join 195 | vstb.v_eeprof_cumulative_size_of_temp_files_bytes natural left outer join 196 | vstb.v_eeprof_current_size_of_temp_files_bytes natural left outer join 197 | vstb.v_eeprof_execution_time_us natural left outer join 198 | vstb.v_eeprof_files_completed natural left outer join 199 | vstb.v_eeprof_files_total natural left outer join 200 | vstb.v_eeprof_input_queue_wait_us natural left outer join 201 | vstb.v_eeprof_output_queue_wait_us natural left outer join 202 | vstb.v_eeprof_read_bytes natural left outer join 203 | vstb.v_eeprof_receive_time_us natural left outer join 204 | vstb.v_eeprof_rows_produced natural left outer join 205 | vstb.v_eeprof_estimated_rows_produced natural left outer join 206 | vstb.v_eeprof_rows_rejected natural left outer join 207 | vstb.v_eeprof_send_time_us natural left outer join 208 | vstb.v_eeprof_total_merge_phases natural left outer join 209 | vstb.v_eeprof_WOS_bytes_acquired natural left outer join 210 | vstb.v_eeprof_WOS_bytes_written natural left outer join 211 | vstb.v_eeprof_memory_allocated_bytes natural left outer join 212 | vstb.v_eeprof_memory_reserved_bytes natural left outer join 213 | vstb.v_eeprof_file_handles natural left outer join 214 | vstb.v_eeprof_written_rows natural left outer join 215 | vstb.v_eeprof_chunk_longest_scan natural left outer join 216 | vstb.v_eeprof_chunk_rows_scanned_squared natural left outer join 217 | vstb.v_eeprof_chunk_scans_run; 218 | 219 | 220 | -- other helper views 221 | 222 | -- operators sorted by execution time, grouped by node, and including row counts, 223 | -- would typically use with "ORDER BY node_name, rk" and a predicate for a specific 224 | -- transaction_id and statement_id 225 | 226 | CREATE OR REPLACE VIEW vstb.v_eeprof_execution_time_us_rank as 227 | select rank() over (partition by transaction_id, statement_id, node_name 228 | order by execution_time_us desc) rk, transaction_id, statement_id, node_name, operator_name, operator_id, path_id, baseplan_id, execution_time_us, rows_produced, is_executing 229 | from (select * from vstb.v_eeprof_execution_time_us natural left outer join vstb.v_eeprof_rows_produced) q; 230 | 231 | -- operators sorted by clock time, grouped by node, and including row counts, 232 | -- would typically use with "ORDER BY node_name, rk" and a predicate for a specific 233 | -- transaction_id and statement_id 234 | 235 | CREATE OR REPLACE VIEW vstb.v_eeprof_clock_time_us_rank as 236 | select rank() over (partition by transaction_id, statement_id, node_name 237 | order by clock_time_us desc) rk, transaction_id, statement_id, node_name, operator_name, operator_id, path_id, baseplan_id, clock_time_us, rows_produced, is_executing 238 | from (select * from vstb.v_eeprof_clock_time_us natural left outer join vstb.v_eeprof_rows_produced) q; 239 | 240 | 241 | --- what parts of each query execution consumed time (aka pivot) 242 | CREATE OR REPLACE VIEW vstb.v_query_execution_breakdown 243 | AS 244 | SELECT 245 | plan_step.time as start_time, 246 | plan_step.node_name as node_name, 247 | plan_step.transaction_id as transaction_id, 248 | plan_step.statement_id as stmt_id, 249 | plan_step.request_id as req_id, 250 | request.duration as overall_duration, 251 | plan_step.duration as plan_duration, 252 | populatevproj_step.duration as popvproj_duration, 253 | serialize_step.duration as serialize_duration, 254 | prepareplan_step.duration as prepareplan_duration, 255 | --pp_tablelocks.duration as pp_tablelocks_duration, 256 | --pp_distplanner.duration as pp_distplanner_duration, 257 | --pp_localplan.duration as pp_localplan_duration, 258 | --pp_eecompile.duration as pp_eecompile_duration, 259 | compileplan_step.duration as compileplan_duration, 260 | executeplan_step.duration as executeplan_duration, 261 | (request.duration - 262 | nvl(plan_step.duration, '0'::interval) - 263 | nvl(populatevproj_step.duration, '0'::interval) - 264 | nvl(serialize_step.duration, '0'::interval) - 265 | nvl(prepareplan_step.duration, '0'::interval) - 266 | nvl(compileplan_step.duration, '0'::interval) - 267 | nvl(executeplan_step.duration, '0'::interval)) as unaccounted_for_duration, 268 | request.request as request, 269 | request.request_type as request_type, 270 | errors.message as error_message 271 | 272 | FROM 273 | ( SELECT 274 | node_name, transaction_id, statement_id, request_id, 275 | time, 276 | completion_time - time as duration 277 | FROM dc_query_executions 278 | WHERE execution_step = 'Plan' 279 | ) as plan_step 280 | LEFT JOIN 281 | ( SELECT 282 | node_name, transaction_id, statement_id, request_id, 283 | completion_time - time as duration 284 | FROM dc_query_executions 285 | WHERE execution_step = 'PopulateVirtualProjection' 286 | ) as populatevproj_step 287 | USING ( node_name, transaction_id, statement_id, request_id) 288 | LEFT JOIN 289 | ( SELECT 290 | node_name, transaction_id, statement_id, request_id, 291 | completion_time - time as duration 292 | FROM dc_query_executions 293 | WHERE execution_step = 'SerializePlan' 294 | ) as serialize_step 295 | USING ( node_name, transaction_id, statement_id, request_id) 296 | LEFT JOIN 297 | ( SELECT 298 | node_name, transaction_id, statement_id, request_id, 299 | completion_time - time as duration 300 | FROM dc_query_executions 301 | WHERE execution_step = 'PreparePlan' 302 | ) as prepareplan_step 303 | USING ( node_name, transaction_id, statement_id, request_id) 304 | LEFT JOIN 305 | ( SELECT 306 | node_name, transaction_id, statement_id, request_id, 307 | completion_time - time as duration 308 | FROM dc_query_executions 309 | WHERE execution_step = 'CompilePlan' 310 | ) as compileplan_step 311 | USING ( node_name, transaction_id, statement_id, request_id) 312 | LEFT JOIN 313 | ( SELECT 314 | node_name, transaction_id, statement_id, request_id, 315 | completion_time - time as duration 316 | FROM dc_query_executions 317 | WHERE execution_step = 'ExecutePlan' 318 | ) as executeplan_step 319 | USING ( node_name, transaction_id, statement_id, request_id) 320 | LEFT JOIN 321 | ( SELECT 322 | node_name, transaction_id, statement_id, request_id, 323 | completion_time - time as duration 324 | FROM dc_query_executions 325 | WHERE execution_step = 'PreparePlan:TakeTableLocks' 326 | ) as pp_tablelocks 327 | USING ( node_name, transaction_id, statement_id, request_id) 328 | LEFT JOIN 329 | ( SELECT 330 | node_name, transaction_id, statement_id, request_id, 331 | completion_time - time as duration 332 | FROM dc_query_executions 333 | WHERE execution_step = 'PreparePlan:DistPlanner' 334 | ) as pp_distplanner 335 | USING ( node_name, transaction_id, statement_id, request_id) 336 | LEFT JOIN 337 | ( SELECT 338 | node_name, transaction_id, statement_id, request_id, 339 | completion_time - time as duration 340 | FROM dc_query_executions 341 | WHERE execution_step = 'PreparePlan:LocalPlan' 342 | ) as pp_localplan 343 | USING ( node_name, transaction_id, statement_id, request_id) 344 | LEFT JOIN 345 | ( SELECT 346 | node_name, transaction_id, statement_id, request_id, 347 | completion_time - time as duration 348 | FROM dc_query_executions 349 | WHERE execution_step = 'PreparePlan:EEcompile' 350 | ) as pp_eecompile 351 | USING ( node_name, transaction_id, statement_id, request_id) 352 | JOIN -- subquery to get part of the query that was requested. Actual query text is truncated. 353 | ( SELECT 354 | dri.node_name, dri.transaction_id, dri.statement_id, dri.request_id, 355 | drc.time - dri.time as duration, 356 | dri.request_type, 357 | replace(substr(dri.request,1,50), E'\n', ' ') as request 358 | FROM dc_requests_issued dri 359 | JOIN dc_requests_completed drc 360 | USING (node_name, session_id, request_id) 361 | ) as request 362 | USING ( node_name, transaction_id, statement_id, request_id) 363 | LEFT JOIN 364 | ( SELECT node_name, transaction_id, statement_id, request_id, 365 | max(message) as message 366 | FROM dc_errors 367 | GROUP BY 1,2,3,4 -- ensure only a single error message 368 | ) as errors 369 | USING ( node_name, transaction_id, statement_id, request_id) 370 | ORDER BY plan_step.time 371 | ; 372 | -------------------------------------------------------------------------------- /sql/ddl/setup_vstb_tables.sql: -------------------------------------------------------------------------------- 1 | --============================================================================= 2 | -- Objective: Monitor Query Activity, System Performance, and Space Usage 3 | -- over time 4 | --============================================================================= 5 | --============================================================================= 6 | -- Create the v_monitor_history schema 7 | --============================================================================= 8 | CREATE SCHEMA vstb; 9 | 10 | --============================================================================= 11 | -- Create the v_monitor table structures 12 | -- execution_engine_profiles 13 | -- query_profiles 14 | -- query_plan_profiles 15 | -- query_requests 16 | -- query_events 17 | -- resource_rejection_details 18 | -- user_sessions 19 | -- transactions 20 | -- load_streams 21 | -- projection_storage 22 | -- projection_usage 23 | -- system_resource_usage 24 | -- resource_acquisitions 25 | -- Create the data collector table structures 26 | -- dc_execution_engine_events 27 | --============================================================================= 28 | DROP TABLE IF EXISTS vstb.execution_engine_profiles CASCADE; 29 | 30 | CREATE TABLE vstb.execution_engine_profiles ( 31 | node_name VARCHAR(128) ENCODING RLE 32 | ,user_id INT ENCODING RLE 33 | ,user_name VARCHAR(128) ENCODING RLE 34 | ,session_id VARCHAR(128) ENCODING RLE 35 | ,transaction_id INT ENCODING DELTARANGE_COMP 36 | ,statement_id INT ENCODING RLE 37 | ,plan_id INT ENCODING BLOCKDICT_COMP 38 | ,operator_name VARCHAR(128) ENCODING RLE 39 | ,operator_id INT ENCODING COMMONDELTA_COMP 40 | ,baseplan_id INT ENCODING COMMONDELTA_COMP 41 | ,path_id INT ENCODING COMMONDELTA_COMP 42 | ,localplan_id INT ENCODING COMMONDELTA_COMP 43 | ,activity_id INT ENCODING DELTARANGE_COMP 44 | ,resource_id INT ENCODING RLE 45 | ,counter_name VARCHAR(128) ENCODING AUTO 46 | ,counter_tag VARCHAR(128) ENCODING AUTO 47 | ,counter_value INT ENCODING DELTARANGE_COMP 48 | ,is_executing boolean ENCODING RLE 49 | ) 50 | ORDER BY transaction_id 51 | ,node_name 52 | ,user_id 53 | ,user_name 54 | ,session_id 55 | ,statement_id 56 | ,plan_id 57 | ,operator_name 58 | ,operator_id 59 | ,baseplan_id 60 | ,path_id 61 | ,localplan_id 62 | ,activity_id 63 | ,resource_id 64 | ,counter_name 65 | ,counter_tag 66 | ,counter_value 67 | ,is_executing 68 | SEGMENTED BY HASH (transaction_id) ALL NODES; 69 | 70 | DROP TABLE IF EXISTS vstb.query_profiles CASCADE; 71 | 72 | CREATE TABLE vstb.query_profiles ( 73 | session_id VARCHAR(128) ENCODING AUTO 74 | ,transaction_id INT ENCODING COMMONDELTA_COMP 75 | ,statement_id INT ENCODING COMMONDELTA_COMP 76 | ,identifier VARCHAR(128) ENCODING RLE 77 | ,node_name VARCHAR(128) ENCODING RLE 78 | ,query VARCHAR(64000) ENCODING AUTO 79 | ,query_search_path VARCHAR(64000) ENCODING RLE 80 | ,schema_name VARCHAR(128) ENCODING RLE 81 | ,table_name VARCHAR(128) ENCODING AUTO 82 | ,projections_used VARCHAR(22) ENCODING RLE 83 | ,query_duration_us NUMERIC(36) ENCODING AUTO 84 | ,query_start_epoch INT ENCODING COMMONDELTA_COMP 85 | ,query_start VARCHAR(63) ENCODING AUTO 86 | ,query_type VARCHAR(128) ENCODING RLE 87 | ,error_code INT ENCODING BLOCKDICT_COMP 88 | ,user_name VARCHAR(128) ENCODING RLE 89 | ,processed_row_count INT ENCODING DELTARANGE_COMP 90 | ,reserved_extra_memory INT ENCODING BLOCKDICT_COMP 91 | ,is_executing boolean ENCODING RLE 92 | ) 93 | ORDER BY transaction_id 94 | ,session_id 95 | ,statement_id 96 | ,identifier 97 | ,node_name 98 | ,query 99 | ,query_search_path 100 | ,schema_name 101 | ,table_name 102 | ,projections_used 103 | ,query_duration_us 104 | ,query_start_epoch 105 | ,query_start 106 | ,query_type 107 | ,error_code 108 | ,user_name 109 | ,processed_row_count 110 | ,reserved_extra_memory 111 | ,is_executing 112 | SEGMENTED BY HASH (transaction_id) ALL NODES; 113 | 114 | DROP TABLE IF EXISTS vstb.query_plan_profiles CASCADE; 115 | 116 | CREATE TABLE vstb.query_plan_profiles ( 117 | transaction_id INT ENCODING DELTARANGE_COMP 118 | ,statement_id INT ENCODING RLE 119 | ,path_id INT ENCODING COMMONDELTA_COMP 120 | ,path_line_index INT ENCODING RLE 121 | ,path_is_started boolean ENCODING RLE 122 | ,path_is_completed boolean ENCODING RLE 123 | ,is_executing boolean ENCODING RLE 124 | ,running_time interval ENCODING DELTARANGE_COMP 125 | ,memory_allocated_bytes INT ENCODING DELTARANGE_COMP 126 | ,read_from_disk_bytes INT ENCODING RLE 127 | ,received_bytes INT ENCODING RLE 128 | ,sent_bytes INT ENCODING RLE 129 | ,path_line VARCHAR(64000) ENCODING AUTO 130 | ) 131 | ORDER BY transaction_id 132 | ,statement_id 133 | ,path_id 134 | ,path_line_index 135 | ,path_is_started 136 | ,path_is_completed 137 | ,is_executing 138 | ,running_time 139 | ,memory_allocated_bytes 140 | ,read_from_disk_bytes 141 | ,received_bytes 142 | ,sent_bytes 143 | ,path_line 144 | SEGMENTED BY HASH (transaction_id) ALL NODES; 145 | 146 | 147 | DROP TABLE IF EXISTS vstb.query_requests CASCADE; 148 | 149 | CREATE TABLE vstb.query_requests ( 150 | node_name VARCHAR(128) ENCODING RLE 151 | ,user_name VARCHAR(128) ENCODING RLE 152 | ,session_id VARCHAR(128) ENCODING AUTO 153 | ,request_id INT ENCODING COMMONDELTA_COMP 154 | ,transaction_id INT ENCODING COMMONDELTA_COMP 155 | ,statement_id INT ENCODING COMMONDELTA_COMP 156 | ,request_type VARCHAR(128) ENCODING RLE 157 | ,request VARCHAR(64000) ENCODING AUTO 158 | ,request_label VARCHAR(128) ENCODING RLE 159 | ,search_path VARCHAR(64000) ENCODING RLE 160 | ,memory_acquired_mb FLOAT ENCODING COMMONDELTA_COMP 161 | ,success boolean ENCODING RLE 162 | ,error_count INT ENCODING RLE 163 | ,start_timestamp timestamptz ENCODING DELTARANGE_COMP 164 | ,end_timestamp timestamptz ENCODING DELTARANGE_COMP 165 | ,request_duration_ms INT ENCODING DELTARANGE_COMP 166 | ,is_executing boolean ENCODING RLE 167 | ) 168 | ORDER BY transaction_id 169 | ,node_name 170 | ,user_name 171 | ,session_id 172 | ,request_id 173 | ,statement_id 174 | ,request_type 175 | ,request 176 | ,request_label 177 | ,search_path 178 | ,memory_acquired_mb 179 | ,success 180 | ,error_count 181 | ,start_timestamp 182 | ,end_timestamp 183 | ,request_duration_ms 184 | ,is_executing 185 | SEGMENTED BY HASH (transaction_id) ALL NODES; 186 | 187 | DROP TABLE IF EXISTS vstb.query_events CASCADE; 188 | 189 | CREATE TABLE vstb.query_events ( 190 | event_timestamp timestamptz ENCODING DELTARANGE_COMP 191 | ,node_name VARCHAR(128) ENCODING RLE 192 | ,user_id INT ENCODING RLE 193 | ,user_name VARCHAR(128) ENCODING RLE 194 | ,session_id VARCHAR(128) ENCODING AUTO 195 | ,request_id INT ENCODING COMMONDELTA_COMP 196 | ,transaction_id INT ENCODING DELTARANGE_COMP 197 | ,statement_id INT ENCODING RLE 198 | ,event_category VARCHAR(12) ENCODING RLE 199 | ,event_type VARCHAR(64000) ENCODING AUTO 200 | ,event_description VARCHAR(64000) ENCODING AUTO 201 | ,operator_name VARCHAR(128) ENCODING AUTO 202 | ,path_id INT ENCODING COMMONDELTA_COMP 203 | ,object_id INT ENCODING DELTARANGE_COMP 204 | ,event_details VARCHAR(64000) ENCODING AUTO 205 | ,suggested_action VARCHAR(64000) ENCODING RLE 206 | ) 207 | ORDER BY transaction_id 208 | ,event_timestamp 209 | ,node_name 210 | ,user_id 211 | ,user_name 212 | ,session_id 213 | ,request_id 214 | ,statement_id 215 | ,event_category 216 | ,event_type 217 | ,event_description 218 | ,operator_name 219 | ,path_id 220 | ,object_id 221 | ,event_details 222 | ,suggested_action 223 | SEGMENTED BY HASH (transaction_id) ALL NODES; 224 | 225 | DROP TABLE IF EXISTS vstb.resource_rejection_details CASCADE; 226 | 227 | CREATE TABLE vstb.resource_rejection_details ( 228 | rejected_timestamp timestamptz ENCODING AUTO 229 | ,node_name VARCHAR(128) ENCODING RLE 230 | ,user_name VARCHAR(128) ENCODING RLE 231 | ,session_id VARCHAR(128) ENCODING RLE 232 | ,request_id INT ENCODING AUTO 233 | ,transaction_id INT ENCODING AUTO 234 | ,statement_id INT ENCODING AUTO 235 | ,pool_id INT ENCODING RLE 236 | ,pool_name VARCHAR(128) ENCODING RLE 237 | ,reason VARCHAR(128) ENCODING RLE 238 | ,resource_type VARCHAR(128) ENCODING RLE 239 | ,rejected_value INT ENCODING AUTO 240 | ) 241 | ORDER BY transaction_id 242 | ,rejected_timestamp 243 | ,node_name 244 | ,user_name 245 | ,session_id 246 | ,request_id 247 | ,statement_id 248 | ,pool_id 249 | ,pool_name 250 | ,reason 251 | ,resource_type 252 | ,rejected_value 253 | SEGMENTED BY HASH (transaction_id) ALL NODES; 254 | 255 | DROP TABLE IF EXISTS vstb.user_sessions CASCADE; 256 | 257 | CREATE TABLE vstb.user_sessions ( 258 | node_name VARCHAR(128) ENCODING RLE 259 | ,user_name VARCHAR(128) ENCODING RLE 260 | ,session_id VARCHAR(128) ENCODING AUTO 261 | ,transaction_id INT ENCODING AUTO 262 | ,statement_id INT ENCODING AUTO 263 | ,session_start_timestamp timestamptz ENCODING AUTO 264 | ,session_end_timestamp timestamptz ENCODING AUTO 265 | ,is_active boolean ENCODING RLE 266 | ,client_hostname VARCHAR(128) ENCODING AUTO 267 | ,client_pid INT ENCODING RLE 268 | ,client_label VARCHAR(64000) ENCODING AUTO 269 | ,ssl_state VARCHAR(128) ENCODING RLE 270 | ,authentication_method VARCHAR(128) ENCODING RLE 271 | ) 272 | ORDER BY session_id 273 | ,user_name 274 | ,node_name 275 | SEGMENTED BY HASH (session_id) ALL NODES; 276 | 277 | DROP TABLE IF EXISTS vstb.transactions CASCADE; 278 | 279 | CREATE TABLE vstb.transactions ( 280 | start_timestamp timestamptz ENCODING DELTARANGE_COMP 281 | ,end_timestamp timestamptz ENCODING DELTARANGE_COMP 282 | ,node_name VARCHAR(128) ENCODING RLE 283 | ,user_id INT ENCODING RLE 284 | ,user_name VARCHAR(128) ENCODING RLE 285 | ,session_id VARCHAR(128) ENCODING AUTO 286 | ,transaction_id INT ENCODING COMMONDELTA_COMP 287 | ,description VARCHAR(64000) ENCODING AUTO 288 | ,start_epoch INT ENCODING COMMONDELTA_COMP 289 | ,end_epoch INT ENCODING COMMONDELTA_COMP 290 | ,number_of_statements INT ENCODING RLE 291 | ,ISOLATION VARCHAR(128) ENCODING RLE 292 | ,is_read_only boolean ENCODING RLE 293 | ,is_committed boolean ENCODING RLE 294 | ,is_local boolean ENCODING RLE 295 | ,is_initiator boolean ENCODING RLE 296 | ,is_ddl boolean ENCODING RLE 297 | ) 298 | ORDER BY transaction_id 299 | ,start_timestamp 300 | ,end_timestamp 301 | ,node_name 302 | ,user_id 303 | ,user_name 304 | ,session_id 305 | ,description 306 | ,start_epoch 307 | ,end_epoch 308 | ,number_of_statements 309 | ,ISOLATION 310 | ,is_read_only 311 | ,is_committed 312 | ,is_local 313 | ,is_initiator 314 | ,is_ddl 315 | SEGMENTED BY HASH (transaction_id) ALL NODES; 316 | 317 | DROP TABLE IF EXISTS vstb.load_streams CASCADE; 318 | 319 | CREATE TABLE vstb.load_streams ( 320 | session_id VARCHAR(128) ENCODING RLE 321 | ,transaction_id INT ENCODING COMMONDELTA_COMP 322 | ,statement_id INT ENCODING RLE 323 | ,stream_name VARCHAR(128) ENCODING RLE 324 | ,schema_name VARCHAR(128) ENCODING RLE 325 | ,table_id INT ENCODING COMMONDELTA_COMP 326 | ,table_name VARCHAR(128) ENCODING AUTO 327 | ,load_start VARCHAR(63) ENCODING AUTO 328 | ,load_duration_ms NUMERIC(54) ENCODING RLE 329 | ,is_executing boolean ENCODING RLE 330 | ,accepted_row_count INT ENCODING COMMONDELTA_COMP 331 | ,rejected_row_count INT ENCODING RLE 332 | ,read_bytes INT ENCODING AUTO 333 | ,input_file_size_bytes INT ENCODING COMMONDELTA_COMP 334 | ,parse_complete_percent INT ENCODING RLE 335 | ,unsorted_row_count INT ENCODING COMMONDELTA_COMP 336 | ,sorted_row_count INT ENCODING COMMONDELTA_COMP 337 | ,sort_complete_percent INT ENCODING RLE 338 | ) 339 | ORDER BY transaction_id 340 | ,session_id 341 | ,statement_id 342 | ,stream_name 343 | ,schema_name 344 | ,table_id 345 | ,table_name 346 | ,load_start 347 | ,load_duration_ms 348 | ,is_executing 349 | ,accepted_row_count 350 | ,rejected_row_count 351 | ,read_bytes 352 | ,input_file_size_bytes 353 | ,parse_complete_percent 354 | ,unsorted_row_count 355 | ,sorted_row_count 356 | ,sort_complete_percent 357 | SEGMENTED BY HASH (transaction_id) ALL NODES; 358 | 359 | 360 | DROP TABLE IF EXISTS vstb.projection_storage CASCADE; 361 | 362 | CREATE TABLE vstb.projection_storage ( 363 | node_name VARCHAR(128) ENCODING RLE 364 | ,projection_id INT ENCODING AUTO 365 | ,projection_name VARCHAR(128) ENCODING AUTO 366 | ,projection_schema VARCHAR(128) ENCODING AUTO 367 | ,projection_column_count INT ENCODING AUTO 368 | ,row_count INT ENCODING AUTO 369 | ,used_bytes INT ENCODING AUTO 370 | ,wos_row_count INT ENCODING RLE 371 | ,wos_used_bytes INT ENCODING RLE 372 | ,ros_row_count INT ENCODING AUTO 373 | ,ros_used_bytes INT ENCODING AUTO 374 | ,ros_count INT ENCODING COMMONDELTA_COMP 375 | ,anchor_table_name VARCHAR(128) ENCODING AUTO 376 | ,anchor_table_schema VARCHAR(128) ENCODING AUTO 377 | ,anchor_table_id INT ENCODING AUTO 378 | ,last_refresh_ts DATETIME ENCODING RLE 379 | ) 380 | ORDER BY projection_id 381 | ,node_name 382 | ,last_refresh_ts 383 | ,anchor_table_name 384 | ,projection_name 385 | ,projection_schema 386 | ,anchor_table_schema 387 | ,projection_column_count 388 | ,anchor_table_id 389 | SEGMENTED BY HASH ( 390 | projection_id 391 | ,node_name 392 | ,last_refresh_ts 393 | ) ALL NODES; 394 | 395 | DROP TABLE IF EXISTS vstb.projection_usage CASCADE; 396 | 397 | CREATE TABLE vstb.projection_usage ( 398 | query_start_timestamp timestamptz ENCODING DELTARANGE_COMP 399 | ,node_name VARCHAR(128) ENCODING RLE 400 | ,user_name VARCHAR(128) ENCODING RLE 401 | ,session_id VARCHAR(128) ENCODING AUTO 402 | ,request_id INT ENCODING COMMONDELTA_COMP 403 | ,transaction_id INT ENCODING COMMONDELTA_COMP 404 | ,statement_id INT ENCODING COMMONDELTA_COMP 405 | ,io_type VARCHAR(128) ENCODING RLE 406 | ,projection_id INT ENCODING COMMONDELTA_COMP 407 | ,projection_name VARCHAR(128) ENCODING AUTO 408 | ,anchor_table_id INT ENCODING COMMONDELTA_COMP 409 | ,anchor_table_schema VARCHAR(128) ENCODING RLE 410 | ,anchor_table_name VARCHAR(128) ENCODING AUTO 411 | ) 412 | ORDER BY anchor_table_schema 413 | ,anchor_table_name 414 | ,projection_name 415 | ,node_name 416 | ,user_name 417 | ,query_start_timestamp 418 | ,io_type 419 | ,session_id 420 | ,request_id 421 | ,transaction_id 422 | ,statement_id 423 | ,projection_id 424 | ,anchor_table_id 425 | SEGMENTED BY HASH (anchor_table_name) ALL NODES; 426 | 427 | DROP TABLE IF EXISTS vstb.dc_execution_engine_events CASCADE; 428 | 429 | CREATE TABLE vstb.dc_execution_engine_events ( 430 | "time" timestamptz ENCODING DELTARANGE_COMP 431 | ,node_name VARCHAR(128) ENCODING RLE 432 | ,session_id VARCHAR(128) ENCODING AUTO 433 | ,user_id INT ENCODING RLE 434 | ,user_name VARCHAR(128) ENCODING RLE 435 | ,transaction_id INT ENCODING DELTARANGE_COMP 436 | ,statement_id INT ENCODING RLE 437 | ,request_id INT ENCODING COMMONDELTA_COMP 438 | ,event_type VARCHAR(128) ENCODING AUTO 439 | ,event_description VARCHAR(512) ENCODING AUTO 440 | ,operator_name VARCHAR(128) ENCODING RLE 441 | ,path_id INT ENCODING COMMONDELTA_COMP 442 | ,event_oid INT ENCODING DELTARANGE_COMP 443 | ,event_details VARCHAR(1024) ENCODING AUTO 444 | ,suggested_action VARCHAR(1024) ENCODING RLE 445 | ) 446 | ORDER BY transaction_id 447 | ,session_id 448 | ,statement_id 449 | ,request_id 450 | ,"time" 451 | ,node_name 452 | ,user_id 453 | ,user_name 454 | ,event_type 455 | ,event_description 456 | ,operator_name 457 | ,path_id 458 | ,event_oid 459 | ,event_details 460 | ,suggested_action 461 | SEGMENTED BY HASH (transaction_id) ALL NODES; 462 | 463 | 464 | DROP TABLE IF EXISTS vstb.system_resource_usage CASCADE; 465 | 466 | CREATE TABLE vstb.system_resource_usage 467 | ( 468 | node_name varchar(128) ENCODING RLE, 469 | end_time timestamp ENCODING COMMONDELTA_COMP, 470 | average_memory_usage_percent float ENCODING COMMONDELTA_COMP, 471 | average_cpu_usage_percent float, 472 | net_rx_kbytes_per_second float, 473 | net_tx_kbytes_per_second float, 474 | io_read_kbytes_per_second float, 475 | io_written_kbytes_per_second float 476 | ) 477 | ORDER BY node_name, end_time 478 | SEGMENTED BY HASH(node_name, end_time) ALL NODES 479 | ; 480 | 481 | 482 | 483 | DROP TABLE IF EXISTS vstb.resource_acquisitions CASCADE; 484 | 485 | CREATE TABLE vstb.resource_acquisitions 486 | ( 487 | node_name varchar(128) ENCODING RLE, 488 | transaction_id int ENCODING COMMONDELTA_COMP, 489 | statement_id int ENCODING COMMONDELTA_COMP, 490 | request_type varchar(128), 491 | pool_id int ENCODING COMMONDELTA_COMP, 492 | pool_name varchar(128), 493 | thread_count int ENCODING COMMONDELTA_COMP, 494 | open_file_handle_count int ENCODING COMMONDELTA_COMP, 495 | memory_inuse_kb int ENCODING COMMONDELTA_COMP, 496 | queue_entry_timestamp timestamptz ENCODING DELTARANGE_COMP, 497 | acquisition_timestamp timestamptz ENCODING DELTARANGE_COMP, 498 | release_timestamp timestamptz ENCODING DELTARANGE_COMP, 499 | duration_ms int ENCODING DELTARANGE_COMP, 500 | is_executing boolean ENCODING BLOCKDICT_COMP 501 | ) ORDER BY transaction_id, statement_id, queue_entry_timestamp, is_executing, node_name, 502 | request_type, pool_name, acquisition_timestamp, release_timestamp 503 | SEGMENTED BY HASH(transaction_id, statement_id, queue_entry_timestamp) ALL NODES ; 504 | 505 | 506 | 507 | --SELECT MARK_DESIGN_KSAFE(0); 508 | 509 | 510 | -- SELECT MARK_DESIGN_KSAFE(1); 511 | --============================================================================= 512 | -- Turn on Profiling 513 | --============================================================================= 514 | SELECT SHOW_PROFILING_CONFIG(); 515 | 516 | SELECT SET_CONFIG_PARAMETER('GlobalSessionProfiling', 1); 517 | SELECT SET_CONFIG_PARAMETER('GlobalQueryProfiling', 1); 518 | SELECT SET_CONFIG_PARAMETER('GlobalEEProfiling', 1); 519 | 520 | 521 | /**************************************************************************************************** 522 | --============================================================================= 523 | -- Initial Setup 524 | --============================================================================= 525 | ;drop table vstb.dc_execution_engine_events 526 | ;drop table vstb.execution_engine_profiles 527 | ;drop table vstb.load_streams 528 | ;drop table vstb.projection_storage 529 | ;drop table vstb.projection_usage 530 | ;drop table vstb.query_events 531 | ;drop table vstb.query_plan_profiles 532 | ;drop table vstb.query_profiles 533 | ;drop table vstb.query_requests 534 | ;drop table vstb.resource_rejection_details 535 | ;drop table vstb.transactions 536 | ;drop table vstb.user_sessions 537 | ; 538 | 539 | 540 | 541 | select * into vstb.dc_execution_engine_events from dc_execution_engine_events WHERE 1=0; 542 | select * into vstb.dc_projections_used from dc_projections_used WHERE 1=0; 543 | select * into vstb.load_streams from v_monitor.load_streams WHERE 1=0; 544 | select * into vstb.execution_engine_profiles from v_monitor.execution_engine_profiles WHERE 1=0; 545 | select * into vstb.query_profiles from v_monitor.query_profiles WHERE 1=0; 546 | select * into vstb.query_plan_profiles from v_monitor.query_plan_profiles WHERE 1=0; 547 | select * into vstb.query_requests from v_monitor.query_requests WHERE 1=0; 548 | select * into vstb.query_events from v_monitor.query_events WHERE 1=0; 549 | select * into vstb.resource_rejection_details from v_monitor.resource_rejection_details WHERE 1=0; 550 | select * into vstb.sessions from v_monitor.sessions WHERE 1=0; 551 | select * into vstb.user_sessions from v_monitor.user_sessions WHERE 1=0; 552 | select * into vstb.transactions from v_monitor.transactions WHERE 1=0; 553 | select *, GETDATE()::DATE AS last_refresh_ts into vstb.projection_storage from v_monitor.projection_storage ; 554 | 555 | --******************************************************************************/ 556 | -------------------------------------------------------------------------------- /sql/ddl/setup_vstb_views_current.sql: -------------------------------------------------------------------------------- 1 | --============================================================================== 2 | -- Diagnostic Views 3 | -- 4 | -- vProjectionUsage 5 | -- vProjectionColumnSize 6 | -- vRunningQueries 7 | -- vLongRunningQueries 8 | -- vQueryPlanProfiles 9 | -- vMostCommonQueries 10 | --============================================================================== 11 | 12 | 13 | --========================================================================= 14 | --Create vProjectionUsage 15 | --========================================================================= 16 | DROP VIEW IF EXISTS vstb.vProjectionUsage ; 17 | 18 | CREATE VIEW vstb.vProjectionUsage 19 | AS 20 | SELECT /*+ label(vProjectionUsage) */ 21 | PS.table_schema 22 | ,PS.table_name 23 | ,PS.table_schema || '.' || PS.table_name AS table_schema_name 24 | ,P.projection_basename 25 | ,P.projection_schema 26 | ,P.projection_name 27 | ,P.projection_schema || '.' || P.projection_name AS projection_schema_name 28 | ,PS.node_name 29 | ,right(PS.node_name,4)::INT as node_number 30 | ,P.owner_name 31 | ,P.create_type 32 | ,P.verified_fault_tolerance 33 | ,CASE WHEN P.is_prejoin = 1 THEN 'TRUE' ELSE '***FALSE***' END AS is_prejoin 34 | ,CASE WHEN P.is_up_to_date = 1 THEN 'TRUE' ELSE '***FALSE***' END AS is_up_to_date 35 | ,CASE WHEN P.has_statistics = 1 THEN 'TRUE' ELSE '***FALSE***' END AS has_statistics 36 | ,CASE WHEN P.is_segmented = 1 THEN 'TRUE' ELSE '***FALSE***' END AS is_segmented 37 | ,CASE WHEN P.is_super_projection = 1 THEN 'TRUE' ELSE '***FALSE***' END AS is_super_projection 38 | ,PC.full_statistics_last_updated 39 | ,DATEDIFF('DAY',PC.full_statistics_last_updated, GETDATE()) AS days_since_full_statistics_last_updated 40 | ,PS.projection_column_count 41 | ,PS.row_count 42 | ,SUM(PS.row_count) OVER (PARTITION BY P.projection_basename) as projection_row_count 43 | ,PS.row_count / ( SUM(PS.row_count) OVER (PARTITION BY P.projection_basename) ) as pct_of_rows_in_projection 44 | , (PS.row_count/ (SUM(PS.row_count) OVER (PARTITION BY P.projection_basename) / SUM(1) OVER (PARTITION BY P.projection_basename))) 45 | AS indexed_projection_skew 46 | ,PS.used_bytes 47 | ,PS.used_bytes/1E9 AS used_GB 48 | ,PS.wos_row_count 49 | ,PS.wos_used_bytes 50 | ,PS.ros_row_count 51 | ,PS.ros_used_bytes 52 | ,PS.ros_count 53 | ,COALESCE(D.deleted_row_count ,0) AS deleted_row_count 54 | ,COALESCE(D.deleted_used_bytes,0) AS deleted_used_bytes 55 | ,COALESCE(D.deleted_used_bytes,0)/1E9 AS deleted_used_GB 56 | ,T.TableUniqueExtractUsers 57 | ,T.TableExtractTransactions 58 | ,T.TableDaysSinceLastExtract 59 | ,T.TableLastExtractDT 60 | ,T.TableFirstExtractDT 61 | ,T.TableDaysSinceLastModify 62 | ,T.TableLastModifyDT 63 | ,T.TableFirstModifyDT 64 | ,PU.ProjectionUniqueExtractUsers 65 | ,PU.ProjectionExtractTransactions 66 | ,PU.ProjectionDaysSinceLastExtract 67 | ,PU.ProjectionLastExtractDT 68 | ,PU.ProjectionFirstExtractDT 69 | ,PU.ProjectionDaysSinceLastModify 70 | ,PU.ProjectionLastModifyDT 71 | ,PU.ProjectionFirstModifyDT 72 | FROM v_catalog.projections AS P 73 | LEFT JOIN 74 | (SELECT 75 | node_name 76 | ,projection_id 77 | ,projection_name 78 | ,projection_schema 79 | ,projection_column_count 80 | ,row_count 81 | ,used_bytes 82 | ,wos_row_count 83 | ,wos_used_bytes 84 | ,ros_row_count 85 | ,ros_used_bytes 86 | ,ros_count 87 | ,anchor_table_name AS table_name 88 | ,anchor_table_schema AS table_schema 89 | ,anchor_table_id AS table_id 90 | FROM v_monitor.projection_storage ) AS PS 91 | ON P.projection_id=PS.projection_id 92 | LEFT JOIN 93 | (SELECT 94 | table_id 95 | ,COUNT(DISTINCT CASE WHEN COALESCE(IsExtract,0)=1 THEN user_name ELSE NULL END) AS TableUniqueExtractUsers 96 | ,COUNT(NULLIFZERO(IsExtract)*transaction_id) AS TableExtractTransactions 97 | ,MIN(DaysSinceLastExtract) AS TableDaysSinceLastExtract 98 | ,MIN(DaysSinceLastModify) AS TableDaysSinceLastModify 99 | ,MAX(ExtractDT) AS TableLastExtractDT 100 | ,MAX(ModifyDT) AS TableLastModifyDT 101 | ,MIN(ExtractDT) AS TableFirstExtractDT 102 | ,MIN(ModifyDT) AS TableFirstModifyDT 103 | FROM 104 | (SELECT 105 | transaction_id 106 | ,user_name 107 | ,anchor_table_id as table_id 108 | ,projection_id 109 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END AS ExtractDT 110 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END AS ModifyDT 111 | ,CASE WHEN io_type LIKE 'input' THEN 1 ELSE 0 END AS IsExtract 112 | ,CASE WHEN io_type LIKE 'output' THEN 1 ELSE 0 END AS IsModify 113 | ,DATEDIFF('DAY' 114 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END 115 | ,GETDATE()) AS DaysSinceLastExtract 116 | ,DATEDIFF('DAY' 117 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END 118 | ,GETDATE()) AS DaysSinceLastModify 119 | FROM v_monitor.projection_usage ) AS B1 120 | GROUP BY table_id) AS T 121 | ON PS.table_id = T.table_id 122 | LEFT JOIN 123 | (SELECT 124 | projection_id 125 | ,COUNT(DISTINCT CASE WHEN COALESCE(IsExtract,0)=1 THEN user_name ELSE NULL END) AS ProjectionUniqueExtractUsers 126 | ,COUNT(NULLIFZERO(IsExtract)*transaction_id) AS ProjectionExtractTransactions 127 | ,MIN(DaysSinceLastExtract) AS ProjectionDaysSinceLastExtract 128 | ,MIN(DaysSinceLastModify) AS ProjectionDaysSinceLastModify 129 | ,MAX(ExtractDT) AS ProjectionLastExtractDT 130 | ,MAX(ModifyDT) AS ProjectionLastModifyDT 131 | ,MIN(ExtractDT) AS ProjectionFirstExtractDT 132 | ,MIN(ModifyDT) AS ProjectionFirstModifyDT 133 | FROM 134 | (SELECT 135 | transaction_id 136 | ,user_name 137 | ,anchor_table_id as table_id 138 | ,projection_id 139 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END AS ExtractDT 140 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END AS ModifyDT 141 | ,CASE WHEN io_type LIKE 'input' THEN 1 ELSE 0 END AS IsExtract 142 | ,CASE WHEN io_type LIKE 'output' THEN 1 ELSE 0 END AS IsModify 143 | ,DATEDIFF('DAY' 144 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END 145 | ,GETDATE()) AS DaysSinceLastExtract 146 | ,DATEDIFF('DAY' 147 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END 148 | ,GETDATE()) AS DaysSinceLastModify 149 | FROM v_monitor.projection_usage ) AS B1 150 | GROUP BY projection_id) AS PU 151 | ON P.projection_id = PU.projection_id 152 | LEFT JOIN 153 | (SELECT 154 | schema_name AS projection_schema 155 | ,projection_name 156 | ,SUM(deleted_row_count) AS deleted_row_count 157 | ,SUM(used_bytes) AS deleted_used_bytes 158 | FROM v_monitor.delete_vectors 159 | GROUP BY 160 | schema_name 161 | ,projection_name ) AS D 162 | ON P.projection_schema=D.projection_schema 163 | AND P.projection_name=D.projection_name 164 | LEFT JOIN 165 | (SELECT projection_id 166 | ,MIN(statistics_updated_timestamp)::DATE AS full_statistics_last_updated 167 | FROM v_catalog.projection_columns 168 | WHERE statistics_type LIKE 'FULL' 169 | GROUP BY projection_id) AS PC 170 | ON P.projection_id = PC.projection_id 171 | ORDER BY 172 | PS.table_schema 173 | ,PS.table_name 174 | ,PS.projection_schema 175 | ,PS.projection_name 176 | ,P.projection_basename 177 | ,PS.node_name 178 | ; 179 | 180 | 181 | 182 | 183 | --========================================================================= 184 | --Create vProjectionColumnSize 185 | ------ Courtesy of Eli Reiman 186 | --========================================================================= 187 | DROP VIEW IF EXISTS vstb.vProjectionColumnSize ; 188 | 189 | CREATE VIEW vstb.vProjectionColumnSize 190 | AS 191 | SELECT 192 | tab.anchor_table_schema 193 | , tab.anchor_table_name 194 | , tab.GB_Table 195 | , proj.projection_name 196 | , proj.GB_Proj 197 | , col.column_name 198 | , col.MB_Col 199 | , col.row_count 200 | , col.encodings 201 | , col.compressions 202 | , colOrder.column_position 203 | , colOrder.sort_position 204 | FROM 205 | ( SELECT anchor_table_schema 206 | , anchor_table_name 207 | , ((SUM(used_bytes)/1E9::FLOAT))::INT AS GB_Table 208 | FROM v_monitor.projection_storage 209 | GROUP BY anchor_table_schema 210 | , anchor_table_name ) tab 211 | LEFT JOIN 212 | ( SELECT anchor_table_schema 213 | , anchor_table_name 214 | , projection_name 215 | , ((SUM(used_bytes)/1E9::FLOAT))::INT AS GB_Proj 216 | FROM v_monitor.projection_storage 217 | GROUP BY anchor_table_schema 218 | , anchor_table_name 219 | , projection_name ) proj 220 | ON proj.anchor_table_schema = tab.anchor_table_schema 221 | AND proj.anchor_table_name = tab.anchor_table_name 222 | LEFT JOIN 223 | ( SELECT anchor_table_schema 224 | , anchor_table_name 225 | , projection_name 226 | , column_name 227 | , encodings 228 | , compressions 229 | , ((SUM(used_bytes)/1E6::FLOAT))::INT AS MB_Col 230 | , SUM(row_count) AS row_count 231 | FROM v_monitor.column_storage 232 | GROUP BY anchor_table_schema 233 | , anchor_table_name 234 | , projection_name 235 | , column_name 236 | , encodings 237 | , compressions ) col 238 | ON col.anchor_table_schema = tab.anchor_table_schema 239 | AND col.anchor_table_name = tab.anchor_table_name 240 | AND col.projection_name = proj.projection_name 241 | LEFT JOIN v_catalog.projection_columns colOrder 242 | ON colOrder.table_schema = tab.anchor_table_schema 243 | AND colOrder.table_name = tab.anchor_table_name 244 | AND colOrder.projection_name = proj.projection_name 245 | AND colOrder.table_column_name = col.column_name 246 | ORDER BY tab.GB_Table DESC 247 | , tab.anchor_table_name 248 | , proj.GB_Proj DESC 249 | , proj.projection_name 250 | , col.MB_Col DESC 251 | ; 252 | 253 | 254 | -- ###Performance 255 | -- **vRunningQueries** 256 | -- **vLongRunningQueries** 257 | -- **vQueryPlanProfiles** 258 | 259 | 260 | --========================================================================= 261 | --Create vRunningQueries 262 | --========================================================================= 263 | DROP VIEW IF EXISTS vstb.vRunningQueries; 264 | 265 | CREATE VIEW vstb.vRunningQueries 266 | AS 267 | SELECT 268 | node_name 269 | ,user_name 270 | ,'SELECT CLOSE_SESSION(''' || session_id || ''');' AS CloseSession 271 | ,statement_start 272 | ,(GETDATE() - statement_start)::INTERVAL AS current_statement_duration 273 | ,REGEXP_REPLACE(current_statement,'[\r\n\t]',' ') AS current_statement 274 | ,session_id 275 | ,transaction_id 276 | ,statement_id 277 | ,client_hostname 278 | ,login_timestamp 279 | ,runtime_priority 280 | ,ssl_state 281 | ,authentication_method 282 | ,transaction_start 283 | ,GETDATE() AS Today 284 | FROM v_monitor.sessions 285 | ORDER BY statement_start DESC 286 | ; 287 | 288 | 289 | 290 | --========================================================================= 291 | --Create vLongRunningQueries 292 | --========================================================================= 293 | DROP VIEW IF EXISTS vstb.vLongRunningQueries; 294 | 295 | CREATE VIEW vstb.vLongRunningQueries 296 | AS 297 | SELECT 298 | node_name 299 | ,user_name 300 | ,start_timestamp 301 | ,end_timestamp 302 | ,(COALESCE(end_timestamp,GETDATE()) - start_timestamp)::INTERVAL AS request_duration 303 | ,request_duration_ms 304 | ,success 305 | ,is_executing 306 | ,REGEXP_REPLACE(request,'[\r\n\t]',' ') AS request 307 | ,'SELECT CLOSE_SESSION(''' || session_id || ''');' AS CloseSession 308 | ,session_id 309 | ,transaction_id 310 | ,statement_id 311 | ,request_type 312 | ,request_label 313 | ,search_path 314 | ,memory_acquired_mb 315 | ,error_count 316 | ,request_id 317 | ,GETDATE() AS Today 318 | FROM v_monitor.query_requests 319 | ORDER BY request_duration_ms DESC 320 | ; 321 | 322 | 323 | 324 | --========================================================================= 325 | --Create vQueryPlanProfiles 326 | --========================================================================= 327 | DROP VIEW IF EXISTS vstb.vQueryPlanProfiles; 328 | 329 | CREATE VIEW vstb.vQueryPlanProfiles 330 | AS 331 | SELECT qp.query_start 332 | ,qp.query_duration_us 333 | ,(COALESCE(qr.end_timestamp, GETDATE()) - qr.start_timestamp)::INTERVAL AS request_duration 334 | ,qp.user_name 335 | ,qp.is_executing 336 | ,qp.query_type 337 | ,qp.session_id 338 | ,qp.transaction_id 339 | ,qp.statement_id 340 | ,qp.identifier 341 | ,qp.node_name 342 | ,REGEXP_REPLACE(query, '[\r\n\t\f]', ' ') AS query 343 | ,qpp.path_line 344 | ,qpp.path_id 345 | ,qpp.path_line_index 346 | ,qpp.running_time 347 | ,qpp.memory_allocated_bytes 348 | ,qpp.read_from_disk_bytes 349 | ,qpp.received_bytes 350 | ,qpp.sent_bytes 351 | ,qe.event_messages 352 | FROM v_monitor.query_profiles AS qp 353 | JOIN v_monitor.query_plan_profiles AS qpp ON qp.statement_id = qpp.statement_id 354 | AND qp.transaction_id = qpp.transaction_id 355 | JOIN v_monitor.query_requests AS qr ON qp.statement_id = qr.statement_id 356 | AND qp.transaction_id = qr.transaction_id 357 | AND qp.session_id = qr.session_id 358 | LEFT JOIN 359 | 360 | ( 361 | SELECT transaction_id 362 | ,statement_id 363 | ,session_id 364 | ,MAPTOSTRING(raw_map) AS event_messages 365 | FROM 366 | ( 367 | SELECT transaction_id 368 | ,statement_id 369 | ,session_id 370 | ,MAPAGGREGATE(event_description 371 | , REGEXP_REPLACE( 372 | mapToSTring(raw_map using parameters canonical_json=true)::VARCHAR(65000) 373 | ,'[\r\n\t\f]',' ') 374 | ) 375 | OVER (PARTITION by transaction_id, statement_id, session_id) AS raw_map 376 | FROM 377 | ( 378 | SELECT event_description 379 | ,transaction_id 380 | ,statement_id 381 | ,session_id 382 | ,MAPAGGREGATE(node_name , event_details ) 383 | OVER (PARTITION BY event_description, transaction_id, statement_id, session_id) AS raw_map 384 | FROM v_monitor.query_events 385 | ) AS T1 386 | ) AS T2 387 | ) AS qe 388 | ON qp.statement_id = qe.statement_id 389 | AND qp.transaction_id = qe.transaction_id 390 | AND qp.session_id = qe.session_id 391 | WHERE 1 = 1 392 | ORDER BY qp.query_start DESC 393 | ,qp.transaction_id 394 | ,qpp.path_line 395 | ,qpp.statement_id 396 | ,qpp.path_id 397 | ,qpp.path_line_index; 398 | 399 | 400 | --========================================================================= 401 | --Create vMostCommonQueries 402 | --========================================================================= 403 | DROP VIEW IF EXISTS vstb.vMostCommonQueries; 404 | 405 | CREATE VIEW vstb.vMostCommonQueries 406 | AS 407 | SELECT 408 | REGEXP_REPLACE(request,'[\r\n\t]',' ') AS request 409 | ,COUNT(*) AS queries 410 | ,COUNT(DISTINCT user_name) AS users 411 | ,MIN(start_timestamp) AS first_run 412 | ,MAX(end_timestamp) AS last_run 413 | ,AVG((COALESCE(end_timestamp,GETDATE()) - start_timestamp))::INTERVAL AS avg_request_duration 414 | ,MIN((COALESCE(end_timestamp,GETDATE()) - start_timestamp))::INTERVAL AS min_request_duration 415 | ,MAX((COALESCE(end_timestamp,GETDATE()) - start_timestamp))::INTERVAL AS max_request_duration 416 | ,(AVG(request_duration_ms)/1e3)::INTEGER AS avg_request_duration_seconds 417 | ,(MIN(request_duration_ms)/1e3)::INTEGER AS min_request_duration_seconds 418 | ,(MAX(request_duration_ms)/1e3)::INTEGER AS max_request_duration_seconds 419 | ,(SUM(request_duration_ms)/1e3)::INTEGER AS total_seconds 420 | ,SUM(memory_acquired_mb) AS total_memory_acquired_mb 421 | FROM v_monitor.query_requests 422 | WHERE 1=1 423 | AND COALESCE(success,TRUE)=TRUE 424 | AND request not ilike 'commit%' 425 | AND request not ilike 'rollback%' 426 | AND request not ilike 'truncate%' 427 | AND request not ilike 'drop%' 428 | AND request not ilike 'grant%' 429 | GROUP BY 1 430 | ORDER BY COUNT(*) DESC 431 | ; 432 | 433 | 434 | 435 | 436 | 437 | 438 | 439 | 440 | 441 | -------------------------------------------------------------------------------- /sql/ddl/setup_vstb_views_historical.sql: -------------------------------------------------------------------------------- 1 | --============================================================================== 2 | -- Diagnostic Views - Including Historical data 3 | -- 4 | -- **vstb.vProjectionSizeHistory** 5 | -- **vstb.vProjectionUsageHistory** 6 | -- **vstb.vLongRunningQueriesHistory** 7 | -- **vstb.vProjectionGrowthOverTimeWeekly** 8 | --============================================================================== 9 | 10 | 11 | --========================================================================= 12 | --Create vProjectionSizeHistory 13 | --========================================================================= 14 | DROP VIEW IF EXISTS vstb.vProjectionSizeHistory ; 15 | 16 | CREATE VIEW vstb.vProjectionSizeHistory AS 17 | SELECT 18 | anchor_table_schema || '.' || anchor_table_name AS anchor_table_schema_name 19 | ,projection_schema || '.' || projection_name AS projection_schema_name 20 | ,last_refresh_ts 21 | ,SUM(row_count) AS row_count 22 | ,SUM(used_bytes)/(1e9::FLOAT) AS used_Gb 23 | ,SUM(ros_count) AS ros_count_sum 24 | ,MIN(ros_count) AS ros_count_min 25 | ,MIN(ros_count) AS ros_count_max 26 | FROM vstb.projection_storage 27 | GROUP BY 1,2,3 28 | ORDER BY 1,2,3; 29 | 30 | --========================================================================= 31 | --Create vProjectionUsageHistory 32 | --========================================================================= 33 | DROP VIEW IF EXISTS vstb.vProjectionUsageHistory ; 34 | 35 | CREATE VIEW vstb.vProjectionUsageHistory 36 | AS 37 | SELECT 38 | PS.table_schema 39 | ,PS.table_name 40 | ,PS.table_schema || '.' || PS.table_name AS table_schema_name 41 | ,P.projection_basename 42 | ,P.projection_schema 43 | ,P.projection_name 44 | ,P.projection_schema || '.' || P.projection_name AS projection_schema_name 45 | ,PS.node_name 46 | ,right(PS.node_name,4)::INT as node_number 47 | ,P.owner_name 48 | ,P.create_type 49 | ,P.verified_fault_tolerance 50 | ,CASE WHEN P.is_prejoin = 1 THEN 'TRUE' ELSE '***FALSE***' END AS is_prejoin 51 | ,CASE WHEN P.is_up_to_date = 1 THEN 'TRUE' ELSE '***FALSE***' END AS is_up_to_date 52 | ,CASE WHEN P.has_statistics = 1 THEN 'TRUE' ELSE '***FALSE***' END AS has_statistics 53 | ,CASE WHEN P.is_segmented = 1 THEN 'TRUE' ELSE '***FALSE***' END AS is_segmented 54 | ,CASE WHEN P.is_super_projection = 1 THEN 'TRUE' ELSE '***FALSE***' END AS is_super_projection 55 | ,PC.full_statistics_last_updated 56 | ,DATEDIFF('DAY',PC.full_statistics_last_updated, GETDATE()) AS days_since_full_statistics_last_updated 57 | ,PS.projection_column_count 58 | ,PS.row_count 59 | ,SUM(PS.row_count) OVER (PARTITION BY P.projection_basename) as projection_row_count 60 | ,PS.row_count / ( SUM(PS.row_count) OVER (PARTITION BY P.projection_basename) ) as pct_of_rows_in_projection 61 | , (PS.row_count/ (SUM(PS.row_count) OVER (PARTITION BY P.projection_basename) / SUM(1) OVER (PARTITION BY P.projection_basename))) 62 | AS indexed_projection_skew 63 | ,PS.used_bytes 64 | ,PS.used_bytes/1E9 AS used_GB 65 | ,PS.wos_row_count 66 | ,PS.wos_used_bytes 67 | ,PS.ros_row_count 68 | ,PS.ros_used_bytes 69 | ,PS.ros_count 70 | ,COALESCE(D.deleted_row_count ,0) AS deleted_row_count 71 | ,COALESCE(D.deleted_used_bytes,0) AS deleted_used_bytes 72 | ,COALESCE(D.deleted_used_bytes,0)/1E9 AS deleted_used_GB 73 | ,T.TableUniqueExtractUsers 74 | ,T.TableExtractTransactions 75 | ,T.TableDaysSinceLastExtract 76 | ,T.TableLastExtractDT 77 | ,T.TableFirstExtractDT 78 | ,T.TableDaysSinceLastModify 79 | ,T.TableLastModifyDT 80 | ,T.TableFirstModifyDT 81 | ,PU.ProjectionUniqueExtractUsers 82 | ,PU.ProjectionExtractTransactions 83 | ,PU.ProjectionDaysSinceLastExtract 84 | ,PU.ProjectionLastExtractDT 85 | ,PU.ProjectionFirstExtractDT 86 | ,PU.ProjectionDaysSinceLastModify 87 | ,PU.ProjectionLastModifyDT 88 | ,PU.ProjectionFirstModifyDT 89 | FROM v_catalog.projections AS P 90 | LEFT JOIN 91 | (SELECT 92 | node_name 93 | ,projection_id 94 | ,projection_name 95 | ,projection_schema 96 | ,projection_column_count 97 | ,row_count 98 | ,used_bytes 99 | ,wos_row_count 100 | ,wos_used_bytes 101 | ,ros_row_count 102 | ,ros_used_bytes 103 | ,ros_count 104 | ,anchor_table_name AS table_name 105 | ,anchor_table_schema AS table_schema 106 | ,anchor_table_id AS table_id 107 | FROM v_monitor.projection_storage ) AS PS 108 | ON P.projection_id=PS.projection_id 109 | LEFT JOIN 110 | (SELECT 111 | table_id 112 | ,COUNT(DISTINCT CASE WHEN COALESCE(IsExtract,0)=1 THEN user_name ELSE NULL END) AS TableUniqueExtractUsers 113 | ,COUNT(NULLIFZERO(IsExtract)*transaction_id) AS TableExtractTransactions 114 | ,MIN(DaysSinceLastExtract) AS TableDaysSinceLastExtract 115 | ,MIN(DaysSinceLastModify) AS TableDaysSinceLastModify 116 | ,MAX(ExtractDT) AS TableLastExtractDT 117 | ,MAX(ModifyDT) AS TableLastModifyDT 118 | ,MIN(ExtractDT) AS TableFirstExtractDT 119 | ,MIN(ModifyDT) AS TableFirstModifyDT 120 | FROM 121 | (SELECT 122 | transaction_id 123 | ,user_name 124 | ,anchor_table_id as table_id 125 | ,projection_id 126 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END AS ExtractDT 127 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END AS ModifyDT 128 | ,CASE WHEN io_type LIKE 'input' THEN 1 ELSE 0 END AS IsExtract 129 | ,CASE WHEN io_type LIKE 'output' THEN 1 ELSE 0 END AS IsModify 130 | ,DATEDIFF('DAY' 131 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END 132 | ,GETDATE()) AS DaysSinceLastExtract 133 | ,DATEDIFF('DAY' 134 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END 135 | ,GETDATE()) AS DaysSinceLastModify 136 | FROM v_monitor.projection_usage 137 | UNION 138 | SELECT 139 | transaction_id 140 | ,user_name 141 | ,anchor_table_id as table_id 142 | ,projection_id 143 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END AS ExtractDT 144 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END AS ModifyDT 145 | ,CASE WHEN io_type LIKE 'input' THEN 1 ELSE 0 END AS IsExtract 146 | ,CASE WHEN io_type LIKE 'output' THEN 1 ELSE 0 END AS IsModify 147 | ,DATEDIFF('DAY' 148 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END 149 | ,GETDATE()) AS DaysSinceLastExtract 150 | ,DATEDIFF('DAY' 151 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END 152 | ,GETDATE()) AS DaysSinceLastModify 153 | FROM vstb.projection_usage ) AS B1 154 | GROUP BY table_id) AS T 155 | ON PS.table_id = T.table_id 156 | LEFT JOIN 157 | (SELECT 158 | projection_id 159 | ,COUNT(DISTINCT CASE WHEN COALESCE(IsExtract,0)=1 THEN user_name ELSE NULL END) AS ProjectionUniqueExtractUsers 160 | ,COUNT(NULLIFZERO(IsExtract)*transaction_id) AS ProjectionExtractTransactions 161 | ,MIN(DaysSinceLastExtract) AS ProjectionDaysSinceLastExtract 162 | ,MIN(DaysSinceLastModify) AS ProjectionDaysSinceLastModify 163 | ,MAX(ExtractDT) AS ProjectionLastExtractDT 164 | ,MAX(ModifyDT) AS ProjectionLastModifyDT 165 | ,MIN(ExtractDT) AS ProjectionFirstExtractDT 166 | ,MIN(ModifyDT) AS ProjectionFirstModifyDT 167 | FROM 168 | (SELECT 169 | transaction_id 170 | ,user_name 171 | ,anchor_table_id as table_id 172 | ,projection_id 173 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END AS ExtractDT 174 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END AS ModifyDT 175 | ,CASE WHEN io_type LIKE 'input' THEN 1 ELSE 0 END AS IsExtract 176 | ,CASE WHEN io_type LIKE 'output' THEN 1 ELSE 0 END AS IsModify 177 | ,DATEDIFF('DAY' 178 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END 179 | ,GETDATE()) AS DaysSinceLastExtract 180 | ,DATEDIFF('DAY' 181 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END 182 | ,GETDATE()) AS DaysSinceLastModify 183 | FROM v_monitor.projection_usage 184 | UNION 185 | SELECT 186 | transaction_id 187 | ,user_name 188 | ,anchor_table_id as table_id 189 | ,projection_id 190 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END AS ExtractDT 191 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END AS ModifyDT 192 | ,CASE WHEN io_type LIKE 'input' THEN 1 ELSE 0 END AS IsExtract 193 | ,CASE WHEN io_type LIKE 'output' THEN 1 ELSE 0 END AS IsModify 194 | ,DATEDIFF('DAY' 195 | ,CASE WHEN io_type LIKE 'input' THEN query_start_timestamp::DATE ELSE NULL END 196 | ,GETDATE()) AS DaysSinceLastExtract 197 | ,DATEDIFF('DAY' 198 | ,CASE WHEN io_type LIKE 'output' THEN query_start_timestamp::DATE ELSE NULL END 199 | ,GETDATE()) AS DaysSinceLastModify 200 | FROM vstb.projection_usage ) AS B1 201 | GROUP BY projection_id) AS PU 202 | ON P.projection_id = PU.projection_id 203 | LEFT JOIN 204 | (SELECT 205 | schema_name AS projection_schema 206 | ,projection_name 207 | ,SUM(deleted_row_count) AS deleted_row_count 208 | ,SUM(used_bytes) AS deleted_used_bytes 209 | FROM v_monitor.delete_vectors 210 | GROUP BY 211 | schema_name 212 | ,projection_name ) AS D 213 | ON P.projection_schema=D.projection_schema 214 | AND P.projection_name=D.projection_name 215 | LEFT JOIN 216 | (SELECT projection_id 217 | ,MIN(statistics_updated_timestamp)::DATE AS full_statistics_last_updated 218 | FROM v_catalog.projection_columns 219 | WHERE statistics_type LIKE 'FULL' 220 | GROUP BY projection_id) AS PC 221 | ON P.projection_id = PC.projection_id 222 | ORDER BY 223 | PS.table_schema 224 | ,PS.table_name 225 | ,PS.projection_schema 226 | ,PS.projection_name 227 | ,P.projection_basename 228 | ,PS.node_name 229 | ; 230 | 231 | 232 | 233 | -- ###Performance 234 | -- **vRunningQueries** 235 | -- **vLongRunningQueries** 236 | -- **vQueryPlanProfiles** 237 | -- **vLongRunningQueriesHistory** 238 | -- **vQueryPlanProfilesHistory** 239 | 240 | --========================================================================= 241 | --Create vLongRunningQueriesHistory 242 | --========================================================================= 243 | DROP VIEW IF EXISTS vstb.vLongRunningQueriesHistory; 244 | 245 | CREATE VIEW vstb.vLongRunningQueriesHistory 246 | AS 247 | SELECT 248 | node_name 249 | ,user_name 250 | ,start_timestamp 251 | ,end_timestamp 252 | ,(COALESCE(end_timestamp,GETDATE()) - start_timestamp)::INTERVAL AS request_duration 253 | ,request_duration_ms 254 | ,success 255 | ,is_executing 256 | ,REGEXP_REPLACE(request,'[\r\n\t]',' ') AS request 257 | ,'SELECT CLOSE_SESSION(''' || session_id || ''');' AS CloseSession 258 | ,session_id 259 | ,transaction_id 260 | ,statement_id 261 | ,request_type 262 | ,request_label 263 | ,search_path 264 | ,memory_acquired_mb 265 | ,error_count 266 | ,request_id 267 | ,GETDATE() AS Today 268 | FROM query_requests 269 | UNION 270 | SELECT 271 | node_name 272 | ,user_name 273 | ,start_timestamp 274 | ,end_timestamp 275 | ,(COALESCE(end_timestamp,GETDATE()) - start_timestamp)::INTERVAL AS request_duration 276 | ,request_duration_ms 277 | ,success 278 | ,is_executing 279 | ,REGEXP_REPLACE(request,'[\r\n\t]',' ') AS request 280 | ,'SELECT CLOSE_SESSION(''' || session_id || ''');' AS CloseSession 281 | ,session_id 282 | ,transaction_id 283 | ,statement_id 284 | ,request_type 285 | ,request_label 286 | ,search_path 287 | ,memory_acquired_mb 288 | ,error_count 289 | ,request_id 290 | ,GETDATE() AS Today 291 | FROM vstb.query_requests 292 | ORDER BY request_duration_ms DESC 293 | ; 294 | 295 | 296 | 297 | --========================================================================= 298 | --Create vProjectionGrowthOverTimeWeekly 299 | --This table measures compressed storage over multiple projections 300 | --Space usage reported is not RAW data. 301 | --========================================================================= 302 | DROP VIEW IF EXISTS vstb.vProjectionGrowthOverTimeWeekly; 303 | 304 | CREATE VIEW vstb.vProjectionGrowthOverTimeWeekly 305 | AS 306 | SELECT 307 | node_name 308 | ,projection_name 309 | ,projection_schema 310 | ,anchor_table_name 311 | ,anchor_table_schema 312 | ,slice_time_week 313 | ,used_bytes 314 | ,used_bytes/1E9 AS used_GB 315 | ,LAG(used_bytes,1,0) OVER ( 316 | PARTITION BY 317 | node_name 318 | ,projection_name 319 | ,projection_schema 320 | ,anchor_table_name 321 | ,anchor_table_schema 322 | ORDER BY slice_time_week ASC) AS used_bytes_previous 323 | ,used_bytes - 324 | LAG(used_bytes,1,0) OVER ( 325 | PARTITION BY 326 | node_name 327 | ,projection_name 328 | ,projection_schema 329 | ,anchor_table_name 330 | ,anchor_table_schema 331 | ORDER BY slice_time_week ASC) AS difference 332 | FROM ( 333 | SELECT slice_time::DATE+6 as slice_time_week 334 | ,node_name 335 | ,projection_name 336 | ,projection_schema 337 | ,anchor_table_name 338 | ,anchor_table_schema 339 | ,TS_LAST_VALUE(used_bytes, 'CONST') AS used_bytes 340 | ,TS_LAST_VALUE(row_count, 'CONST') AS row_count 341 | FROM vstb.projection_storage 342 | WHERE 1 = 1 343 | AND projection_schema NOT LIKE 'v_%' 344 | TIMESERIES slice_time AS '1 WEEK' 345 | OVER (PARTITION BY 346 | node_name 347 | ,projection_name 348 | ,projection_schema 349 | ,anchor_table_name 350 | ,anchor_table_schema 351 | ORDER BY last_refresh_ts) 352 | ) AS T 353 | ORDER BY 354 | node_name 355 | ,projection_name 356 | ,projection_schema 357 | ,anchor_table_name 358 | ,anchor_table_schema 359 | ,slice_time_week 360 | ; 361 | 362 | 363 | 364 | 365 | 366 | 367 | 368 | 369 | 370 | 371 | 372 | -------------------------------------------------------------------------------- /sql/merge/load_vstb_tables.sql: -------------------------------------------------------------------------------- 1 | --=========================================================================== 2 | -- Merge data into the historical tables. 3 | -- T=Target 4 | -- S=Source 5 | -- vstb.dc_projections_used 6 | -- 20131126 - DH - Creation 7 | --============================================================================ 8 | 9 | --========================================================================= 10 | -- Define Parameters 11 | --========================================================================= 12 | \set query_duration_seconds 0 13 | 14 | \set AUTOCOMMIT on 15 | \set ON_ERROR_STOP on 16 | 17 | 18 | \qecho ========================================================================= 19 | \qecho projection_usage 20 | \qecho ========================================================================= 21 | INSERT /*+direct, label(load_historical$v0_1$projection_usage) */ 22 | INTO vstb.projection_usage 23 | ( 24 | query_start_timestamp 25 | ,node_name 26 | ,user_name 27 | ,session_id 28 | ,request_id 29 | ,transaction_id 30 | ,statement_id 31 | ,io_type 32 | ,projection_id 33 | ,projection_name 34 | ,anchor_table_id 35 | ,anchor_table_schema 36 | ,anchor_table_name 37 | ) 38 | SELECT 39 | query_start_timestamp 40 | ,node_name 41 | ,user_name 42 | ,session_id 43 | ,request_id 44 | ,transaction_id 45 | ,statement_id 46 | ,io_type 47 | ,projection_id 48 | ,projection_name 49 | ,anchor_table_id 50 | ,anchor_table_schema 51 | ,anchor_table_name 52 | FROM v_monitor.projection_usage 53 | WHERE anchor_table_schema NOT LIKE 'v_%' -- exclude system projections 54 | EXCEPT 55 | SELECT 56 | query_start_timestamp 57 | ,node_name 58 | ,user_name 59 | ,session_id 60 | ,request_id 61 | ,transaction_id 62 | ,statement_id 63 | ,io_type 64 | ,projection_id 65 | ,projection_name 66 | ,anchor_table_id 67 | ,anchor_table_schema 68 | ,anchor_table_name 69 | FROM vstb.projection_usage 70 | WHERE query_start_timestamp >= (SELECT MIN(query_start_timestamp) 71 | FROM v_monitor.projection_usage) 72 | ; 73 | 74 | 75 | 76 | \qecho ========================================================================= 77 | \qecho execution_engine_profiles 78 | \qecho ========================================================================= 79 | INSERT /*+direct, label(load_historical$v0_1$execution_engine_profiles) */ 80 | INTO vstb.execution_engine_profiles 81 | ( 82 | node_name 83 | ,user_id 84 | ,user_name 85 | ,session_id 86 | ,transaction_id 87 | ,statement_id 88 | ,plan_id 89 | ,operator_name 90 | ,operator_id 91 | ,baseplan_id 92 | ,path_id 93 | ,localplan_id 94 | ,activity_id 95 | ,resource_id 96 | ,counter_name 97 | ,counter_tag 98 | ,counter_value 99 | ,is_executing 100 | ) 101 | SELECT 102 | node_name 103 | ,user_id 104 | ,user_name 105 | ,session_id 106 | ,transaction_id 107 | ,statement_id 108 | ,plan_id 109 | ,operator_name 110 | ,operator_id 111 | ,baseplan_id 112 | ,path_id 113 | ,localplan_id 114 | ,activity_id 115 | ,resource_id 116 | ,counter_name 117 | ,counter_tag 118 | ,counter_value 119 | ,is_executing 120 | FROM execution_engine_profiles 121 | WHERE is_executing = 0 122 | AND transaction_id <> 0 123 | EXCEPT 124 | SELECT 125 | node_name 126 | ,user_id 127 | ,user_name 128 | ,session_id 129 | ,transaction_id 130 | ,statement_id 131 | ,plan_id 132 | ,operator_name 133 | ,operator_id 134 | ,baseplan_id 135 | ,path_id 136 | ,localplan_id 137 | ,activity_id 138 | ,resource_id 139 | ,counter_name 140 | ,counter_tag 141 | ,counter_value 142 | ,is_executing 143 | FROM vstb.execution_engine_profiles 144 | WHERE (node_name, user_id, session_id, transaction_id, statement_id) 145 | IN (SELECT DISTINCT 146 | node_name, user_id, session_id, transaction_id, statement_id 147 | FROM execution_engine_profiles ) 148 | ; 149 | 150 | 151 | \qecho ========================================================================= 152 | \qecho vstb.load_streams 153 | \qecho Only pick up statistics for completed load jobs 154 | \qecho ========================================================================= 155 | INSERT /*+direct, label(load_historical$v0_1$load_streams) */ 156 | INTO vstb.load_streams 157 | ( 158 | session_id 159 | ,transaction_id 160 | ,statement_id 161 | ,stream_name 162 | ,schema_name 163 | ,table_id 164 | ,table_name 165 | ,load_start 166 | ,load_duration_ms 167 | ,is_executing 168 | ,accepted_row_count 169 | ,rejected_row_count 170 | ,read_bytes 171 | ,input_file_size_bytes 172 | ,parse_complete_percent 173 | ,unsorted_row_count 174 | ,sorted_row_count 175 | ,sort_complete_percent 176 | ) 177 | SELECT 178 | session_id 179 | ,transaction_id 180 | ,statement_id 181 | ,stream_name 182 | ,schema_name 183 | ,table_id 184 | ,table_name 185 | ,load_start 186 | ,load_duration_ms 187 | ,is_executing 188 | ,accepted_row_count 189 | ,rejected_row_count 190 | ,read_bytes 191 | ,input_file_size_bytes 192 | ,parse_complete_percent 193 | ,unsorted_row_count 194 | ,sorted_row_count 195 | ,sort_complete_percent 196 | FROM v_monitor.load_streams 197 | WHERE is_executing = 0 198 | EXCEPT 199 | SELECT 200 | session_id 201 | ,transaction_id 202 | ,statement_id 203 | ,stream_name 204 | ,schema_name 205 | ,table_id 206 | ,table_name 207 | ,load_start 208 | ,load_duration_ms 209 | ,is_executing 210 | ,accepted_row_count 211 | ,rejected_row_count 212 | ,read_bytes 213 | ,input_file_size_bytes 214 | ,parse_complete_percent 215 | ,unsorted_row_count 216 | ,sorted_row_count 217 | ,sort_complete_percent 218 | FROM vstb.load_streams 219 | WHERE ( session_id, transaction_id, statement_id ) 220 | IN (SELECT DISTINCT 221 | session_id, transaction_id, statement_id 222 | FROM v_monitor.load_streams ) 223 | ; 224 | 225 | \qecho ========================================================================= 226 | \qecho vstb.query_events 227 | \qecho ========================================================================= 228 | INSERT /*+direct, label(load_historical$v0_1$query_events) */ 229 | INTO vstb.query_events 230 | ( 231 | event_timestamp 232 | ,node_name 233 | ,user_id 234 | ,user_name 235 | ,session_id 236 | ,request_id 237 | ,transaction_id 238 | ,statement_id 239 | ,event_category 240 | ,event_type 241 | ,event_description 242 | ,operator_name 243 | ,path_id 244 | ,object_id 245 | ,event_details 246 | ,suggested_action 247 | ) 248 | SELECT 249 | event_timestamp 250 | ,node_name 251 | ,user_id 252 | ,user_name 253 | ,session_id 254 | ,request_id 255 | ,transaction_id 256 | ,statement_id 257 | ,event_category 258 | ,event_type 259 | ,event_description 260 | ,operator_name 261 | ,path_id 262 | ,object_id 263 | ,event_details 264 | ,suggested_action 265 | FROM v_monitor.query_events 266 | WHERE transaction_id <> 0 267 | EXCEPT 268 | SELECT 269 | event_timestamp 270 | ,node_name 271 | ,user_id 272 | ,user_name 273 | ,session_id 274 | ,request_id 275 | ,transaction_id 276 | ,statement_id 277 | ,event_category 278 | ,event_type 279 | ,event_description 280 | ,operator_name 281 | ,path_id 282 | ,object_id 283 | ,event_details 284 | ,suggested_action 285 | FROM vstb.query_events 286 | WHERE 287 | ( 288 | event_timestamp 289 | ,user_id 290 | ,session_id 291 | ,transaction_id 292 | ) 293 | IN 294 | ( SELECT DISTINCT 295 | event_timestamp 296 | ,user_id 297 | ,session_id 298 | ,transaction_id 299 | FROM v_monitor.query_events ) 300 | ; 301 | 302 | 303 | 304 | \qecho ========================================================================= 305 | \qecho vstb.query_plan_profiles 306 | \qecho Only select records from completed queries. 307 | \qecho Only select records where queries run time >= :query_duration_seconds 308 | \qecho ========================================================================= 309 | INSERT /*+direct, label(load_historical$v0_1$query_plan_profiles) */ 310 | INTO vstb.query_plan_profiles 311 | ( 312 | transaction_id 313 | ,statement_id 314 | ,path_id 315 | ,path_line_index 316 | ,path_is_started 317 | ,path_is_completed 318 | ,is_executing 319 | ,running_time 320 | ,memory_allocated_bytes 321 | ,read_from_disk_bytes 322 | ,received_bytes 323 | ,sent_bytes 324 | ,path_line 325 | ) 326 | SELECT 327 | S.transaction_id 328 | ,S.statement_id 329 | ,S.path_id 330 | ,S.path_line_index 331 | ,S.path_is_started 332 | ,S.path_is_completed 333 | ,S.is_executing 334 | ,S.running_time 335 | ,S.memory_allocated_bytes 336 | ,S.read_from_disk_bytes 337 | ,S.received_bytes 338 | ,S.sent_bytes 339 | ,S.path_line 340 | FROM v_monitor.query_plan_profiles AS S 341 | LEFT JOIN 342 | (SELECT DISTINCT 343 | transaction_id 344 | ,statement_id 345 | FROM vstb.query_plan_profiles) AS T 346 | ON S.transaction_id = T.transaction_id 347 | AND S.statement_id = T.statement_id 348 | JOIN v_monitor.query_profiles AS QP 349 | ON S.transaction_id = QP.transaction_id 350 | AND S.statement_id = QP.statement_id 351 | WHERE T.transaction_id IS NULL 352 | AND S.transaction_id <> 0 353 | AND QP.is_executing = 0 354 | AND QP.query_duration_us >= CASE WHEN :query_duration_seconds = 0 355 | THEN 0 356 | ELSE ( :query_duration_seconds * 1e6)::INT 357 | END 358 | ; 359 | 360 | 361 | \qecho ========================================================================= 362 | \qecho vstb.query_profiles 363 | \qecho ========================================================================= 364 | INSERT /*+direct, label(load_historical$v0_1$query_profiles) */ 365 | INTO vstb.query_profiles 366 | ( 367 | session_id 368 | ,transaction_id 369 | ,statement_id 370 | ,identifier 371 | ,node_name 372 | ,query 373 | ,query_search_path 374 | ,schema_name 375 | ,table_name 376 | ,projections_used 377 | ,query_duration_us 378 | ,query_start_epoch 379 | ,query_start 380 | ,query_type 381 | ,error_code 382 | ,user_name 383 | ,processed_row_count 384 | ,reserved_extra_memory 385 | ,is_executing 386 | ) 387 | SELECT 388 | session_id 389 | ,transaction_id 390 | ,statement_id 391 | ,identifier 392 | ,node_name 393 | ,query 394 | ,query_search_path 395 | ,schema_name 396 | ,table_name 397 | ,projections_used 398 | ,query_duration_us 399 | ,query_start_epoch 400 | ,query_start 401 | ,query_type 402 | ,error_code 403 | ,user_name 404 | ,processed_row_count 405 | ,reserved_extra_memory 406 | ,is_executing 407 | FROM query_profiles 408 | WHERE transaction_id <> 0 409 | AND is_executing=0 410 | AND query_type in ('LOAD','QUERY','UTILITY') 411 | EXCEPT 412 | SELECT 413 | session_id 414 | ,transaction_id 415 | ,statement_id 416 | ,identifier 417 | ,node_name 418 | ,query 419 | ,query_search_path 420 | ,schema_name 421 | ,table_name 422 | ,projections_used 423 | ,query_duration_us 424 | ,query_start_epoch 425 | ,query_start 426 | ,query_type 427 | ,error_code 428 | ,user_name 429 | ,processed_row_count 430 | ,reserved_extra_memory 431 | ,is_executing 432 | FROM vstb.query_profiles 433 | WHERE query_start >= (SELECT MIN(query_start) FROM query_profiles) 434 | ; 435 | 436 | 437 | 438 | \qecho ========================================================================= 439 | \qecho vstb.query_requests 440 | \qecho ========================================================================= 441 | INSERT /*+direct, label(load_historical$v0_1$query_requests) */ 442 | INTO vstb.query_requests 443 | ( 444 | node_name 445 | ,user_name 446 | ,session_id 447 | ,request_id 448 | ,transaction_id 449 | ,statement_id 450 | ,request_type 451 | ,request 452 | ,request_label 453 | ,search_path 454 | ,memory_acquired_mb 455 | ,success 456 | ,error_count 457 | ,start_timestamp 458 | ,end_timestamp 459 | ,request_duration_ms 460 | ,is_executing 461 | ) 462 | SELECT 463 | node_name 464 | ,user_name 465 | ,session_id 466 | ,request_id 467 | ,transaction_id 468 | ,statement_id 469 | ,request_type 470 | ,request 471 | ,request_label 472 | ,search_path 473 | ,memory_acquired_mb 474 | ,success 475 | ,error_count 476 | ,start_timestamp 477 | ,end_timestamp 478 | ,request_duration_ms 479 | ,is_executing 480 | FROM v_monitor.query_requests 481 | WHERE is_executing=0 482 | AND transaction_id <> 0 483 | AND request_type IN ('LOAD','QUERY','UTILITY') 484 | EXCEPT 485 | SELECT 486 | node_name 487 | ,user_name 488 | ,session_id 489 | ,request_id 490 | ,transaction_id 491 | ,statement_id 492 | ,request_type 493 | ,request 494 | ,request_label 495 | ,search_path 496 | ,memory_acquired_mb 497 | ,success 498 | ,error_count 499 | ,start_timestamp 500 | ,end_timestamp 501 | ,request_duration_ms 502 | ,is_executing 503 | FROM vstb.query_requests 504 | WHERE start_timestamp >= (SELECT MIN(start_timestamp) 505 | FROM v_monitor.query_requests) 506 | ; 507 | 508 | \qecho ========================================================================= 509 | \qecho vstb.resource_rejection_details 510 | \qecho ========================================================================= 511 | INSERT /*+direct, label(load_historical$v0_1$resource_rejection_details) */ 512 | INTO vstb.resource_rejection_details 513 | ( 514 | rejected_timestamp 515 | ,node_name 516 | ,user_name 517 | ,session_id 518 | ,request_id 519 | ,transaction_id 520 | ,statement_id 521 | ,pool_id 522 | ,pool_name 523 | ,reason 524 | ,resource_type 525 | ,rejected_value 526 | ) 527 | SELECT 528 | rejected_timestamp 529 | ,node_name 530 | ,user_name 531 | ,session_id 532 | ,request_id 533 | ,transaction_id 534 | ,statement_id 535 | ,pool_id 536 | ,pool_name 537 | ,reason 538 | ,resource_type 539 | ,rejected_value 540 | FROM v_monitor.resource_rejection_details 541 | WHERE transaction_id <> 0 542 | EXCEPT 543 | SELECT 544 | rejected_timestamp 545 | ,node_name 546 | ,user_name 547 | ,session_id 548 | ,request_id 549 | ,transaction_id 550 | ,statement_id 551 | ,pool_id 552 | ,pool_name 553 | ,reason 554 | ,resource_type 555 | ,rejected_value 556 | FROM vstb.resource_rejection_details 557 | WHERE rejected_timestamp >= (SELECT MIN(rejected_timestamp) 558 | FROM v_monitor.resource_rejection_details) 559 | ; 560 | 561 | 562 | \qecho ========================================================================= 563 | \qecho vstb.user_sessions 564 | \qecho ========================================================================= 565 | INSERT /*+direct, label(load_historical$v0_1$user_sessions) */ 566 | INTO vstb.user_sessions 567 | ( 568 | node_name 569 | ,user_name 570 | ,session_id 571 | ,transaction_id 572 | ,statement_id 573 | ,session_start_timestamp 574 | ,session_end_timestamp 575 | ,is_active 576 | ,client_hostname 577 | ,client_pid 578 | ,client_label 579 | ,ssl_state 580 | ,authentication_method 581 | ) 582 | SELECT 583 | node_name 584 | ,user_name 585 | ,session_id 586 | ,transaction_id 587 | ,statement_id 588 | ,session_start_timestamp 589 | ,session_end_timestamp 590 | ,is_active 591 | ,client_hostname 592 | ,client_pid 593 | ,client_label 594 | ,ssl_state 595 | ,authentication_method 596 | FROM v_monitor.user_sessions 597 | WHERE is_active=0 598 | EXCEPT 599 | SELECT 600 | node_name 601 | ,user_name 602 | ,session_id 603 | ,transaction_id 604 | ,statement_id 605 | ,session_start_timestamp 606 | ,session_end_timestamp 607 | ,is_active 608 | ,client_hostname 609 | ,client_pid 610 | ,client_label 611 | ,ssl_state 612 | ,authentication_method 613 | FROM vstb.user_sessions 614 | WHERE session_start_timestamp >= (SELECT MIN(session_start_timestamp) 615 | FROM v_monitor.user_sessions) 616 | ; 617 | 618 | 619 | 620 | \qecho ========================================================================= 621 | \qecho vstb.transactions 622 | \qecho end_timestamp=NULL for transactions that are in process. 623 | \qecho ========================================================================= 624 | INSERT /*+direct, label(load_historical$v0_1$transactions) */ 625 | INTO vstb.transactions 626 | ( 627 | start_timestamp 628 | ,end_timestamp 629 | ,node_name 630 | ,user_id 631 | ,user_name 632 | ,session_id 633 | ,transaction_id 634 | ,description 635 | ,start_epoch 636 | ,end_epoch 637 | ,number_of_statements 638 | ,isolation 639 | ,is_read_only 640 | ,is_committed 641 | ,is_local 642 | ,is_initiator 643 | ,is_ddl 644 | ) 645 | SELECT DISTINCT 646 | start_timestamp 647 | ,end_timestamp 648 | ,node_name 649 | ,user_id 650 | ,user_name 651 | ,session_id 652 | ,transaction_id 653 | ,description 654 | ,start_epoch 655 | ,end_epoch 656 | ,number_of_statements 657 | ,isolation 658 | ,is_read_only 659 | ,is_committed 660 | ,is_local 661 | ,is_initiator 662 | ,is_ddl 663 | FROM v_monitor.transactions 664 | WHERE end_timestamp IS NOT NULL -- completed transactions 665 | AND transaction_id <> 0 666 | AND (COALESCE(is_ddl,FALSE)=FALSE 667 | /* OR transaction_id IN 668 | (SELECT DISTINCT transaction_id 669 | FROM v_monitor.query_requests 670 | WHERE transaction_id <> 0 671 | AND request_type IN ('LOAD','QUERY','UTILITY') */ 672 | ) 673 | EXCEPT 674 | SELECT 675 | start_timestamp 676 | ,end_timestamp 677 | ,node_name 678 | ,user_id 679 | ,user_name 680 | ,session_id 681 | ,transaction_id 682 | ,description 683 | ,start_epoch 684 | ,end_epoch 685 | ,number_of_statements 686 | ,isolation 687 | ,is_read_only 688 | ,is_committed 689 | ,is_local 690 | ,is_initiator 691 | ,is_ddl 692 | FROM vstb.transactions 693 | WHERE start_timestamp >= (SELECT MIN(start_timestamp) FROM v_monitor.transactions) 694 | ; 695 | 696 | 697 | \qecho ========================================================================= 698 | \qecho vstb.projection_storage 699 | \qecho ========================================================================= 700 | INSERT /*+direct, label(load_historical$v0_1$projection_storage) */ 701 | INTO vstb.projection_storage 702 | ( 703 | node_name 704 | ,projection_id 705 | ,projection_name 706 | ,projection_schema 707 | ,projection_column_count 708 | ,row_count 709 | ,used_bytes 710 | ,wos_row_count 711 | ,wos_used_bytes 712 | ,ros_row_count 713 | ,ros_used_bytes 714 | ,ros_count 715 | ,anchor_table_name 716 | ,anchor_table_schema 717 | ,anchor_table_id 718 | ,last_refresh_ts 719 | ) 720 | SELECT 721 | node_name 722 | ,projection_id 723 | ,projection_name 724 | ,projection_schema 725 | ,projection_column_count 726 | ,row_count 727 | ,used_bytes 728 | ,wos_row_count 729 | ,wos_used_bytes 730 | ,ros_row_count 731 | ,ros_used_bytes 732 | ,ros_count 733 | ,anchor_table_name 734 | ,anchor_table_schema 735 | ,anchor_table_id 736 | ,TRANSACTION_TIMESTAMP() AS last_refresh_ts 737 | FROM v_monitor.projection_storage 738 | ; 739 | 740 | \qecho ========================================================================= 741 | \qecho Delete records from earlier in the day to save space. 742 | \qecho ========================================================================= 743 | DELETE FROM vstb.projection_storage 744 | WHERE last_refresh_ts::DATE = (SELECT MAX(last_refresh_ts)::DATE 745 | FROM vstb.projection_storage) 746 | AND last_refresh_ts < (SELECT MAX(last_refresh_ts) 747 | FROM vstb.projection_storage); 748 | 749 | 750 | 751 | \qecho ========================================================================= 752 | \qecho dc_execution_engine_events 753 | \qecho ========================================================================= 754 | INSERT /*+direct, label(load_historical$v0_1$dc_execution_engine_events) */ 755 | INTO vstb.dc_execution_engine_events 756 | ( 757 | time 758 | ,node_name 759 | ,session_id 760 | ,user_id 761 | ,user_name 762 | ,transaction_id 763 | ,statement_id 764 | ,request_id 765 | ,event_type 766 | ,event_description 767 | ,operator_name 768 | ,path_id 769 | ,event_oid 770 | ,event_details 771 | ,suggested_action 772 | ) 773 | SELECT 774 | time 775 | ,node_name 776 | ,session_id 777 | ,user_id 778 | ,user_name 779 | ,transaction_id 780 | ,statement_id 781 | ,request_id 782 | ,event_type 783 | ,event_description 784 | ,operator_name 785 | ,path_id 786 | ,event_oid 787 | ,event_details 788 | ,suggested_action 789 | FROM dc_execution_engine_events 790 | WHERE transaction_id <> 0 791 | EXCEPT 792 | SELECT 793 | time 794 | ,node_name 795 | ,session_id 796 | ,user_id 797 | ,user_name 798 | ,transaction_id 799 | ,statement_id 800 | ,request_id 801 | ,event_type 802 | ,event_description 803 | ,operator_name 804 | ,path_id 805 | ,event_oid 806 | ,event_details 807 | ,suggested_action 808 | FROM vstb.dc_execution_engine_events 809 | WHERE time >= (SELECT MIN(time) FROM dc_execution_engine_events) 810 | ; 811 | 812 | 813 | \qecho ========================================================================= 814 | \qecho system_resource_usage 815 | \qecho ========================================================================= 816 | INSERT /*+direct, label(load_historical$v0_1$system_resource_usage) */ 817 | INTO vstb.system_resource_usage 818 | ( 819 | node_name 820 | ,end_time 821 | ,average_memory_usage_percent 822 | ,average_cpu_usage_percent 823 | ,net_rx_kbytes_per_second 824 | ,net_tx_kbytes_per_second 825 | ,io_read_kbytes_per_second 826 | ,io_written_kbytes_per_second 827 | ) 828 | SELECT 829 | node_name 830 | ,end_time 831 | ,average_memory_usage_percent 832 | ,average_cpu_usage_percent 833 | ,net_rx_kbytes_per_second 834 | ,net_tx_kbytes_per_second 835 | ,io_read_kbytes_per_second 836 | ,io_written_kbytes_per_second 837 | FROM v_monitor.system_resource_usage 838 | WHERE end_time > (SELECT MAX(end_time) from vstb.system_resource_usage) 839 | ; 840 | 841 | \qecho ========================================================================= 842 | \qecho resource_acquisitions 843 | \qecho ========================================================================= 844 | INSERT /*+direct, label(load_historical$v0_1$resource_acquisitions) */ 845 | INTO vstb.resource_acquisitions 846 | ( 847 | node_name 848 | ,transaction_id 849 | ,statement_id 850 | ,request_type 851 | ,pool_id 852 | ,pool_name 853 | ,thread_count 854 | ,open_file_handle_count 855 | ,memory_inuse_kb 856 | ,queue_entry_timestamp 857 | ,acquisition_timestamp 858 | ,release_timestamp 859 | ,duration_ms 860 | ,is_executing 861 | ) 862 | SELECT 863 | node_name 864 | ,transaction_id 865 | ,statement_id 866 | ,request_type 867 | ,pool_id 868 | ,pool_name 869 | ,thread_count 870 | ,open_file_handle_count 871 | ,memory_inuse_kb 872 | ,queue_entry_timestamp 873 | ,acquisition_timestamp 874 | ,release_timestamp 875 | ,duration_ms 876 | ,is_executing 877 | FROM v_monitor.resource_acquisitions 878 | WHERE is_executing=0 879 | AND (transaction_id, statement_id, queue_entry_timestamp) 880 | NOT IN (SELECT transaction_id, statement_id, queue_entry_timestamp FROM vstb.resource_acquisitions) 881 | ; 882 | 883 | 884 | 885 | \qecho ========================================================================= 886 | \qecho Collect Statistics 887 | \qecho ========================================================================= 888 | SELECT ANALYZE_STATISTICS('vstb.dc_execution_engine_events' ); 889 | SELECT ANALYZE_STATISTICS('vstb.projection_usage' ); 890 | SELECT ANALYZE_STATISTICS('vstb.execution_engine_profiles' ); 891 | SELECT ANALYZE_STATISTICS('vstb.load_streams' ); 892 | SELECT ANALYZE_STATISTICS('vstb.projection_storage' ); 893 | SELECT ANALYZE_STATISTICS('vstb.query_events' ); 894 | SELECT ANALYZE_STATISTICS('vstb.query_plan_profiles' ); 895 | SELECT ANALYZE_STATISTICS('vstb.query_profiles' ); 896 | SELECT ANALYZE_STATISTICS('vstb.query_requests' ); 897 | SELECT ANALYZE_STATISTICS('vstb.resource_rejection_details' ); 898 | SELECT ANALYZE_STATISTICS('vstb.user_sessions' ); 899 | SELECT ANALYZE_STATISTICS('vstb.transactions' ); 900 | SELECT ANALYZE_STATISTICS('vstb.system_resource_usage' ); 901 | SELECT ANALYZE_STATISTICS('vstb.resource_acquisitions' ); 902 | 903 | 904 | -------------------------------------------------------------------------------- /sql/merge/purge_deleted_records.sql: -------------------------------------------------------------------------------- 1 | 2 | -------------------------------------------------------------------------------- 3 | -- Purge records if all nodes on the cluster are up. 4 | -- Set the ancient high water mark (AHM) 5 | -- Identify tables in a schema that have records marked for deletion 6 | -- Purge deleted records from those tables 7 | -- If a node is down you will need to manually delete the PurgeProjectionsFile 8 | 9 | -- 20131210v0.1 - DH - Initial Version 10 | -------------------------------------------------------------------------------- 11 | \set AUTOCOMMIT OFF 12 | \set ON_ERROR_STOP on 13 | 14 | -------------------------------------------------------------------------------- 15 | -- Set Variables 16 | -------------------------------------------------------------------------------- 17 | \set SchemaName '''public''' 18 | \set StartDateTime `date "+%Y%m%d%H%M%S"` 19 | \set Program 'Purge Deleted Rows v0.1' 20 | \set PurgeProjectionsFile '/tmp/PurgeRecords.' :StartDateTime '.sql' 21 | \set PurgeProjectionsFileTxt '\'' :PurgeProjectionsFile '\'' 22 | \set 23 | 24 | SELECT GET_AHM_TIME(), GETDATE(); 25 | 26 | \o :PurgeProjectionsFile 27 | \pset tuples_only 28 | 29 | -------------------------------------------------------------------------------- 30 | -- Quit if a node is down. 31 | -------------------------------------------------------------------------------- 32 | SELECT DISTINCT CASE WHEN node_state IS NOT NULL THEN '\q' ELSE '' END AS Action 33 | FROM v_catalog.nodes 34 | WHERE node_state ILIKE 'DOWN'; 35 | 36 | 37 | -------------------------------------------------------------------------------- 38 | -- Throw an error (1/0) if a node is down. 39 | -------------------------------------------------------------------------------- 40 | --SELECT 1/(1-COUNT(DISTINCT node_state)) 41 | --FROM v_catalog.nodes 42 | --WHERE node_state ILIKE 'DOWN'; 43 | 44 | 45 | -------------------------------------------------------------------------------- 46 | -- Dynamically generate SQL and send the SQL to the PurgeProjectionsFiles 47 | -------------------------------------------------------------------------------- 48 | SELECT 'SELECT MAKE_AHM_NOW();' 49 | ; 50 | 51 | -------------------------------------------------------------------------------- 52 | -- Dynamically generate SQL and send the SQL to the PurgeProjectionsFiles 53 | -- If you want to purge all tables then use 54 | -- SELECT 'SELECT PURGE();'; 55 | -------------------------------------------------------------------------------- 56 | SELECT 'SELECT PURGE_PROJECTION(' || '''' 57 | || schema_name || '.' || projection_name || '''' 58 | || ') AS ' || projection_name || ';' 59 | FROM v_monitor.delete_vectors 60 | WHERE schema_name IN ( :SchemaName ) 61 | ; 62 | 63 | -------------------------------------------------------------------------------- 64 | -- Remove the dynamic SQL file when done. 65 | -- Change the rm to a cat when testing to prevent the file from being deleted. 66 | -------------------------------------------------------------------------------- 67 | SELECT '\! rm ' || :PurgeProjectionsFileTxt as RemoveTempFile 68 | ; 69 | 70 | \o 71 | \pset tuples_only 72 | 73 | -------------------------------------------------------------------------------- 74 | -- Set AHM, purge projections, and remove the temp file 75 | -------------------------------------------------------------------------------- 76 | \i :PurgeProjectionsFile 77 | 78 | SELECT GET_AHM_TIME(), GETDATE(); 79 | 80 | \q 81 | -------------------------------------------------------------------------------- /sql/merge/update_statistics.sql: -------------------------------------------------------------------------------- 1 | 2 | -------------------------------------------------------------------------------- 3 | -- Identify tables in a schema that have 4 | -- 1. No Statistics 5 | -- 2. Statistics more than 1 day out of date 6 | -- i.e. (Modify Date - 1 Day) > Date Statistics Last Updated 7 | -- 3. Contain data 8 | -- 9 | -- Collect full statistics on the tables identified above. 10 | -- 20131209v0.1 - DH - Initial Version 11 | -------------------------------------------------------------------------------- 12 | \set AUTOCOMMIT OFF 13 | \set ON_ERROR_STOP on 14 | 15 | -------------------------------------------------------------------------------- 16 | -- Set Variables 17 | -------------------------------------------------------------------------------- 18 | \set SchemaName '''public''' 19 | \set StartDateTime `date "+%Y%m%d%H%M%S"` 20 | \set Program 'Update Statistics v1' 21 | \set AnalyzeStatsFile '/tmp/analyze_statistics.' :StartDateTime '.sql' 22 | \set AnalyzeStatsFileTxt '\'' :AnalyzeStatsFile '\'' 23 | \set 24 | 25 | SELECT GETDATE(); 26 | 27 | \o :AnalyzeStatsFile 28 | \pset tuples_only 29 | 30 | -------------------------------------------------------------------------------- 31 | -- Dynamically generate SQL and send the SQL to the AnalyzeStatsFiles 32 | -------------------------------------------------------------------------------- 33 | SELECT 'SELECT ANALYZE_STATISTICS(' || '''' 34 | || T1.table_schema || '.' || T1.table_name || '''' 35 | || ') AS ' || T1.table_name || ';' 36 | FROM ( 37 | -- Tables with no statistics 38 | SELECT table_id 39 | ,table_schema 40 | ,table_name 41 | FROM v_catalog.projection_columns 42 | WHERE statistics_type NOT LIKE 'FULL' 43 | AND table_schema ILIKE :SchemaName 44 | GROUP BY table_id 45 | ,table_schema 46 | ,table_name 47 | 48 | UNION 49 | 50 | -- Statistics more than 1 day out of date. 51 | SELECT S.table_id 52 | ,S.table_schema 53 | ,S.table_name 54 | FROM ( 55 | -- Tables which have full statistics 56 | SELECT table_id 57 | ,table_schema 58 | ,table_name 59 | ,MIN(statistics_updated_timestamp)::DATE AS full_statistics_last_updated 60 | FROM v_catalog.projection_columns 61 | WHERE statistics_type ILIKE 'FULL' 62 | AND table_schema ILIKE :SchemaName 63 | GROUP BY table_id 64 | ,table_schema 65 | ,table_name 66 | ) AS S 67 | LEFT JOIN ( 68 | -- Tables which have been recently modified 69 | SELECT anchor_table_id AS table_id 70 | ,MAX(query_start_timestamp)::DATE AS last_modified 71 | FROM v_monitor.projection_usage 72 | WHERE io_type ILIKE 'output' 73 | AND anchor_table_schema ILIKE :SchemaName 74 | GROUP BY anchor_table_id 75 | ) M 76 | ON S.table_id = M.table_id 77 | WHERE (M.last_modified - 1) > S.full_statistics_last_updated 78 | ) AS T1 79 | JOIN ( -- Filter out tables with no records 80 | SELECT anchor_table_id as table_id 81 | FROM v_monitor.projection_storage 82 | WHERE ros_count>0 OR wos_used_bytes>0 83 | GROUP BY anchor_table_id 84 | ) as T2 85 | ON T1.table_id=T2.table_id 86 | ; 87 | 88 | -------------------------------------------------------------------------------- 89 | -- Remove the dynamic SQL file when done. 90 | -- Change the rm to a cat when testing to prevent the file from being deleted. 91 | -------------------------------------------------------------------------------- 92 | SELECT '\! rm ' || :AnalyzeStatsFileTxt as RemoveTempFile ; 93 | 94 | \o 95 | \pset tuples_only 96 | 97 | -------------------------------------------------------------------------------- 98 | -- Analyze Statistics and remove the temp file 99 | -------------------------------------------------------------------------------- 100 | \i :AnalyzeStatsFile 101 | 102 | SELECT GETDATE(); 103 | 104 | \q 105 | --------------------------------------------------------------------------------