├── .github └── workflows │ └── ci.yml ├── .gitignore ├── Gemfile ├── LICENSE.txt ├── README.md ├── Rakefile ├── lib ├── rails-sqlite-extras.rb └── rails_sqlite_extras │ ├── queries │ ├── compile_options.sql │ ├── index_size.sql │ ├── integrity_check.sql │ ├── pragma.sql │ ├── sequence_number.sql │ ├── table_size.sql │ └── total_size.sql │ ├── railtie.rb │ ├── tasks │ └── all.rake │ └── version.rb ├── rails-sqlite-extras.gemspec ├── spec ├── smoke_spec.rb └── spec_helper.rb └── test.db /.github/workflows/ci.yml: -------------------------------------------------------------------------------- 1 | name: Ruby CI 2 | 3 | on: 4 | push: 5 | branches: [ main ] 6 | pull_request: 7 | branches: [ main ] 8 | 9 | jobs: 10 | test: 11 | runs-on: ubuntu-latest 12 | strategy: 13 | fail-fast: false 14 | matrix: 15 | ruby-version: ['3.3', '3.2', '3.1'] 16 | steps: 17 | - uses: actions/checkout@v4 18 | - name: Set up Ruby ${{ matrix.ruby-version }} 19 | uses: ruby/setup-ruby@v1 20 | with: 21 | ruby-version: ${{ matrix.ruby-version }} 22 | - name: Setup dependencies 23 | run: | 24 | gem install bundler -v 2.4.22 25 | sudo apt-get update --allow-releaseinfo-change 26 | bundle config set --local path 'vendor/bundle' 27 | bundle config set force_ruby_platform true 28 | bundle config set build.sqlite3 "--with-sqlite-cflags='-DSQLITE_ENABLE_DBSTAT_VTAB=1'" 29 | bundle install 30 | sleep 2 31 | - name: Run tests 32 | run: | 33 | bundle exec rspec spec/ 34 | 35 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | Gemfile.lock 2 | .bundle/ 3 | .ruby-version 4 | pkg/ 5 | *.gem 6 | docker-compose.yml 7 | .byebug_history 8 | 9 | -------------------------------------------------------------------------------- /Gemfile: -------------------------------------------------------------------------------- 1 | source "https://rubygems.org" 2 | 3 | gemspec 4 | -------------------------------------------------------------------------------- /LICENSE.txt: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright © Paweł Urbanek 2024 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining 6 | a copy of this software and associated documentation files (the 7 | "Software"), to deal in the Software without restriction, including 8 | without limitation the rights to use, copy, modify, merge, publish, 9 | distribute, sublicense, and/or sell copies of the Software, and to 10 | permit persons to whom the Software is furnished to do so, subject to 11 | the following conditions: 12 | 13 | The above copyright notice and this permission notice shall be 14 | included in all copies or substantial portions of the Software. 15 | 16 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 17 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 18 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. 19 | IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY 20 | CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, 21 | TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE 22 | SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 23 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Rails Sqlite Extras [![Gem Version](https://badge.fury.io/rb/rails-sqlite-extras.svg)](https://badge.fury.io/rb/rails-sqlite-extras) [![GH Actions](https://github.com/pawurb/rails-sqlite-extras/actions/workflows/ci.yml/badge.svg)](https://github.com/pawurb/rails-sqlite-extras/actions) 2 | 3 | Copy/paste of [ecto_sqlite3_extras](https://github.com/orsinium-labs/ecto_sqlite3_extras). Helper queries available in Ruby and Rails rake tasks providing insights into the Sqlite database. 4 | 5 | ## Installation 6 | 7 | `Gemfile` 8 | ```bash 9 | gem "rails-sqlite-extras" 10 | ``` 11 | 12 | Some queries use `dbstat` table. You have to use [sqlite3 gem](https://github.com/sparklemotion/sqlite3-ruby) with version `>= 2.3.0` because it has this feature enabled by default: 13 | 14 | `Gemfile` 15 | 16 | ```ruby 17 | gem "sqlite3", "~> 2.3" 18 | ``` 19 | 20 | Alternatively, if you're stuck on lower version, you have to enable `dbstat` by setting a `SQLITE_ENABLE_DBSTAT_VTAB` compile flag: 21 | 22 | ```bash 23 | bundle config set force_ruby_platform true 24 | bundle config set build.sqlite3 "--with-sqlite-cflags='-DSQLITE_ENABLE_DBSTAT_VTAB=1'" 25 | ``` 26 | 27 | ## Available queries 28 | 29 | ### `total_size` 30 | 31 | ```bash 32 | rake sqlite_extras:total_size 33 | ``` 34 | 35 | ```ruby 36 | RailsSqliteExtras.total_size 37 | ``` 38 | 39 | The total size of all tables and indices. It's a summary table, it has only 2 columns: `name` and `value`. Rows: 40 | 41 | - `cells`: The number of cells in the DB. Each value stored in the DB is represented as at least one cell. So, the number of cells correlates with the number of records in the DB. 42 | - `payload_size`: How much space the actual useful payload takes in the DB. 43 | - `unused_size`: How much space in the DB is reserved, not used yet, and can be used later to store more data. This is a surplus that occurs because SQLite allocates space for data in chunks ("pages"). 44 | - `vacuum_size`: How much space is unused and cannot be used for future data. You can run [VACUUM](https://www.sqlite.org/lang_vacuum.html) command to reduce it. 45 | - `page_size`: The total space occupied by all pages. Each page is a single chunk of space allocated by SQLite. This number is the sum of `payload_size`, `unused_size`, and `vacuum_size`. 46 | - `pages`: The total number of pages. 47 | - `pages: leaf`: The pages that store the actual data. Read [SQLite Internals: Pages & B-trees](https://fly.io/blog/sqlite-internals-btree/) to learn more. 48 | - `pages: internal`: The pages that store ranges for leaf pages for a faster lookup. Sometimes also called "interior pages". 49 | - `pages: overflow`: The pages that store chunks of big data that don't fit in a single leaf page. 50 | - `pages: table`: The pages used for storing data for tables. 51 | - `pages: index`: The pages used for storing indices. 52 | 53 | ### `table_size` 54 | 55 | ```bash 56 | rake sqlite_extras:table_size 57 | ``` 58 | 59 | ```ruby 60 | RailsSqliteExtras.table_size 61 | ``` 62 | 63 | Information about the space used (and unused) by all tables. Based on the [dbstat](https://www.sqlite.org/dbstat.html) virtual table. 64 | 65 | - `name`: The table name. 66 | - `payload_size`. 67 | - `unused_size`. 68 | - `vacuum_size`. 69 | - `page_size`. 70 | - `cells`. 71 | - `pages`. 72 | - `max_payload_size`: The size of the biggest payload in the table. 73 | 74 | ### `index_size` 75 | 76 | ```bash 77 | rake sqlite_extras:index_size 78 | ``` 79 | 80 | ```ruby 81 | RailsSqliteExtras.index_size 82 | ``` 83 | 84 | Size of all indices. 85 | 86 | - `name`: The index name. 87 | - `table_name`: The table where the index is defined. 88 | - `column_name`: The name of the column being indexed. This column is NULL if the column is the rowid or an expression. 89 | - `payload_size`. 90 | - `unused_size`. 91 | - `page_size`. 92 | - `cells`. 93 | - `pages`. 94 | - `max_payload_size`. 95 | 96 | ### `sequence_number` 97 | 98 | ```bash 99 | rake sqlite_extras:sequence_number 100 | ``` 101 | 102 | ```ruby 103 | RailsSqliteExtras.sequence_number 104 | ``` 105 | 106 | Sequence numbers of autoincrement columns. Generated based on the [sqlite_sequence](https://renenyffenegger.ch/notes/development/databases/SQLite/internals/schema-objects/sqlite_sequence) table. The query will fail if there are no autoincrement columns in the DB yet. 107 | 108 | - `table_name`. 109 | - `sequence_number`. 110 | 111 | ### `pragma` 112 | 113 | ```bash 114 | rake sqlite_extras:pragma 115 | ``` 116 | 117 | ```ruby 118 | RailsSqliteExtras.pragma 119 | ``` 120 | 121 | List values of PRAGMAs (settings). Only includes the ones that have an integer or a boolean value. For brevity, the ones with the `0` (`false`) value are excluded from the output (based on the observation that this is the default value for most of the PRAGMAs). Check out the SQLite documentation to learn more about what each PRAGMA means: [PRAGMA Statements](https://www.sqlite.org/pragma.html). 122 | 123 | - `name`: the name of the PRAGMA as listed in the SQLite documentation. 124 | - `value`: the value of the PRAGMA. The `true` value is converted into `1` (and `false` is simply excluded). 125 | 126 | ### `compile_options` 127 | 128 | ```bash 129 | rake sqlite_extras:compile_options 130 | ``` 131 | 132 | ```ruby 133 | RailsSqliteExtras.compile_options 134 | ``` 135 | 136 | List the [compile-time options](https://www.sqlite.org/compile.html) used when building SQLite, one option per row. The "SQLITE_" prefix is omitted from the returned option names. See [exqlite docs](https://github.com/elixir-sqlite/exqlite#defining-extra-compile-flags) on how to change these options. 137 | 138 | ### `integrity_check` 139 | 140 | ```bash 141 | rake sqlite_extras:integrity_check 142 | ``` 143 | 144 | ```ruby 145 | RailsSqliteExtras.integrity_check 146 | ``` 147 | 148 | Run integrity checks on the database. Executes [PRAGMA integrity_check](https://www.sqlite.org/pragma.html#pragma_integrity_check) and returns the resulting messages. -------------------------------------------------------------------------------- /Rakefile: -------------------------------------------------------------------------------- 1 | require "bundler/gem_tasks" 2 | require "rspec/core/rake_task" 3 | 4 | RSpec::Core::RakeTask.new(:spec) 5 | -------------------------------------------------------------------------------- /lib/rails-sqlite-extras.rb: -------------------------------------------------------------------------------- 1 | # frozen_string_literal: true 2 | 3 | require "terminal-table" 4 | 5 | module RailsSqliteExtras 6 | @@database_url = nil 7 | 8 | QUERIES = %i( 9 | compile_options 10 | index_size 11 | integrity_check 12 | pragma 13 | sequence_number 14 | table_size 15 | total_size 16 | ) 17 | 18 | QUERIES.each do |query_name| 19 | define_singleton_method query_name do |options = {}| 20 | run_query( 21 | query_name: query_name, 22 | in_format: options.fetch(:in_format, :display_table), 23 | ) 24 | end 25 | end 26 | 27 | def self.run_query(query_name:, in_format:) 28 | sql = sql_for(query_name: query_name) 29 | 30 | result = connection.execute(sql) 31 | 32 | self.display_result( 33 | result, 34 | title: self.description_for(query_name: query_name), 35 | in_format: in_format, 36 | ) 37 | end 38 | 39 | def self.display_result(result, title:, in_format:) 40 | case in_format 41 | when :array 42 | result.values 43 | when :hash 44 | result.to_a 45 | when :raw 46 | result 47 | when :display_table 48 | headings = if result.count > 0 49 | result[0].keys 50 | else 51 | ["No results"] 52 | end 53 | 54 | puts Terminal::Table.new( 55 | title: title, 56 | headings: headings, 57 | rows: result.map(&:values), 58 | ) 59 | else 60 | raise "Invalid in_format option" 61 | end 62 | end 63 | 64 | def self.sql_for(query_name:) 65 | File.read( 66 | sql_path_for(query_name: query_name) 67 | ) 68 | end 69 | 70 | def self.description_for(query_name:) 71 | first_line = File.open( 72 | sql_path_for(query_name: query_name) 73 | ) { |f| f.readline } 74 | 75 | first_line[/\/\*(.*?)\*\//m, 1].strip 76 | end 77 | 78 | def self.sql_path_for(query_name:) 79 | File.join(File.dirname(__FILE__), "/rails_sqlite_extras/queries/#{query_name}.sql") 80 | end 81 | 82 | def self.connection 83 | if (db_url = ENV["RAILS_SQLITE_EXTRAS_DATABASE_URL"]) 84 | ActiveRecord::Base.establish_connection(db_url).lease_connection 85 | else 86 | ActiveRecord::Base.connection 87 | end 88 | end 89 | 90 | def self.database_url=(value) 91 | @@database_url = value 92 | end 93 | 94 | def self.database_url 95 | @@database_url || ENV["RUBY_PG_EXTRAS_DATABASE_URL"] || ENV.fetch("DATABASE_URL") 96 | end 97 | end 98 | 99 | require "rails_sqlite_extras/railtie" if defined?(Rails) 100 | -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/queries/compile_options.sql: -------------------------------------------------------------------------------- 1 | /* List the compile-time options used when building SQLite. */ 2 | 3 | SELECT compile_options AS 'value' FROM pragma_compile_options; -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/queries/index_size.sql: -------------------------------------------------------------------------------- 1 | /* Metadata of the indexes, descending by size. */ 2 | 3 | SELECT 4 | d.name AS name, 5 | s.tbl_name AS table_name, 6 | i.name AS column_name, 7 | d.payload AS payload_size, 8 | d.unused AS unused_size, 9 | d.pgsize AS page_size, 10 | d.ncell AS cells, 11 | d.pageno AS pages, 12 | d.mx_payload AS max_payload_size 13 | FROM 14 | dbstat AS d, 15 | sqlite_schema AS s, 16 | pragma_index_info(d.name) AS i 17 | WHERE 18 | d.name = s.name 19 | AND s.type = 'index' 20 | AND d.aggregate = TRUE 21 | ORDER BY page_size DESC; -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/queries/integrity_check.sql: -------------------------------------------------------------------------------- 1 | /* Run integrity checks on the database. */ 2 | 3 | SELECT integrity_check as message 4 | FROM pragma_integrity_check; -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/queries/pragma.sql: -------------------------------------------------------------------------------- 1 | /* List values of PRAGMAs (settings). */ 2 | 3 | SELECT * 4 | FROM ( 5 | SELECT 'analysis_limit' AS name, analysis_limit AS value FROM pragma_analysis_limit 6 | UNION ALL SELECT 'application_id', * FROM pragma_application_id 7 | UNION ALL SELECT 'auto_vacuum', * FROM pragma_auto_vacuum 8 | UNION ALL SELECT 'automatic_index', * FROM pragma_automatic_index 9 | UNION ALL SELECT 'busy_timeout', * FROM pragma_busy_timeout 10 | UNION ALL SELECT 'cache_size', * FROM pragma_cache_size 11 | UNION ALL SELECT 'cache_spill', * FROM pragma_cache_spill 12 | UNION ALL SELECT 'cell_size_check', * FROM pragma_cell_size_check 13 | UNION ALL SELECT 'checkpoint_fullfsync', * FROM pragma_checkpoint_fullfsync 14 | UNION ALL SELECT 'data_version', * FROM pragma_data_version 15 | UNION ALL SELECT 'defer_foreign_keys', * FROM pragma_defer_foreign_keys 16 | UNION ALL SELECT 'freelist_count', * FROM pragma_freelist_count 17 | UNION ALL SELECT 'fullfsync', * FROM pragma_fullfsync 18 | UNION ALL SELECT 'hard_heap_limit', * FROM pragma_hard_heap_limit 19 | UNION ALL SELECT 'ignore_check_constraints', * FROM pragma_ignore_check_constraints 20 | UNION ALL SELECT 'journal_size_limit', * FROM pragma_journal_size_limit 21 | UNION ALL SELECT 'legacy_alter_table', * FROM pragma_legacy_alter_table 22 | UNION ALL SELECT 'max_page_count', * FROM pragma_max_page_count 23 | UNION ALL SELECT 'page_size', * FROM pragma_page_size 24 | UNION ALL SELECT 'query_only', * FROM pragma_query_only 25 | UNION ALL SELECT 'read_uncommitted', * FROM pragma_read_uncommitted 26 | UNION ALL SELECT 'recursive_triggers', * FROM pragma_recursive_triggers 27 | UNION ALL SELECT 'reverse_unordered_selects', * FROM pragma_reverse_unordered_selects 28 | UNION ALL SELECT 'soft_heap_limit', * FROM pragma_soft_heap_limit 29 | UNION ALL SELECT 'synchronous', * FROM pragma_synchronous 30 | UNION ALL SELECT 'temp_store', * FROM pragma_temp_store 31 | UNION ALL SELECT 'threads', * FROM pragma_threads 32 | UNION ALL SELECT 'trusted_schema', * FROM pragma_trusted_schema 33 | UNION ALL SELECT 'user_version', * FROM pragma_user_version 34 | ) 35 | WHERE value != 0 -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/queries/sequence_number.sql: -------------------------------------------------------------------------------- 1 | /* Sequence numbers of autoincrement columns. */ 2 | 3 | SELECT name AS table_name, seq AS sequence_number 4 | FROM sqlite_sequence 5 | ORDER BY sequence_number DESC -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/queries/table_size.sql: -------------------------------------------------------------------------------- 1 | /* Metadata of the tables (excluding indexes), descending by size. */ 2 | SELECT 3 | name, 4 | payload AS payload_size, 5 | unused as unused_size, 6 | pgsize - payload - unused as vacuum_size, 7 | pgsize as page_size, 8 | ncell as cells, 9 | pageno as pages, 10 | mx_payload as max_payload_size 11 | FROM dbstat 12 | WHERE 13 | name IN (SELECT name FROM sqlite_schema WHERE type='table') 14 | AND aggregate=TRUE 15 | ORDER BY page_size DESC; -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/queries/total_size.sql: -------------------------------------------------------------------------------- 1 | /* The total size of all tables and indexes. */ 2 | SELECT 'pages' AS name, MAX(pageno) as value FROM dbstat 3 | UNION ALL SELECT 'cells', SUM(ncell) FROM dbstat 4 | UNION ALL SELECT 'payload_size', SUM(payload) FROM dbstat 5 | UNION ALL SELECT 'unused_size', SUM(unused) FROM dbstat 6 | UNION ALL SELECT 'vacuum_size', SUM(pgsize) - SUM(payload) - SUM(unused) FROM dbstat 7 | UNION ALL SELECT 'page_size', SUM(pgsize) FROM dbstat 8 | 9 | UNION ALL SELECT 'pages: leaf', COUNT(*) 10 | FROM dbstat WHERE pagetype = 'leaf' 11 | UNION ALL SELECT 'pages: internal', COUNT(*) 12 | FROM dbstat WHERE pagetype = 'internal' 13 | UNION ALL SELECT 'pages: overflow', COUNT(*) 14 | FROM dbstat WHERE pagetype = 'overflow' 15 | UNION ALL SELECT 'pages: table', COUNT(*) 16 | FROM dbstat WHERE name IN (SELECT name FROM sqlite_schema WHERE type='table') 17 | UNION ALL SELECT 'pages: index', COUNT(*) 18 | FROM dbstat WHERE name IN (SELECT name FROM sqlite_schema WHERE type='index') -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/railtie.rb: -------------------------------------------------------------------------------- 1 | # frozen_string_literal: true 2 | 3 | class RailsSqliteExtras::Railtie < Rails::Railtie 4 | rake_tasks do 5 | load "rails_sqlite_extras/tasks/all.rake" 6 | end 7 | end 8 | -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/tasks/all.rake: -------------------------------------------------------------------------------- 1 | # frozen_string_literal: true 2 | 3 | require "rails-sqlite-extras" 4 | 5 | namespace :sqlite_extras do 6 | RailsSqliteExtras::QUERIES.each do |query_name| 7 | desc RailsSqliteExtras.description_for(query_name: query_name) 8 | task query_name.to_sym => :environment do 9 | RailsSqliteExtras.public_send(query_name) 10 | end 11 | end 12 | end 13 | -------------------------------------------------------------------------------- /lib/rails_sqlite_extras/version.rb: -------------------------------------------------------------------------------- 1 | # frozen_string_literal: true 2 | 3 | module RailsSqliteExtras 4 | VERSION = "0.1.2" 5 | end 6 | -------------------------------------------------------------------------------- /rails-sqlite-extras.gemspec: -------------------------------------------------------------------------------- 1 | # -*- encoding: utf-8 -*- 2 | lib = File.expand_path("../lib", __FILE__) 3 | $LOAD_PATH.unshift(lib) unless $LOAD_PATH.include?(lib) 4 | require "rails_sqlite_extras/version" 5 | 6 | Gem::Specification.new do |s| 7 | s.name = "rails-sqlite-extras" 8 | s.version = RailsSqliteExtras::VERSION 9 | s.authors = ["pawurb"] 10 | s.email = ["contact@pawelurbanek.com"] 11 | s.summary = %q{ Rails Sqlite database insights. } 12 | s.description = %q{ Helper queries providing insights into the Sqlite database for Rails apps. } 13 | s.homepage = "http://github.com/pawurb/rails-sqlite-extras" 14 | s.files = `git ls-files`.split("\n").reject { |f| f.match?(/\.db$/) } 15 | s.test_files = s.files.grep(%r{^(spec)/}) 16 | s.require_paths = ["lib"] 17 | s.license = "MIT" 18 | s.add_dependency "rails" 19 | s.add_dependency "sqlite3" 20 | s.add_dependency "terminal-table" 21 | s.add_development_dependency "rake" 22 | s.add_development_dependency "rspec" 23 | s.add_development_dependency "rufo" 24 | s.add_development_dependency "dbg-rb" 25 | 26 | if s.respond_to?(:metadata=) 27 | s.metadata = { "rubygems_mfa_required" => "true" } 28 | end 29 | end 30 | -------------------------------------------------------------------------------- /spec/smoke_spec.rb: -------------------------------------------------------------------------------- 1 | # frozen_string_literal: true 2 | 3 | require "spec_helper" 4 | require "rails-sqlite-extras" 5 | 6 | describe RailsSqliteExtras do 7 | RailsSqliteExtras::QUERIES.each do |query_name| 8 | it "#{query_name} description can be read" do 9 | expect do 10 | RailsSqliteExtras.description_for( 11 | query_name: query_name, 12 | ) 13 | end.not_to raise_error 14 | end 15 | end 16 | 17 | RailsSqliteExtras::QUERIES.reject { |q| q == :kill_all }.each do |query_name| 18 | it "#{query_name} query can be executed" do 19 | expect do 20 | RailsSqliteExtras.run_query( 21 | query_name: query_name, 22 | in_format: :display_table, 23 | ) 24 | end.not_to raise_error 25 | end 26 | end 27 | end 28 | -------------------------------------------------------------------------------- /spec/spec_helper.rb: -------------------------------------------------------------------------------- 1 | # frozen_string_literal: true 2 | 3 | require "rubygems" 4 | require "bundler/setup" 5 | require "active_record" 6 | require_relative "../lib/rails-sqlite-extras" 7 | 8 | RSpec.configure do |config| 9 | config.before :suite do 10 | ENV["RAILS_SQLITE_EXTRAS_DATABASE_URL"] = "sqlite3://#{Dir.pwd}/test.db" 11 | end 12 | 13 | config.after :suite do 14 | end 15 | end 16 | -------------------------------------------------------------------------------- /test.db: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/pawurb/rails-sqlite-extras/f9b89871b9c279fdb64fc27c0eaa64472fd601f5/test.db --------------------------------------------------------------------------------