Skip to content
Snippets Groups Projects
Unverified Commit 6b5791ea authored by dpsutton's avatar dpsutton Committed by GitHub
Browse files

Create `cache_info` table in our persisted schemas (#29632)

* Create `cache_info` table in our persisted schemas

```sql
-- postgres/redshift
test-data=# select * from metabase_cache_424a9_379.cache_info ;
       key        |                value
------------------+--------------------------------------
 settings-version | 1
 created-at       | 2023-03-28
 instance-uuid    | 407e4ba8-2bab-470f-aeb5-9fc63fd18c4e
 instance-name    | Metabase Test
(4 rows)
```

```sql
--mysql
mysql> select * from metabase_cache_424a9_435.cache_info;
+------------------+--------------------------------------+
| key              | value                                |
+------------------+--------------------------------------+
| settings-version | 1                                    |
| created-at       | 2023-03-28                           |
| instance-uuid    | 407e4ba8-2bab-470f-aeb5-9fc63fd18c4e |
| instance-name    | Metabase Test                        |
+------------------+--------------------------------------+
```

our key values in v1:
```clojure
(defn kv-table-values
  "Version 1 of the values to go in the key/value table `cache_info` table."
  []
  [{:key   "settings-version"
    :value "1"}
   {:key   "created-at"
    ;; "2023-03-28"
    :value (.format (LocalDate/now) DateTimeFormatter/ISO_LOCAL_DATE)}
   {:key   "instance-uuid"
    :value (public-settings/site-uuid)}
   {:key   "instance-name"
    :value (public-settings/site-name)}])
```

This will enable us to delete cached schemas in shared databases (cloud
versions like redshift) without risking wiping out a cached schema
during an active test run.

The code to delete the schemas will be something like,

```clojure
(def spec (sql-jdbc.conn/connection-details->spec
           :redshift
           {:host "xxx.us-east-1.reshift.amazonaws.com"
            :db "db"
            :port 5439
            :user "user"
            :password "password"}))

(let [days-prior 1 ;; probably 2 to handle crossing day time. Can also adjust to 6 hours, etc
      threshold (.minus (java.time.LocalDate/now)
                        days-prior
                        java.time.temporal.ChronoUnit/DAYS)]
  (doseq [schema (->> ["select nspname from pg_namespace where nspname like 'metabase_cache%'"]
                      (jdbc/query spec)
                      (map :nspname))]
    (let [[{created :value}] (jdbc/query spec (sql/format {:select [:value]
                                                           :from [(keyword schema "cache_info")]
                                                           :where [:= :key "created-at"]}
                                                          {:dialect :ansi}))]
      (when created
        (let [creation-day (java.time.LocalDate/parse created)]
          (when (.isBefore creation-day threshold)
            (jdbc/execute! spec [(format "drop schema %s cascade" schema)])))))))
```

or if we want to do it in a single query:

```clojure
schemas=> (let [days-prior 1
                threshold  (.minus (java.time.LocalDate/now)
                                   days-prior
                                   java.time.temporal.ChronoUnit/DAYS)]
            (let [schemas (->> ["select nspname
                         from pg_namespace
                         where nspname like 'metabase_cache%'"]
                               (jdbc/query spec)
                               (map :nspname))]
              (jdbc/with-db-connection [conn spec]
                (jdbc/execute! conn [(format "set search_path= %s;" (str/join ", " schemas))])
                (let [sql               (sql/format {:select [:schema :created-at]
                                                     :from   {:union-all
                                                              (for [schema schemas]
                                                                {:select [[[:inline schema] :schema]
                                                                          [{:select [:value]
                                                                            :from   [(keyword schema "cache_info")]
                                                                            :where  [:= :key [:inline "created-at"]]}
                                                                           :created-at]]})}}
                                                    {:dialect :ansi})
                      old?              (fn [{create-str :created-at}]
                                          (let [created (java.time.LocalDate/parse create-str)]
                                            (.isBefore created threshold)))
                      schemas-to-delete (->> (jdbc/query spec sql)
                                             (filter old?)
                                             (map :schema))]
                  schemas-to-delete))))
("metabase_cache_424a9_503") ;; when there are any, string join them and delete them as above
```

* Use Instants so we can compare by hours instead of just days
parent dbc4a37d
No related branches found
No related tags found
No related merge requests found
......@@ -2,7 +2,15 @@
(:require
[clojure.string :as str]
[metabase.driver :as driver]
[metabase.util.i18n :refer [tru]]))
[metabase.public-settings :as public-settings]
[metabase.util.i18n :refer [tru]])
(:import
(java.time Instant)
(java.time.format DateTimeFormatter)))
(set! *warn-on-reflection* true)
(defn schema-name
"Returns a schema name for persisting models. Needs the database to use the db id and the site-uuid to ensure that
......@@ -41,6 +49,31 @@
(fn [database] (driver/dispatch-on-initialized-driver (:engine database)))
:hierarchy #'driver/hierarchy)
(defn create-kv-table-honey-sql-form
"The honeysql form that creates the persisted schema `cache_info` table."
[schema-name]
{:create-table [(keyword schema-name "cache_info") :if-not-exists]
:with-columns [[:key :text] [:value :text]]})
(defn kv-table-values
"Version 1 of the values to go in the key/value table `cache_info` table."
[]
[{:key "settings-version"
:value "1"}
{:key "created-at"
;; "2023-03-29T14:01:27.871697Z"
:value (.format DateTimeFormatter/ISO_INSTANT (Instant/now))}
{:key "instance-uuid"
:value (public-settings/site-uuid)}
{:key "instance-name"
:value (public-settings/site-name)}])
(defn populate-kv-table-honey-sql-form
"The honeysql form that populates the persisted schema `cache_info` table."
[schema-name]
{:insert-into [(keyword schema-name "cache_info")]
:values (kv-table-values)})
(defn error->message
"Human readable messages for different connection errors."
[error schema]
......
......@@ -3,6 +3,7 @@
[clojure.core.async :as a]
[clojure.java.jdbc :as jdbc]
[clojure.string :as str]
[honey.sql :as sql]
[java-time :as t]
[metabase.driver.ddl.interface :as ddl.i]
[metabase.driver.sql-jdbc.connection :as sql-jdbc.conn]
......@@ -117,7 +118,20 @@
(fn delete-table [conn]
(sql.ddl/execute! conn [(sql.ddl/drop-table-sql database table-name)]))
;; This will never be called, if the last step fails it does not need to be undone
(constantly nil)]]]
(constantly nil)]
[:persist.check/create-kv-table
(fn create-kv-table [conn]
(sql.ddl/execute! conn [(format "drop table if exists %s.cache_info"
schema-name)])
(sql.ddl/execute! conn (sql/format
(ddl.i/create-kv-table-honey-sql-form schema-name)
{:dialect :mysql})))]
[:persist.check/populate-kv-table
(fn create-kv-table [conn]
(sql.ddl/execute! conn (sql/format
(ddl.i/populate-kv-table-honey-sql-form
schema-name)
{:dialect :mysql})))]]]
;; Unlike postgres, mysql ddl clauses will not rollback in a transaction.
;; So we keep track of undo-steps to manually rollback previous, completed steps.
(jdbc/with-db-connection [conn db-spec]
......
......@@ -69,17 +69,30 @@
[:persist.check/create-table
(fn create-table [conn]
(sql.ddl/execute! conn [(sql.ddl/create-table-sql database
{:table-name table-name
:field-definitions [{:field-name "field"
:base-type :type/Text}]}
"select 1")]))]
{:table-name table-name
:field-definitions [{:field-name "field"
:base-type :type/Text}]}
"select 1")]))]
[:persist.check/read-table
(fn read-table [conn]
(sql.ddl/jdbc-query conn [(format "select * from %s.%s"
schema-name table-name)]))]
schema-name table-name)]))]
[:persist.check/delete-table
(fn delete-table [conn]
(sql.ddl/execute! conn [(sql.ddl/drop-table-sql database table-name)]))]]]
(sql.ddl/execute! conn [(sql.ddl/drop-table-sql database table-name)]))]
[:persist.check/create-kv-table
(fn create-kv-table [conn]
(sql.ddl/execute! conn [(format "drop table if exists %s.cache_info"
schema-name)])
(sql.ddl/execute! conn (sql/format
(ddl.i/create-kv-table-honey-sql-form schema-name)
{:dialect :ansi})))]
[:persist.check/populate-kv-table
(fn create-kv-table [conn]
(sql.ddl/execute! conn (sql/format
(ddl.i/populate-kv-table-honey-sql-form
schema-name)
{:dialect :ansi})))]]]
(jdbc/with-db-connection [conn (sql-jdbc.conn/db->pooled-connection-spec database)]
(jdbc/with-db-transaction
[tx conn]
......
......@@ -3,6 +3,7 @@
[clojure.core.async :as a]
[clojure.string :as str]
[clojure.test :refer :all]
[honey.sql :as sql]
[metabase.driver :as driver]
[metabase.driver.ddl.interface :as ddl.i]
[metabase.models :refer [Card]]
......@@ -13,7 +14,12 @@
[metabase.query-processor.middleware.fix-bad-references
:as fix-bad-refs]
[metabase.test :as mt]
[toucan2.core :as t2]))
[toucan2.core :as t2])
(:import
(java.time Instant)
(java.time.temporal ChronoUnit)))
(set! *warn-on-reflection* true)
(deftest can-persist-test
(testing "Can each database that allows for persistence actually persist"
......@@ -22,7 +28,29 @@
(mt/dataset test-data
(let [[success? error] (ddl.i/check-can-persist (mt/db))]
(is success? (str "Not able to persist on " driver/*driver*))
(is (= :persist.check/valid error))))))))
(is (= :persist.check/valid error)))
(testing "Populates the `cache_info` table with v1 information"
(let [schema-name (ddl.i/schema-name (mt/db) (public-settings/site-uuid))
query {:query
(first
(sql/format {:select [:key :value]
:from [(keyword schema-name "cache_info")]}
{:dialect (if (= (:engine (mt/db)) :mysql)
:mysql
:ansi)}))}
values (into {} (->> query mt/native-query qp/process-query mt/rows))]
(is (partial= {"settings-version" "1"
"instance-uuid" (public-settings/site-uuid)}
(into {} (->> query mt/native-query qp/process-query mt/rows))))
(let [[low high] [(.minus (Instant/now) 1 ChronoUnit/MINUTES)
(.plus (Instant/now) 1 ChronoUnit/MINUTES)]
^Instant created (some-> (get values "created-at")
(java.time.Instant/parse))]
(if created
(is (and (.isAfter created low) (.isBefore created high))
"Date was not created recently")
(throw (ex-info "Did not find `created-at` in `cache_info` table"
{})))))))))))
(deftest persisted-models-max-rows-test
(testing "Persisted models should have the full number of rows of the underlying query,
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment