From 9895e3b513c14ebb9a6c3e3b04ac5230bac01241 Mon Sep 17 00:00:00 2001 From: Elliot Chance Date: Sun, 24 Dec 2023 18:48:39 +0100 Subject: [PATCH] Adding NUMERIC and DECIMAL types (#186) `NUMERIC` and `DECIMAL` types are used for arbitrary precision exact numbers. This has a been long in development. It's required several rewrites and some major changes and improvements to vsql in previous versions to lay the foundation for these types to be fully integrated as first class citizens. Now, number literals that contains a '.' (even if they are a whole numbers such as `123.`) are treated as `NUMERIC` with the scale and precision determined from the number. Arithmetic operations can result in types that are higher in scale and precision, according to the standard (which is very specific about all of that). As far as I'm aware vsql is the only SQL database to treat these as distinct types according to the standard, rather than being aliases of the same underlying type. In a nutshell, `NUMERIC` and `DECIMAL` are both stored as fractions, but `NUMERIC` permits any denominator within range, whereas a `DECIMAL` must have a base 10 denominator. You can think of `DECIMAL` as having "exactly" the precision specified (i.e good for currency), but `NUMERIC` has "at least" the precision specified. Meaning it's possible to `CAST` a `NUMERIC` to a higher precision and get more decimal places (from the inherent nature of a fraction). The docs explain this much better, with examples. Since this does introduce new storage types, a database file version bump is required but this likely be the last version bump before v1.0.0 is released. Along with the two new SQL types, there are some functions that work directly with exact numbers: `ABS`, `CEIL`, `FLOOR` and `MOD`. SQL Standard E011-03 --- docs/functions.rst | 72 +++-- docs/numbers.rst | 149 ++++++++++ docs/sql-compliance.rst | 6 +- docs/v-client-library-docs.rst | 436 +++++++++++++++------------- tests/arithmetic.sql | 14 +- tests/cast.sql | 3 + tests/create-table.sql | 18 ++ tests/decimal.sql | 95 ++++++ tests/double-precision.sql | 38 +-- tests/group-by.sql | 6 +- tests/literal.sql | 10 +- tests/math.sql | 73 +++-- tests/numeric.sql | 104 +++++++ tests/order.sql | 4 +- tests/select-where.sql | 6 +- tests/update.sql | 8 +- tests/values.sql | 16 +- vsql/connection.v | 7 - vsql/funcs.v | 6 + vsql/numeric.v | 363 +++++++++++++++++++++++ vsql/operators.v | 56 +++- vsql/query_cache.v | 129 +++++--- vsql/row.v | 26 +- vsql/std_data_type.v | 41 ++- vsql/std_literal.v | 11 +- vsql/std_numeric_value_expression.v | 3 +- vsql/std_numeric_value_function.v | 43 +++ vsql/std_routine_invocation.v | 11 +- vsql/std_store_assignment.v | 67 ++++- vsql/std_table_definition.v | 5 + vsql/type.v | 65 +++-- vsql/value.v | 109 +++++-- 32 files changed, 1553 insertions(+), 447 deletions(-) create mode 100644 tests/decimal.sql create mode 100644 tests/numeric.sql create mode 100644 vsql/numeric.v diff --git a/docs/functions.rst b/docs/functions.rst index eaf443e..3fd6137 100644 --- a/docs/functions.rst +++ b/docs/functions.rst @@ -151,15 +151,19 @@ ABS .. code-block:: sql ABS(DOUBLE PRECISION) DOUBLE PRECISION + ABS(NUMERIC) NUMERIC -Absolute value. +Absolute value. When using ``NUMERIC`` the same scale and precision is returned. **Examples** .. code-block:: sql - VALUES ABS(1.2); - -- 1.2 + VALUES ABS(1.2e0); + -- 1.2e0 + + VALUES ABS(-1.23e0); + -- 1.23e0 VALUES ABS(-1.23); -- 1.23 @@ -218,34 +222,43 @@ CEIL .. code-block:: sql CEIL(DOUBLE PRECISION) DOUBLE PRECISION + CEIL(NUMERIC) NUMERIC -Round up to the nearest integer. +Round up to the nearest integer. When using ``NUMERIC`` the same scale and +precision is returned. **Examples** .. code-block:: sql - VALUES CEIL(3.7); - -- COL1: 4 + VALUES CEIL(3.7e0); + -- COL1: 4e0 + + VALUES CEIL(3.3e0); + -- COL2: 4e0 - VALUES CEIL(3.3); - -- COL2: 4 + VALUES CEIL(-3.7e0); + -- COL3: -3e0 - VALUES CEIL(-3.7); - -- COL3: -3 + VALUES CEIL(-3.3e0); + -- COL4: -3e0 - VALUES CEIL(-3.3); - -- COL4: -3 + VALUES CEILING(3.7e0); + -- COL1: 4e0 - VALUES CEILING(3.7); + VALUES CEIL(3.7); -- COL1: 4 + VALUES CEILING(-3.7); + -- COL1: -3 + CEILING ^^^^^^^ .. code-block:: sql CEILING(DOUBLE PRECISION) DOUBLE PRECISION + CEILING(NUMERIC) NUMERIC ``CEILING`` is an alias of ``CEIL``. @@ -303,25 +316,33 @@ FLOOR .. code-block:: sql FLOOR(DOUBLE PRECISION) DOUBLE PRECISION + FLOOR(NUMERIC) NUMERIC -Round down to the nearest integer. +Round down to the nearest integer. When using ``NUMERIC`` the same scale and +precision is returned. **Examples** .. code-block:: sql - VALUES FLOOR(3.7); - -- COL1: 3 + VALUES FLOOR(3.7e0); + -- COL1: 3e0 - VALUES FLOOR(3.3); + VALUES FLOOR(3.3e0); + -- COL1: 3e0 + + VALUES FLOOR(-3.7e0); + -- COL1: -4e0 + + VALUES FLOOR(-3.3e0); + -- COL1: -4e0 + + VALUES FLOOR(3.7); -- COL1: 3 VALUES FLOOR(-3.7); -- COL1: -4 - VALUES FLOOR(-3.3); - -- COL1: -4 - LN ^^^ @@ -360,15 +381,20 @@ MOD .. code-block:: sql MOD(DOUBLE PRECISION, DOUBLE PRECISION) DOUBLE PRECISION + MOD(NUMERIC, NUMERIC) NUMERIC -Modulus. +Modulus. When using ``NUMERIC`` the result will have a precision that is the +highest precision between either parameter. The scale is undetermined. **Examples** .. code-block:: sql - VALUES MOD(232, 3); - -- COL1: 1 + VALUES MOD(232e0, 3e0); + -- COL1: 1e0 + + VALUES MOD(10.7e0, 0.8e0); + -- COL1: 0.3e0 VALUES MOD(10.7, 0.8); -- COL1: 0.3 diff --git a/docs/numbers.rst b/docs/numbers.rst index f1e72c2..c24ecb1 100644 --- a/docs/numbers.rst +++ b/docs/numbers.rst @@ -195,6 +195,155 @@ range a ``SQLSTATE 22003 numeric value out of range`` is raised. - -9223372036854775808 to 9223372036854775807 - 8 or 9 bytes [2]_ + * - ``DECIMAL(scale,prec)`` + - Variable, described below. + - Variable based on scale + + * - ``NUMERIC(scale,prec)`` + - Variable, described below. + - Variable based on scale + +DECIMAL vs NUMERIC +^^^^^^^^^^^^^^^^^^ + +``DECIMAL`` and ``NUMERIC`` are both exact numeric types that require a scale +and precision. Both store their respective values as fractions. For example, +``1.23`` could be represented as ``123/100``. + +The main difference between these two types comes down to the allowed +denominators. In short, a ``NUMERIC`` may have any denominator, whereas a +``DECIMAL`` must have a denominator of exactly 10^scale. This can also be +expressed as: + +.. list-table:: + :header-rows: 1 + + * - Type + - Numerator + - Denominator + + * - ``NUMERIC(scale, precision)`` + - ± 10^scale (exclusive) + - ± 10^scale (exclusive) + + * - ``DECIMAL(scale, precision)`` + - ± 10^scale (exclusive) + - 10^scale + +When calculations are performed on a ``DECIMAL``, the result from each operation +will be normalized to always satisfy this constraint. + +This means that a ``DECIMAL`` is always exact at the scale and precision +specified and casting to a higher precision will not alter the value. In +contrast, a ``NUMERIC`` promises to have *at least* the precision specified but +the value may change as to be more exact if the precision is increased. This is +best understood with some examples: + +.. code-block:: sql + + VALUES CAST(1.23 AS DECIMAL(3,2)) / CAST(5 AS DECIMAL) * CAST(5 AS DECIMAL); + -- 1.20 + +Because: + +1. ``1.23 AS DECIMAL(3,2)`` -> ``123/100`` +2. Normalize denominator -> ``123/100`` +3. Divide by ``5`` -> ``123/500`` +4. Normalize denominator -> ``24/100`` +5. Multiply by ``5`` -> ``120/100`` +6. Normalize denominator -> ``24/100`` + +Whereas, + +.. code-block:: sql + + VALUES CAST(1.23 AS NUMERIC(3,2)) / 5 * 5; + -- 1.23 + +Because: + +1. ``1.23 AS NUMERIC(3,2)`` -> ``123/100`` +2. Divide by ``5`` -> ``123/500`` +3. Multiply by ``5`` -> ``615/500`` + +This may seem like the only difference is that ``NUMERIC`` does not normalize +the denominator, but actually they both need to normalize a denominator that +would be out of bounds. Consider the example: + +.. code-block:: sql + + VALUES CAST(1.23 AS NUMERIC(3,2)) / 11; + -- 0.11 + +1. ``1.23 AS NUMERIC(3,2)`` -> ``123/100`` +2. Divide by ``11`` -> ``123/1100`` +3. Denominator is out of bounds as it cannot be larger than 100. Highest + precision equivalent would be -> ``11/100`` + +This the same process and result that a ``DECIMAL`` that the equivalent decimal +operation. Casting to higher precision might result in a different value for +``NUMERIC`` values, for example: + +.. code-block:: sql + + VALUES CAST(CAST(5 AS NUMERIC(3,2)) / CAST(7 AS NUMERIC(5,4)) AS NUMERIC(5,4)); + -- 0.7142 + +Because: + +1. ``5 AS NUMERIC(3,2)`` -> ``5/1`` +2. Divide by ``7`` -> ``5/7`` +3. Cast to ``NUMERIC(5,4)`` -> ``5/7`` +4. Formatted result based on 4 precision -> ``0.7142`` + +.. code-block:: sql + + VALUES CAST(CAST(5 AS DECIMAL(3,2)) / CAST(7 AS DECIMAL) AS DECIMAL(5,4)); + -- 0.7100 + +Because: + +1. ``5 AS DECIMAL(3,2)`` -> ``500/100`` +2. Divide by ``7`` -> ``500/700`` +3. Normalize denominator -> ``71/100`` +4. Cast to ``DECIMAL(5,4)`` -> ``7100/10000`` +5. Formatted result based on 4 precision -> ``0.7100`` + +Operations Between Exact Types +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +Arithmetic operations can only be performed when both operates are the same +fundamental types, ``NUMERIC`` or ``DECIMAL``, although they do not need to +share the same scale or precision. + +.. list-table:: + :header-rows: 1 + + * - Operation + - Result Type + + * - ``NUMERIC(s1, s2) + NUMERIC(s2, p2)`` + - ``NUMERIC(MAX(s1, s2), MIN(p1, p2))`` + + * - ``NUMERIC(s1, s2) - NUMERIC(s2, p2)`` + - ``NUMERIC(MAX(s1, s2), MIN(p1, p2))`` + + * - ``NUMERIC(s1, s2) * NUMERIC(s2, p2)`` + - ``NUMERIC(s1 * s2, p1 + p2)`` + + * - ``NUMERIC(s1, s2) / NUMERIC(s2, p2)`` + - ``NUMERIC(s1 * s2, p1 + p2)`` + +Examples: + +.. code-block:: sql + + VALUES CAST(10.24 AS NUMERIC(4,2)) + CAST(12.123 AS NUMERIC(8,3)); + -- 22.36 as NUMERIC(32, 3) + + VALUES CAST(10.24 AS NUMERIC(4,2)) * CAST(12.123 AS NUMERIC(8,3)); + -- 124.13952 as NUMERIC(32, 5) + Casting ------- diff --git a/docs/sql-compliance.rst b/docs/sql-compliance.rst index a42a9f6..6ce63fe 100644 --- a/docs/sql-compliance.rst +++ b/docs/sql-compliance.rst @@ -13,7 +13,7 @@ Mandatory Features ------------------ As of the latest version (or at least the version of this documentation) -**vsql supports 60 of the 164 mandatory features** of the +**vsql supports 62 of the 164 mandatory features** of the `SQL:2016 Standard `_. .. list-table:: Table 43 — Feature taxonomy and definition for mandatory features @@ -22,7 +22,7 @@ As of the latest version (or at least the version of this documentation) * - Feature ID - Feature Name - * - ⭕ **E011** + * - ✅ **E011** - **Numeric data types** * - ✅ E011-01 @@ -31,7 +31,7 @@ As of the latest version (or at least the version of this documentation) * - ✅ E011-02 - ``REAL``, ``DOUBLE PRECISON``, and ``FLOAT`` data types - * - ❌ E011-03 + * - ✅ E011-03 - ``DECIMAL`` and ``NUMERIC`` data types * - ✅ E011-04 diff --git a/docs/v-client-library-docs.rst b/docs/v-client-library-docs.rst index 40da83f..d4265f4 100644 --- a/docs/v-client-library-docs.rst +++ b/docs/v-client-library-docs.rst @@ -13,59 +13,57 @@ Constants -fn catalog_name_from_path -------------------------- +fn open +------- .. code-block:: v - pub fn catalog_name_from_path(path string) string - + pub fn open(path string) !&Connection +open is the convenience function for open_database() with default options. -fn new_varchar_value --------------------- +fn catalog_name_from_path +------------------------- .. code-block:: v - pub fn new_varchar_value(x string) Value + pub fn catalog_name_from_path(path string) string -new_varchar_value creates a ``CHARACTER VARYING`` value. -fn open -------- + +fn sqlstate_to_int +------------------ .. code-block:: v - pub fn open(path string) !&Connection + pub fn sqlstate_to_int(code string) int -open is the convenience function for open_database() with default options. +sqlstate_to_int converts the 5 character SQLSTATE code (such as "42P01") into an integer representation. The returned value can be converted back to its respective string by using sqlstate_from_int(). -fn open_database ----------------- +If code is invalid the result will be unexpected. +fn start_timer +-------------- -.. code-block:: v - pub fn open_database(path string, options ConnectionOptions) !&Connection +.. code-block:: v -open_database will open an existing database file or create a new file if the path does not exist. + pub fn start_timer() Timer -If the file does exist, open_database will assume that the file is a valid database file (not corrupt). Otherwise unexpected behavior or even a crash may occur. -The special file name ":memory:" can be used to create an entirely in-memory database. This will be faster but all data will be lost when the connection is closed. -open_database can be used concurrently for reading and writing to the same file and provides the following default protections: +fn sqlstate_from_int +-------------------- -- Fine: Multiple processes open_database() the same file. -- Fine: Multiple goroutines sharing an open_database() on the same file. +.. code-block:: v -- Bad: Multiple goroutines open_database() the same file. + pub fn sqlstate_from_int(code int) string -See ConnectionOptions and default_connection_options(). +sqlstate_from_int performs the inverse operation of sqlstate_to_int. fn pluralize ------------ @@ -87,57 +85,49 @@ fn default_connection_options default_connection_options returns the sensible defaults used by open() and the correct base to provide your own option overrides. See ConnectionOptions. -fn new_benchmark +fn open_database ---------------- .. code-block:: v - pub fn new_benchmark(conn &Connection) Benchmark - - - -fn new_bigint_value -------------------- - + pub fn open_database(path string, options ConnectionOptions) !&Connection -.. code-block:: v +open_database will open an existing database file or create a new file if the path does not exist. - pub fn new_bigint_value(x i64) Value +If the file does exist, open_database will assume that the file is a valid database file (not corrupt). Otherwise unexpected behavior or even a crash may occur. -new_bigint_value creates a ``BIGINT`` value. +The special file name ":memory:" can be used to create an entirely in-memory database. This will be faster but all data will be lost when the connection is closed. -fn sqlstate_from_int --------------------- +open_database can be used concurrently for reading and writing to the same file and provides the following default protections: +- Fine: Multiple processes open_database() the same file. -.. code-block:: v +- Fine: Multiple goroutines sharing an open_database() on the same file. - pub fn sqlstate_from_int(code int) string +- Bad: Multiple goroutines open_database() the same file. -sqlstate_from_int performs the inverse operation of sqlstate_to_int. +See ConnectionOptions and default_connection_options(). -fn sqlstate_to_int ------------------- +fn new_benchmark +---------------- .. code-block:: v - pub fn sqlstate_to_int(code string) int + pub fn new_benchmark(conn &Connection) Benchmark -sqlstate_to_int converts the 5 character SQLSTATE code (such as "42P01") into an integer representation. The returned value can be converted back to its respective string by using sqlstate_from_int(). -If code is invalid the result will be unexpected. -fn start_timer --------------- +fn new_bigint_value +------------------- .. code-block:: v - pub fn start_timer() Timer - + pub fn new_bigint_value(x i64) Value +new_bigint_value creates a ``BIGINT`` value. fn new_boolean_value -------------------- @@ -169,6 +159,20 @@ fn new_date_value new_date_value creates a ``DATE`` value. +fn new_decimal_value +-------------------- + + +.. code-block:: v + + pub fn new_decimal_value(x string) Value + +new_decimal_value expects a value to be valid and the size and scale are determined from the value as: + +123 -> DECIMAL(3, 0) 123. -> DECIMAL(3, 0) 1.23 -> DECIMAL(3, 2) -1.23 -> DECIMAL(3, 2) 12.00 -> DECIMAL(4, 2) + + + fn new_double_precision_value ----------------------------- @@ -199,6 +203,20 @@ fn new_null_value new_null_value creates a NULL value of a specific type. In SQL, all NULL values need to have a type. +fn new_numeric_value +-------------------- + + +.. code-block:: v + + pub fn new_numeric_value(x string) Value + +new_numeric_value expects a value to be valid and the size and scale are determined from the value as: + +123 -> NUMERIC(3, 0) 123. -> NUMERIC(3, 0) 1.23 -> NUMERIC(3, 2) -1.23 -> NUMERIC(3, 2) 12.00 -> NUMERIC(4, 2) + + + fn new_query_cache ------------------ @@ -269,21 +287,25 @@ fn new_timestamp_value new_timestamp_value creates a ``TIMESTAMP`` value. -fn new_unknown_value +fn new_varchar_value -------------------- .. code-block:: v - pub fn new_unknown_value() Value + pub fn new_varchar_value(x string) Value -new_unknown_value returns an ``UNKNOWN`` value. This is the ``NULL`` representation of ``BOOLEAN``. +new_varchar_value creates a ``CHARACTER VARYING`` value. -type Server ------------ +fn new_unknown_value +-------------------- +.. code-block:: v + pub fn new_unknown_value() Value + +new_unknown_value returns an ``UNKNOWN`` value. This is the ``NULL`` representation of ``BOOLEAN``. type Row -------- @@ -297,6 +319,12 @@ type Column +type Server +----------- + + + + enum Boolean ------------ @@ -313,88 +341,6 @@ enum Boolean Possible values for a BOOLEAN. -struct VirtualTable -------------------- - - -.. code-block:: v - - pub struct VirtualTable { - create_table_sql string - create_table_stmt TableDefinition - data VirtualTableProviderFn @[required] - mut: - is_done bool - rows []Row - } - - - -struct CatalogConnection ------------------------- - - -.. code-block:: v - - @[heap] - pub struct CatalogConnection { - // path is the file name of the database. It can be the special name - // ':memory:'. - path string - catalog_name string - mut: - // storage will be replaced when the file is reopend for reading or writing. - storage Storage - // options are used when aquiring each file connection. - options ConnectionOptions - // virtual_tables can be created independent from the physical schema. - virtual_tables map[string]VirtualTable - } - -A Connection allows querying and other introspection for a database file. Use open() or open_database() to create a Connection. - -struct Connection ------------------ - - -.. code-block:: v - - @[heap] - pub struct Connection { - mut: - catalogs map[string]&CatalogConnection - // funcs only needs to be initialized once on open() - funcs []Func - // query_cache is maintained over file reopens. - query_cache &QueryCache - // cast_rules are use for CAST() (see cast.v) - cast_rules map[string]CastFunc - // unary_operators and binary_operators are for operators (see operators.v) - unary_operators map[string]UnaryOperatorFunc - binary_operators map[string]BinaryOperatorFunc - // current_schema is where to search for unquailified table names. It will - // have an initial value of 'PUBLIC'. - current_schema string - // current_catalog (also known as the database). It will have an inital value - // derived from the first database file loaded. - current_catalog string - pub mut: - // now allows you to override the wall clock that is used. The Time must be - // in UTC with a separate offset for the current local timezone (in positive - // or negative minutes). - now fn () (time.Time, i16) @[required] - // warnings are SQLSTATE errors that do not stop the execution. For example, - // if a value must be truncated during a runtime CAST. - // - // Warnings are not ever reset, although only 100 of the most recent warnings - // are retained. This is to be able to collect all warnings during some - // arbitrary process defined by the application. Instead, you should call - // clear_warnings() before starting a block of work. - warnings []IError - } - -A Connection allows querying and other introspection for a database file. Use open() or open_database() to create a Connection. - struct ConnectionOptions ------------------------ @@ -438,65 +384,6 @@ struct ConnectionOptions ConnectionOptions can modify the behavior of a connection when it is opened. You should not create the ConnectionOptions instance manually. Instead, use default_connection_options() as a starting point and modify the attributes. -struct Identifier ------------------ - - -.. code-block:: v - - pub struct Identifier { - pub: - // catalog_name is optional. If not provided, the CURRENT_CATALOG will be - // used. - catalog_name string - // schema_name is optional. If not provided, it will use CURRENT_SCHEMA. - schema_name string - // entity_name would be the table name, sequence name, etc. Something inside - // of a schema. It is case sensitive. - entity_name string - // sub_entity_name would represent a column name. It is case sensitive. - sub_entity_name string - // custom_id is a way to override the behavior of rendering and storage. This - // is only used for internal identifiers. - custom_id string - custom_typ Type - } - -Identifier is used to describe a object within a schema (such as a table name) or a property of an object (like a column name of a table). You should not instantiate this directly, instead use the appropriate new_*_identifier() function. - -If you need the fully qualified (canonical) form of an identified you can use Connection.resolve_schema_identifier(). - -struct PageObject ------------------ - - -.. code-block:: v - - pub struct PageObject { - // The key is not required to be unique in the page. It becomes unique when - // combined with tid. However, no more than two version of the same key can - // exist in a page. See the caveats at the top of btree.v. - key []u8 - // The value contains the serialized data for the object. The first byte of - // key is used to both identify what type of object this is and also keep - // objects within the same collection also within the same range. - value []u8 - // When is_blob_ref is true, the value will be always be 5 bytes. See - // blob_info(). - is_blob_ref bool - mut: - // The tid is the transaction that created the object. - // - // TODO(elliotchance): It makes more sense to construct a new PageObject - // when changing the tid and xid. - tid int - // The xid is the transaciton that deleted the object, or zero if it has - // never been deleted. - xid int - } - -TODO(elliotchance): This does not need to be public. It was required for a bug at the time with V not being able to pass this to the shuffle function. At some point in the future remove the pub and see if it works. - struct PreparedStmt ------------------- @@ -559,6 +446,23 @@ A Result contains zero or more rows returned from a query. See next() for an example on iterating rows in a Result. +struct Benchmark +---------------- + + +.. code-block:: v + + pub struct Benchmark { + pub mut: + conn &Connection + account_rows int + teller_rows int + branch_rows int + run_for time.Duration + } + + + struct Schema ------------- @@ -610,6 +514,23 @@ struct Sequence A SEQUENCE definition. +struct VirtualTable +------------------- + + +.. code-block:: v + + pub struct VirtualTable { + create_table_sql string + create_table_stmt TableDefinition + data VirtualTableProviderFn @[required] + mut: + is_done bool + rows []Row + } + + + struct ServerOptions -------------------- @@ -624,6 +545,71 @@ struct ServerOptions +struct Connection +----------------- + + +.. code-block:: v + + @[heap] + pub struct Connection { + mut: + catalogs map[string]&CatalogConnection + // funcs only needs to be initialized once on open() + funcs []Func + // query_cache is maintained over file reopens. + query_cache &QueryCache + // cast_rules are use for CAST() (see cast.v) + cast_rules map[string]CastFunc + // unary_operators and binary_operators are for operators (see operators.v) + unary_operators map[string]UnaryOperatorFunc + binary_operators map[string]BinaryOperatorFunc + // current_schema is where to search for unquailified table names. It will + // have an initial value of 'PUBLIC'. + current_schema string + // current_catalog (also known as the database). It will have an inital value + // derived from the first database file loaded. + current_catalog string + pub mut: + // now allows you to override the wall clock that is used. The Time must be + // in UTC with a separate offset for the current local timezone (in positive + // or negative minutes). + now fn () (time.Time, i16) @[required] + // warnings are SQLSTATE errors that do not stop the execution. For example, + // if a value must be truncated during a runtime CAST. + // + // Warnings are not ever reset, although only 100 of the most recent warnings + // are retained. This is to be able to collect all warnings during some + // arbitrary process defined by the application. Instead, you should call + // clear_warnings() before starting a block of work. + warnings []IError + } + +A Connection allows querying and other introspection for a database file. Use open() or open_database() to create a Connection. + +struct CatalogConnection +------------------------ + + +.. code-block:: v + + @[heap] + pub struct CatalogConnection { + // path is the file name of the database. It can be the special name + // ':memory:'. + path string + catalog_name string + mut: + // storage will be replaced when the file is reopend for reading or writing. + storage Storage + // options are used when aquiring each file connection. + options ConnectionOptions + // virtual_tables can be created independent from the physical schema. + virtual_tables map[string]VirtualTable + } + +A Connection allows querying and other introspection for a database file. Use open() or open_database() to create a Connection. + struct Table ------------ @@ -698,20 +684,62 @@ struct Value A single value. It contains it's type information in ``typ``. -struct Benchmark ----------------- +struct PageObject +----------------- .. code-block:: v - pub struct Benchmark { - pub mut: - conn &Connection - account_rows int - teller_rows int - branch_rows int - run_for time.Duration + pub struct PageObject { + // The key is not required to be unique in the page. It becomes unique when + // combined with tid. However, no more than two version of the same key can + // exist in a page. See the caveats at the top of btree.v. + key []u8 + // The value contains the serialized data for the object. The first byte of + // key is used to both identify what type of object this is and also keep + // objects within the same collection also within the same range. + value []u8 + // When is_blob_ref is true, the value will be always be 5 bytes. See + // blob_info(). + is_blob_ref bool + mut: + // The tid is the transaction that created the object. + // + // TODO(elliotchance): It makes more sense to construct a new PageObject + // when changing the tid and xid. + tid int + // The xid is the transaciton that deleted the object, or zero if it has + // never been deleted. + xid int } +TODO(elliotchance): This does not need to be public. It was required for a bug at the time with V not being able to pass this to the shuffle function. At some point in the future remove the pub and see if it works. +struct Identifier +----------------- + + +.. code-block:: v + + pub struct Identifier { + pub: + // catalog_name is optional. If not provided, the CURRENT_CATALOG will be + // used. + catalog_name string + // schema_name is optional. If not provided, it will use CURRENT_SCHEMA. + schema_name string + // entity_name would be the table name, sequence name, etc. Something inside + // of a schema. It is case sensitive. + entity_name string + // sub_entity_name would represent a column name. It is case sensitive. + sub_entity_name string + // custom_id is a way to override the behavior of rendering and storage. This + // is only used for internal identifiers. + custom_id string + custom_typ Type + } + +Identifier is used to describe a object within a schema (such as a table name) or a property of an object (like a column name of a table). You should not instantiate this directly, instead use the appropriate new_*_identifier() function. + +If you need the fully qualified (canonical) form of an identified you can use Connection.resolve_schema_identifier(). diff --git a/tests/arithmetic.sql b/tests/arithmetic.sql index 91519ae..51ee80c 100644 --- a/tests/arithmetic.sql +++ b/tests/arithmetic.sql @@ -16,23 +16,23 @@ VALUES 6 / 2; /* types */ VALUES 1.2 + 2.4; --- COL1: 3.6e0 (DOUBLE PRECISION) +-- COL1: 3.6 (NUMERIC(2, 1)) /* types */ VALUES 1.7 - 0.5; --- COL1: 1.2e0 (DOUBLE PRECISION) +-- COL1: 1.2 (NUMERIC(2, 1)) /* types */ VALUES 2.2 * 3.3; --- COL1: 7.26e0 (DOUBLE PRECISION) +-- COL1: 7.26 (NUMERIC(4, 2)) /* types */ VALUES 6.0 / 2.5; --- COL1: 2.4e0 (DOUBLE PRECISION) +-- COL1: 2.4 (NUMERIC(4, 2)) /* types */ VALUES 0.0 / 2.5; --- COL1: 0e0 (DOUBLE PRECISION) +-- COL1: 0 (NUMERIC(4, 2)) /* types */ VALUES 2.5 / 0.0; @@ -44,11 +44,11 @@ VALUES -123; /* types */ VALUES +1.23; --- COL1: 1.23e0 (DOUBLE PRECISION) +-- COL1: 1.23 (NUMERIC(3, 2)) /* types */ VALUES 1.5 + 2.4 * 7.0; --- COL1: 18.3e0 (DOUBLE PRECISION) +-- COL1: 18.3 (NUMERIC(4, 2)) VALUES 30000 + 30000; -- error 22003: numeric value out of range diff --git a/tests/cast.sql b/tests/cast.sql index ae9a250..7d06778 100644 --- a/tests/cast.sql +++ b/tests/cast.sql @@ -65,3 +65,6 @@ VALUES CAST(12345 AS VARCHAR(3)); VALUES CAST(123456789 AS DOUBLE PRECISION); -- COL1: 1.23456789e+08 + +VALUES CAST(1.23 AS NUMERIC); +-- COL1: 1.23 diff --git a/tests/create-table.sql b/tests/create-table.sql index e0bbc2b..2e62da1 100644 --- a/tests/create-table.sql +++ b/tests/create-table.sql @@ -106,6 +106,24 @@ CREATE TABLE foo (bar TIMESTAMP WITH TIME ZONE); CREATE TABLE foo (bar TIMESTAMP(3) WITH TIME ZONE); -- msg: CREATE TABLE 1 +CREATE TABLE foo (bar NUMERIC); +-- error 42601: syntax error: column BAR: NUMERIC must specify a size + +CREATE TABLE foo (bar NUMERIC(10)); +-- msg: CREATE TABLE 1 + +CREATE TABLE foo (bar NUMERIC(10, 2)); +-- msg: CREATE TABLE 1 + +CREATE TABLE foo (bar DECIMAL); +-- error 42601: syntax error: column BAR: DECIMAL must specify a size + +CREATE TABLE foo (bar DECIMAL(10)); +-- msg: CREATE TABLE 1 + +CREATE TABLE foo (bar DECIMAL(10, 2)); +-- msg: CREATE TABLE 1 + CREATE TABLE foo.bar (baz BIGINT); -- error 3F000: invalid schema name: FOO diff --git a/tests/decimal.sql b/tests/decimal.sql new file mode 100644 index 0000000..4f22906 --- /dev/null +++ b/tests/decimal.sql @@ -0,0 +1,95 @@ +CREATE TABLE foo (bar DECIMAL); +-- error 42601: syntax error: column BAR: DECIMAL must specify a size + +CREATE TABLE foo (bar DECIMAL(4, 2)); +INSERT INTO foo (bar) VALUES (1.23); +INSERT INTO foo (bar) VALUES (12345); +INSERT INTO foo (bar) VALUES (-1.24); +SELECT * FROM foo; +SELECT -bar FROM foo; +-- msg: CREATE TABLE 1 +-- msg: INSERT 1 +-- error 22003: numeric value out of range +-- msg: INSERT 1 +-- BAR: 1.23 +-- BAR: -1.24 +-- COL1: -1.23 +-- COL1: 1.24 + +VALUES CAST(1.23 AS DECIMAL(10, 6)); +-- COL1: 1.230000 + +VALUES CAST(1.23 AS DECIMAL(10, 2)); +-- COL1: 1.23 + +VALUES CAST(1.23 AS DECIMAL(10, 1)); +-- COL1: 1.2 + +VALUES CAST(1234.5 AS DECIMAL(3, 0)); +-- error 22003: numeric value out of range + +VALUES CAST(-1.23 AS DECIMAL); +-- COL1: -1.23 + +VALUES CAST(-12.34 AS DECIMAL(4, 2)); +-- COL1: -12.34 + +VALUES CAST(-12.34 AS DECIMAL(4, 1)); +-- COL1: -12.3 + +VALUES CAST(-12.34 AS DECIMAL(2, 0)); +-- COL1: -12 + +VALUES CAST(-12.34 AS DECIMAL(3, 2)); +-- error 22003: numeric value out of range + +VALUES CAST(1.23 AS DECIMAL(6, 2)) + CAST(1.5 AS DECIMAL(6, 3)); +-- COL1: 2.730 + +VALUES CAST(1.23 AS DECIMAL(6, 2)) - CAST(1.5 AS DECIMAL(6, 3)); +-- COL1: -0.270 + +VALUES CAST(1.23 AS DECIMAL(6, 2)) - CAST(-1.5 AS DECIMAL(6, 3)); +-- COL1: 2.730 + +VALUES CAST(1.23 AS DECIMAL(6, 2)) * CAST(1.5 AS DECIMAL(6, 3)); +-- COL1: 1.84500 + +VALUES CAST(CAST(1.23 AS DECIMAL(6, 2)) * CAST(1.5 AS DECIMAL(6, 3)) AS DECIMAL(6, 4)); +-- COL1: 1.8450 + +VALUES CAST(1.24 AS DECIMAL(6, 2)) / CAST(1.5 AS DECIMAL(6, 3)); +-- COL1: 0.82666 + +VALUES CAST(1.24 AS DECIMAL(6, 3)) / CAST(1.5 AS DECIMAL(6, 2)); +-- COL1: 0.82666 + +VALUES CAST(CAST(1.24 AS DECIMAL(6, 2)) / CAST(1.5 AS DECIMAL(6, 3)) AS DECIMAL(6, 4)); +-- COL1: 0.8266 + +VALUES CAST(1.23 AS DECIMAL(3,2)) / 5; +-- error 42883: operator does not exist: DECIMAL / SMALLINT + +-- # This is an important case because it's described in detail in the docs for +-- # NUMERIC vs DECIMAL. +VALUES CAST(CAST(5 AS DECIMAL(3,2)) / CAST(7 AS DECIMAL) AS DECIMAL(5,4)); +-- COL1: 0.7100 + +VALUES CAST(10.24 AS DECIMAL(4,2)) + CAST(12.123 AS DECIMAL(8,3)); +-- COL1: 22.360 + +VALUES CAST(10.24 AS DECIMAL(4,2)) * CAST(12.123 AS DECIMAL(8,3)); +-- COL1: 124.13952 + +-- # This is an important case because it's described in detail in the docs for +-- # NUMERIC vs DECIMAL. +VALUES CAST(1.23 AS DECIMAL(3,2)) / CAST(5 AS DECIMAL) * CAST(5 AS DECIMAL); +-- COL1: 1.20 + +VALUES CAST(5 AS DECIMAL(3,2)) / CAST(7 AS DECIMAL(5,4)); +-- COL1: 0.714285 + +-- # This is an important case because it's described in detail in the docs for +-- # NUMERIC vs DECIMAL. +VALUES CAST(1.23 AS DECIMAL(3,2)) / CAST(5 AS DECIMAL) * CAST(5 AS DECIMAL); +-- COL1: 1.20 diff --git a/tests/double-precision.sql b/tests/double-precision.sql index 4956432..25f1820 100644 --- a/tests/double-precision.sql +++ b/tests/double-precision.sql @@ -48,78 +48,78 @@ SELECT CAST(x AS DOUBLE PRECISION) FROM foo; -- COL1: 123e0 /* types */ -VALUES CAST(500000000.3 AS DOUBLE PRECISION) * 2000000000.7; +VALUES CAST(500000000.3 AS DOUBLE PRECISION) * 2000000000.7e0; -- COL1: 1.00000000095e+18 (DOUBLE PRECISION) /* types */ -VALUES CAST(1.23 AS DOUBLE PRECISION) + 53.7; +VALUES CAST(1.23 AS DOUBLE PRECISION) + 53.7e0; -- COL1: 54.93e0 (DOUBLE PRECISION) /* types */ -VALUES 53.7 + CAST(1.23 AS DOUBLE PRECISION); +VALUES 53.7e0 + CAST(1.23 AS DOUBLE PRECISION); -- COL1: 54.93e0 (DOUBLE PRECISION) /* types */ -VALUES CAST(500000000 AS DOUBLE PRECISION) + 2000000000.7; +VALUES CAST(500000000 AS DOUBLE PRECISION) + 2000000000.7e0; -- COL1: 2.5000000007e+09 (DOUBLE PRECISION) /* types */ -VALUES 500000000.7 + CAST(2000000000 AS DOUBLE PRECISION); +VALUES 500000000.7e0 + CAST(2000000000 AS DOUBLE PRECISION); -- COL1: 2.5000000007e+09 (DOUBLE PRECISION) /* types */ -VALUES CAST(1.23 AS DOUBLE PRECISION) - 53.7; +VALUES CAST(1.23 AS DOUBLE PRECISION) - 53.7e0; -- COL1: -52.47e0 (DOUBLE PRECISION) /* types */ -VALUES 53.7 - CAST(1.23 AS DOUBLE PRECISION); +VALUES 53.7e0 - CAST(1.23 AS DOUBLE PRECISION); -- COL1: 52.47e0 (DOUBLE PRECISION) /* types */ -VALUES CAST(-2000000000.1 AS DOUBLE PRECISION) - 500000000.7; +VALUES CAST(-2000000000.1 AS DOUBLE PRECISION) - 500000000.7e0; -- COL1: -0.25000000008e+10 (DOUBLE PRECISION) /* types */ -VALUES -500000000.7 - CAST(2000000000.1 AS DOUBLE PRECISION); +VALUES -500000000.7e0 - CAST(2000000000.1 AS DOUBLE PRECISION); -- COL1: -0.25000000008e+10 (DOUBLE PRECISION) /* types */ -VALUES CAST(12.3 AS DOUBLE PRECISION) * 53.7; +VALUES CAST(12.3 AS DOUBLE PRECISION) * 53.7e0; -- COL1: 660.51e0 (DOUBLE PRECISION) /* types */ -VALUES -53.7 * CAST(12.3 AS DOUBLE PRECISION); +VALUES -53.7e0 * CAST(12.3 AS DOUBLE PRECISION); -- COL1: -660.51e0 (DOUBLE PRECISION) /* types */ -VALUES CAST(-300000.1 AS DOUBLE PRECISION) * 200000.7; +VALUES CAST(-300000.1 AS DOUBLE PRECISION) * 200000.7e0; -- COL1: -6.000023000007e+10 (DOUBLE PRECISION) /* types */ -VALUES -300000.7 * CAST(200000.1 AS DOUBLE PRECISION); +VALUES -300000.7e0 * CAST(200000.1 AS DOUBLE PRECISION); -- COL1: -6.000017000007e+10 (DOUBLE PRECISION) /* types */ -VALUES CAST(1.23 AS DOUBLE PRECISION) / 53.7; +VALUES CAST(1.23 AS DOUBLE PRECISION) / 53.7e0; -- COL1: 0.022905027933e0 (DOUBLE PRECISION) /* types */ -VALUES -123.7 / CAST(53.1 AS DOUBLE PRECISION); +VALUES -123.7e0 / CAST(53.1 AS DOUBLE PRECISION); -- COL1: -2.329566854991e0 (DOUBLE PRECISION) /* types */ -VALUES CAST(-300000000.5 AS DOUBLE PRECISION) / 0.02; +VALUES CAST(-300000000.5 AS DOUBLE PRECISION) / 0.02e0; -- COL1: -1.5000000025e+10 (DOUBLE PRECISION) /* types */ -VALUES -90000.7 / CAST(3.2 AS DOUBLE PRECISION); +VALUES -90000.7e0 / CAST(3.2 AS DOUBLE PRECISION); -- COL1: -28125.218749999996e0 (DOUBLE PRECISION) -VALUES CAST(-30000.5 AS DOUBLE PRECISION) / 0.0; +VALUES CAST(-30000.5 AS DOUBLE PRECISION) / 0.0e0; -- error 22012: division by zero /* types */ -VALUES -90000.5 / CAST(0.1 AS DOUBLE PRECISION); +VALUES -90000.5e0 / CAST(0.1 AS DOUBLE PRECISION); -- COL1: -900005e0 (DOUBLE PRECISION) CREATE TABLE foo (x DOUBLE PRECISION); diff --git a/tests/group-by.sql b/tests/group-by.sql index 1eeb39f..9b92f96 100644 --- a/tests/group-by.sql +++ b/tests/group-by.sql @@ -81,7 +81,7 @@ EXPLAIN SELECT x + 1.0, x FROM foo GROUP BY x; -- EXPLAIN: GROUP BY (":memory:".PUBLIC.FOO.X DOUBLE PRECISION) -- EXPLAIN: EXPR (COL1 DOUBLE PRECISION, X DOUBLE PRECISION) -SELECT x + 1.0, x FROM foo GROUP BY x; +SELECT x + 1e0, x FROM foo GROUP BY x; -- COL1: 2.234e0 X: 1.234e0 -- COL1: 6.6e0 X: 5.6e0 -- COL1: 13.34e0 X: 12.34e0 @@ -166,12 +166,12 @@ EXPLAIN SELECT min(x), max(x) FROM foo; SELECT min(x), max(x) FROM foo; -- COL1: 1.234e0 COL2: 12.34e0 -EXPLAIN SELECT avg(x * 2.0) FROM foo; +EXPLAIN SELECT avg(x * 2e0) FROM foo; -- EXPLAIN: TABLE ":memory:".PUBLIC.FOO (X DOUBLE PRECISION, Y CHARACTER VARYING(32)) -- EXPLAIN: GROUP BY (AVG(X * 2e0) DOUBLE PRECISION) -- EXPLAIN: EXPR (COL1 DOUBLE PRECISION) -SELECT avg(x * 2.0) FROM foo; +SELECT avg(x * 2e0) FROM foo; -- COL1: 10.4032e0 EXPLAIN SELECT x FROM foo GROUP BY x FETCH FIRST 2 ROWS ONLY; diff --git a/tests/literal.sql b/tests/literal.sql index d9135a7..6e4c149 100644 --- a/tests/literal.sql +++ b/tests/literal.sql @@ -4,15 +4,15 @@ VALUES 1; /* types */ VALUES 1.23; --- COL1: 1.23e0 (DOUBLE PRECISION) +-- COL1: 1.23 (NUMERIC(3, 2)) /* types */ VALUES 1.; --- COL1: 1e0 (DOUBLE PRECISION) +-- COL1: 1 (NUMERIC(1)) /* types */ VALUES .23; --- COL1: 0.23e0 (DOUBLE PRECISION) +-- COL1: 0.23 (NUMERIC(3, 2)) /* types */ VALUES 789; @@ -71,7 +71,7 @@ VALUES ROW(2 + 3 * 5, (2 + 3) * 5); /* types */ VALUES -9223372036854775809; --- COL1: -9223372036854775809 (NUMERIC) +-- COL1: -9223372036854775809 (NUMERIC(19)) /* types */ VALUES -9223372036854775808; @@ -115,4 +115,4 @@ VALUES 9223372036854775807; /* types */ VALUES 9223372036854775808; --- COL1: 9223372036854775808 (NUMERIC) +-- COL1: 9223372036854775808 (NUMERIC(19)) diff --git a/tests/math.sql b/tests/math.sql index b541f80..567ce4d 100644 --- a/tests/math.sql +++ b/tests/math.sql @@ -1,5 +1,10 @@ +/* types */ VALUES ROW(ABS(1.2), ABS(-1.23)); --- COL1: 1.2e0 COL2: 1.23e0 +-- COL1: 1.2 (NUMERIC(2, 1)) COL2: 1.23 (NUMERIC(3, 2)) + +/* types */ +VALUES ROW(ABS(1.2e0), ABS(-1.23e0)); +-- COL1: 1.2e0 (DOUBLE PRECISION) COL2: 1.23e0 (DOUBLE PRECISION) VALUES ABS('hello'); -- error 42883: function does not exist: ABS(CHARACTER(5)) @@ -11,77 +16,105 @@ VALUES ABS(1, 2); -- error 42601: syntax error: near "," /* types */ -VALUES SIN(1.2); +VALUES MOD(232.0, 3.0); +-- COL1: 1 (NUMERIC(4, 1)) + +/* types */ +VALUES MOD(10.7, 0.8); +-- COL1: 0.3 (NUMERIC(3, 1)) + +/* types */ +VALUES MOD(232.000, 3.0); +-- COL1: 1 (NUMERIC(6, 3)) + +/* types */ +VALUES MOD(232., 3.0000); +-- COL1: 1 (NUMERIC(10, 4)) + +/* types */ +VALUES ROW(FLOOR(3.7), FLOOR(3.3), FLOOR(-3.7), FLOOR(-3.3)); +-- COL1: 3 (NUMERIC(1)) COL2: 3 (NUMERIC(1)) COL3: -4 (NUMERIC(1)) COL4: -4 (NUMERIC(1)) + +/* types */ +VALUES ROW(CEIL(3.7), CEIL(3.3), CEIL(-3.7), CEIL(-3.3)); +-- COL1: 4 (NUMERIC(1)) COL2: 4 (NUMERIC(1)) COL3: -3 (NUMERIC(1)) COL4: -3 (NUMERIC(1)) + +/* types */ +VALUES CEILING(3.7); +-- COL1: 4 (NUMERIC(1)) + +/* types */ +VALUES SIN(1.2e0); -- COL1: 0.932039085967e0 (DOUBLE PRECISION) /* types */ -VALUES COS(1.2); +VALUES COS(1.2e0); -- COL1: 0.362357754477e0 (DOUBLE PRECISION) /* types */ -VALUES TAN(1.2); +VALUES TAN(1.2e0); -- COL1: 2.572151622126e0 (DOUBLE PRECISION) /* types */ -VALUES SINH(1.2); +VALUES SINH(1.2e0); -- COL1: 1.509461355412e0 (DOUBLE PRECISION) /* types */ -VALUES COSH(1.2); +VALUES COSH(1.2e0); -- COL1: 1.810655567324e0 (DOUBLE PRECISION) /* types */ -VALUES TANH(1.2); +VALUES TANH(1.2e0); -- COL1: 0.833654607012e0 (DOUBLE PRECISION) /* types */ -VALUES ASIN(0.2); +VALUES ASIN(0.2e0); -- COL1: 0.20135792079e0 (DOUBLE PRECISION) /* types */ -VALUES ACOS(0.2); +VALUES ACOS(0.2e0); -- COL1: 1.369438406005e0 (DOUBLE PRECISION) /* types */ -VALUES ATAN(0.2); +VALUES ATAN(0.2e0); -- COL1: 0.19739555985e0 (DOUBLE PRECISION) /* types */ -VALUES MOD(232.0, 3.0); +VALUES MOD(232e0, 3e0); -- COL1: 1e0 (DOUBLE PRECISION) /* types */ -VALUES MOD(10.7, 0.8); +VALUES MOD(10.7e0, 0.8e0); -- COL1: 0.3e0 (DOUBLE PRECISION) /* types */ -VALUES LOG10(13.7); +VALUES LOG10(13.7e0); -- COL1: 1.136720567156e0 (DOUBLE PRECISION) /* types */ -VALUES LN(13.7); +VALUES LN(13.7e0); -- COL1: 2.617395832834e0 (DOUBLE PRECISION) /* types */ -VALUES EXP(3.7); +VALUES EXP(3.7e0); -- COL1: 40.447304360067e0 (DOUBLE PRECISION) /* types */ -VALUES POWER(3.7, 2.5); +VALUES POWER(3.7e0, 2.5e0); -- COL1: 26.333240780428e0 (DOUBLE PRECISION) /* types */ -VALUES SQRT(3.7); +VALUES SQRT(3.7e0); -- COL1: 1.923538406167e0 (DOUBLE PRECISION) /* types */ -VALUES ROW(FLOOR(3.7), FLOOR(3.3), FLOOR(-3.7), FLOOR(-3.3)); +VALUES ROW(FLOOR(3.7e0), FLOOR(3.3e0), FLOOR(-3.7e0), FLOOR(-3.3e0)); -- COL1: 3e0 (DOUBLE PRECISION) COL2: 3e0 (DOUBLE PRECISION) COL3: -4e0 (DOUBLE PRECISION) COL4: -4e0 (DOUBLE PRECISION) /* types */ -VALUES ROW(CEIL(3.7), CEIL(3.3), CEIL(-3.7), CEIL(-3.3)); +VALUES ROW(CEIL(3.7e0), CEIL(3.3e0), CEIL(-3.7e0), CEIL(-3.3e0)); -- COL1: 4e0 (DOUBLE PRECISION) COL2: 4e0 (DOUBLE PRECISION) COL3: -3e0 (DOUBLE PRECISION) COL4: -3e0 (DOUBLE PRECISION) /* types */ -VALUES CEILING(3.7); +VALUES CEILING(3.7e0); -- COL1: 4e0 (DOUBLE PRECISION) diff --git a/tests/numeric.sql b/tests/numeric.sql new file mode 100644 index 0000000..9b05074 --- /dev/null +++ b/tests/numeric.sql @@ -0,0 +1,104 @@ +CREATE TABLE foo (bar NUMERIC); +-- error 42601: syntax error: column BAR: NUMERIC must specify a size + +CREATE TABLE foo (bar NUMERIC(4, 2)); +INSERT INTO foo (bar) VALUES (1.23); +INSERT INTO foo (bar) VALUES (12345); +INSERT INTO foo (bar) VALUES (-1.24); +SELECT * FROM foo; +SELECT -bar FROM foo; +-- msg: CREATE TABLE 1 +-- msg: INSERT 1 +-- error 22003: numeric value out of range +-- msg: INSERT 1 +-- BAR: 1.23 +-- BAR: -1.24 +-- COL1: -1.23 +-- COL1: 1.24 + +VALUES 0.001; +VALUES .23; +VALUES -.23; +-- COL1: 0.001 +-- COL1: 0.23 +-- COL1: -0.23 + +VALUES CAST(1.23 AS NUMERIC(10, 6)); +-- COL1: 1.23 + +VALUES CAST(1.23 AS NUMERIC(10, 2)); +-- COL1: 1.23 + +VALUES CAST(1.23 AS NUMERIC(10, 1)); +-- COL1: 1.2 + +VALUES CAST(1234.5 AS NUMERIC(3, 0)); +-- error 22003: numeric value out of range + +VALUES CAST(-1.23 AS NUMERIC); +-- COL1: -1.23 + +VALUES CAST(-12.34 AS NUMERIC(4, 2)); +-- COL1: -12.34 + +VALUES CAST(-12.34 AS NUMERIC(4, 1)); +-- COL1: -12.3 + +VALUES CAST(-12.34 AS NUMERIC(2, 0)); +-- COL1: -12 + +VALUES CAST(-12.34 AS NUMERIC(3, 2)); +-- error 22003: numeric value out of range + +VALUES CAST(1.23 AS NUMERIC(6, 2)) + CAST(1.5 AS NUMERIC(6, 3)); +-- COL1: 2.73 + +VALUES CAST(1.23 AS NUMERIC(6, 2)) - CAST(1.5 AS NUMERIC(6, 3)); +-- COL1: -0.27 + +VALUES CAST(1.23 AS NUMERIC(6, 2)) - CAST(-1.5 AS NUMERIC(6, 3)); +-- COL1: 2.73 + +VALUES CAST(1.23 AS NUMERIC(6, 2)) * CAST(1.5 AS NUMERIC(6, 3)); +-- COL1: 1.845 + +VALUES CAST(CAST(1.23 AS NUMERIC(6, 2)) * CAST(1.5 AS NUMERIC(6, 3)) AS NUMERIC(6, 4)); +-- COL1: 1.845 + +VALUES CAST(1.24 AS NUMERIC(6, 2)) / CAST(1.5 AS NUMERIC(6, 3)); +-- COL1: 0.82666 + +VALUES CAST(1.24 AS NUMERIC(6, 3)) / CAST(1.5 AS NUMERIC(6, 2)); +-- COL1: 0.82666 + +VALUES CAST(CAST(1.24 AS NUMERIC(6, 2)) / CAST(1.5 AS NUMERIC(6, 3)) AS NUMERIC(6, 4)); +-- COL1: 0.8266 + +VALUES CAST(1.23 AS NUMERIC(3,2)) / 5; +-- COL1: 0.24 + +VALUES CAST(CAST(1.23 AS NUMERIC(3,2)) / 5 AS NUMERIC(4, 3)); +-- COL1: 0.246 + +-- # This is an important case because it's described in detail in the docs for +-- # NUMERIC vs DECIMAL. +VALUES CAST(1.23 AS NUMERIC(3,2)) / 5 * 5; +-- COL1: 1.23 + +-- # This is an important case because it's described in detail in the docs for +-- # NUMERIC vs DECIMAL. +VALUES CAST(1.23 AS NUMERIC(3,2)) / 11; +-- COL1: 0.11 + +-- # This is an important case because it's described in detail in the docs for +-- # NUMERIC vs DECIMAL. +VALUES CAST(CAST(5 AS NUMERIC(3,2)) / CAST(7 AS NUMERIC(5,4)) AS NUMERIC(5,4)); +-- COL1: 0.7142 + +/* types */ +VALUES CAST(10.24 AS NUMERIC(4,2)) + CAST(12.123 AS NUMERIC(8,3)); +-- COL1: 22.36 (NUMERIC(8, 3)) + +/* types */ +VALUES CAST(10.24 AS NUMERIC(4,2)) * CAST(12.123 AS NUMERIC(8,3)); +-- COL1: 124.13952 (NUMERIC(32, 5)) diff --git a/tests/order.sql b/tests/order.sql index 112f51f..ef6083a 100644 --- a/tests/order.sql +++ b/tests/order.sql @@ -66,13 +66,13 @@ EXPLAIN SELECT * FROM foo ORDER BY ABS(10 - x); -- EXPLAIN: ORDER BY ABS(10 - X) ASC -- EXPLAIN: EXPR (":memory:".PUBLIC.FOO.X DOUBLE PRECISION, ":memory:".PUBLIC.FOO.Y CHARACTER VARYING(32)) -SELECT * FROM foo ORDER BY ABS(10.0 - x); +SELECT * FROM foo ORDER BY ABS(10e0 - x); -- X: 12.34e0 Y: there -- X: 5.6e0 Y: bar -- X: 1.234e0 Y: hi -- X: 0.1234e0 Y: hi -SELECT * FROM foo ORDER BY ABS(10.0 - x) DESC; +SELECT * FROM foo ORDER BY ABS(10e0 - x) DESC; -- X: 0.1234e0 Y: hi -- X: 1.234e0 Y: hi -- X: 5.6e0 Y: bar diff --git a/tests/select-where.sql b/tests/select-where.sql index 8d9f536..860cb7b 100644 --- a/tests/select-where.sql +++ b/tests/select-where.sql @@ -6,7 +6,7 @@ INSERT INTO foo (num) VALUES (35); EXPLAIN SELECT * FROM foo WHERE num = 27.0; -- EXPLAIN: TABLE ":memory:".PUBLIC.FOO (NUM DOUBLE PRECISION) --- EXPLAIN: WHERE NUM = 27e0 +-- EXPLAIN: WHERE NUM = 27 -- EXPLAIN: EXPR (":memory:".PUBLIC.FOO.NUM DOUBLE PRECISION) SELECT * FROM foo WHERE num = 27.0; @@ -28,7 +28,7 @@ SELECT * FROM foo WHERE num < 27.0; EXPLAIN SELECT * FROM foo WHERE num <= 27.0; -- EXPLAIN: TABLE ":memory:".PUBLIC.FOO (NUM DOUBLE PRECISION) --- EXPLAIN: WHERE NUM <= 27e0 +-- EXPLAIN: WHERE NUM <= 27 -- EXPLAIN: EXPR (":memory:".PUBLIC.FOO.NUM DOUBLE PRECISION) SELECT * FROM foo WHERE num <= 27.0; @@ -37,7 +37,7 @@ SELECT * FROM foo WHERE num <= 27.0; EXPLAIN SELECT * FROM foo WHERE foo.num = 27.0; -- EXPLAIN: TABLE ":memory:".PUBLIC.FOO (NUM DOUBLE PRECISION) --- EXPLAIN: WHERE FOO.NUM = 27e0 +-- EXPLAIN: WHERE FOO.NUM = 27 -- EXPLAIN: EXPR (":memory:".PUBLIC.FOO.NUM DOUBLE PRECISION) SELECT * FROM foo WHERE foo.num = 27.0; diff --git a/tests/update.sql b/tests/update.sql index 239796c..e3cf5c2 100644 --- a/tests/update.sql +++ b/tests/update.sql @@ -55,7 +55,7 @@ UPDATE foo SET baz = NULL; CREATE TABLE foo (baz FLOAT); INSERT INTO foo (baz) VALUES (-123); -UPDATE foo SET baz = -223.0 * 4.2; +UPDATE foo SET baz = -223.0e0 * 4.2e0; SELECT * FROM foo; -- msg: CREATE TABLE 1 -- msg: INSERT 1 @@ -64,7 +64,7 @@ SELECT * FROM foo; CREATE TABLE foo (baz FLOAT); INSERT INTO foo (baz) VALUES (-123); -UPDATE foo SET baz = baz * 4.2; +UPDATE foo SET baz = baz * 4.2e0; SELECT * FROM foo; -- msg: CREATE TABLE 1 -- msg: INSERT 1 @@ -73,7 +73,7 @@ SELECT * FROM foo; CREATE TABLE foo (baz FLOAT); INSERT INTO foo (baz) VALUES (-123); -UPDATE foo SET baz = foo.baz * 4.2; +UPDATE foo SET baz = foo.baz * 4.2e0; SELECT * FROM foo; -- msg: CREATE TABLE 1 -- msg: INSERT 1 @@ -86,7 +86,7 @@ UPDATE foo.bar SET baz = baz * 4.2; CREATE SCHEMA foo; CREATE TABLE foo.bar (baz FLOAT); INSERT INTO foo.bar (baz) VALUES (-123); -UPDATE foo.bar SET baz = baz * 4.2; +UPDATE foo.bar SET baz = baz * 4.2e0; SELECT * FROM foo.bar; -- msg: CREATE SCHEMA 1 -- msg: CREATE TABLE 1 diff --git a/tests/values.sql b/tests/values.sql index 1ac4600..6de92c7 100644 --- a/tests/values.sql +++ b/tests/values.sql @@ -9,12 +9,12 @@ EXPLAIN SELECT * FROM (VALUES 1); EXPLAIN SELECT * FROM (VALUES 1.23); -- EXPLAIN: $1: --- EXPLAIN: VALUES (COL1 DOUBLE PRECISION) = ROW(1.23e0) --- EXPLAIN: TABLE $1 (COL1 DOUBLE PRECISION) --- EXPLAIN: EXPR ($1.COL1 DOUBLE PRECISION) +-- EXPLAIN: VALUES (COL1 NUMERIC(3, 2)) = ROW(1.23) +-- EXPLAIN: TABLE $1 (COL1 NUMERIC(3, 2)) +-- EXPLAIN: EXPR ($1.COL1 NUMERIC(3, 2)) SELECT * FROM (VALUES 1.23); --- COL1: 1.23e0 +-- COL1: 1.23 SELECT * FROM (VALUES 1, 'foo', TRUE); -- COL1: 1 @@ -52,11 +52,11 @@ VALUES 'cool'; /* types */ VALUES 'cool', 12.3; -- COL1: cool (CHARACTER(4)) --- COL1: 12.3e0 (DOUBLE PRECISION) +-- COL1: 12.3 (NUMERIC(3, 1)) /* types */ VALUES ROW('cool', 12.3); --- COL1: cool (CHARACTER(4)) COL2: 12.3e0 (DOUBLE PRECISION) +-- COL1: cool (CHARACTER(4)) COL2: 12.3 (NUMERIC(3, 1)) /* types */ VALUES '12.3'; @@ -70,10 +70,10 @@ EXPLAIN VALUES 'hello'; -- EXPLAIN: VALUES (COL1 CHARACTER(5)) = ROW('hello') EXPLAIN VALUES 'hello', 1.22; --- EXPLAIN: VALUES (COL1 CHARACTER(5)) = ROW('hello'), ROW(1.22e0) +-- EXPLAIN: VALUES (COL1 CHARACTER(5)) = ROW('hello'), ROW(1.22) EXPLAIN VALUES ROW('hello', 1.22); --- EXPLAIN: VALUES (COL1 CHARACTER(5), COL2 DOUBLE PRECISION) = ROW('hello', 1.22e0) +-- EXPLAIN: VALUES (COL1 CHARACTER(5), COL2 NUMERIC(3, 2)) = ROW('hello', 1.22) SELECT * FROM (VALUES ROW(123), ROW(456)); -- COL1: 123 diff --git a/vsql/connection.v b/vsql/connection.v index 7929725..858e3aa 100644 --- a/vsql/connection.v +++ b/vsql/connection.v @@ -299,13 +299,6 @@ fn (conn Connection) find_function(func_name string, arg_types []Type) !Func { for i, t in arg_types { mut real_arg_type := t - // TODO(elliotchance): There is a special case where numeric literals are - // treated as DOUBLE PRECISION. This will be changed in the future when we - // have proper support for NUMERIC. - if t.typ == .is_numeric && t.scale == 0 { - real_arg_type = Type{SQLType.is_double_precision, 0, 0, false} - } - // TODO(elliotchance); For now, we just consider all CHARACTER types as // CHARACTER VARYING. if t.typ == .is_character { diff --git a/vsql/funcs.v b/vsql/funcs.v index 45ea444..7111f3c 100644 --- a/vsql/funcs.v +++ b/vsql/funcs.v @@ -14,24 +14,30 @@ fn register_builtin_funcs(mut conn Connection) ! { double_precision := Type{SQLType.is_double_precision, 0, 0, false} integer := Type{SQLType.is_integer, 0, 0, false} varchar := Type{SQLType.is_varchar, 0, 0, false} + numeric := Type{SQLType.is_numeric, 0, 0, false} // Scalar functions. conn.register_func(Func{'ABS', [double_precision], false, func_abs, double_precision})! + conn.register_func(Func{'ABS', [numeric], false, func_abs_numeric, numeric})! conn.register_func(Func{'ACOS', [double_precision], false, func_acos, double_precision})! conn.register_func(Func{'ASIN', [double_precision], false, func_asin, double_precision})! conn.register_func(Func{'ATAN', [double_precision], false, func_atan, double_precision})! conn.register_func(Func{'CEIL', [double_precision], false, func_ceil, double_precision})! + conn.register_func(Func{'CEIL', [numeric], false, func_ceil_numeric, numeric})! conn.register_func(Func{'CEILING', [double_precision], false, func_ceil, double_precision})! + conn.register_func(Func{'CEILING', [numeric], false, func_ceil_numeric, numeric})! conn.register_func(Func{'CHARACTER_LENGTH', [varchar], false, func_char_length, integer})! conn.register_func(Func{'CHAR_LENGTH', [varchar], false, func_char_length, integer})! conn.register_func(Func{'COS', [double_precision], false, func_cos, double_precision})! conn.register_func(Func{'COSH', [double_precision], false, func_cosh, double_precision})! conn.register_func(Func{'EXP', [double_precision], false, func_exp, double_precision})! conn.register_func(Func{'FLOOR', [double_precision], false, func_floor, double_precision})! + conn.register_func(Func{'FLOOR', [numeric], false, func_floor_numeric, numeric})! conn.register_func(Func{'LN', [double_precision], false, func_ln, double_precision})! conn.register_func(Func{'LOG10', [double_precision], false, func_log10, double_precision})! conn.register_func(Func{'LOWER', [varchar], false, func_lower, varchar})! conn.register_func(Func{'MOD', [double_precision, double_precision], false, func_mod, double_precision})! + conn.register_func(Func{'MOD', [numeric, numeric], false, func_mod_numeric, numeric})! conn.register_func(Func{'OCTET_LENGTH', [varchar], false, func_octet_length, integer})! conn.register_func(Func{'POSITION', [varchar, varchar], false, func_position, integer})! conn.register_func(Func{'POWER', [double_precision, double_precision], false, func_power, double_precision})! diff --git a/vsql/numeric.v b/vsql/numeric.v new file mode 100644 index 0000000..765906c --- /dev/null +++ b/vsql/numeric.v @@ -0,0 +1,363 @@ +// numeric.v contains the implementation and operations for the DECIMAL and +// NUMERIC types. + +module vsql + +import math +import math.big +import strings + +// These are used for encoding certain aspects for storage. +const numeric_is_null = u8(1 << 0) +const numeric_is_zero = u8(1 << 1) +const numeric_is_negative = u8(1 << 2) + +struct Numeric { + // typ contains the precision and scale that affect calculations. + typ Type + is_null bool + // numerator contains the sign (+/-) and may be zero, however, you should + // always test the denominator for an actual zero. + numerator big.Integer + // denominator will not be negative. It may be zero to represent a zero value. + denominator big.Integer +} + +fn new_numeric(typ Type, numerator big.Integer, denominator big.Integer) Numeric { + return Numeric{ + typ: typ + numerator: numerator + denominator: denominator + } +} + +fn new_null_numeric(typ Type) Numeric { + return Numeric{ + typ: typ + is_null: true + } +} + +fn new_numeric_from_f64(x f64) Numeric { + parts := '${x}'.split('e') + mut n := new_numeric_from_string(parts[0]) + if parts.len > 1 { + negative_exponent := parts[1].starts_with('-') + exponent := if negative_exponent { + '1' + strings.repeat(`0`, parts[1][1..].int()) + } else { + '1' + strings.repeat(`0`, parts[1].int()) + } + if negative_exponent { + // It's not possible for the divide to fail because the exponent will + // always be >= 1. + n = n.divide(new_numeric_from_string(exponent)) or { panic(err) } + } else { + n = n.multiply(new_numeric_from_string(exponent)) + } + } + + return n +} + +// NOTE: numeric value is expected to be well formed. +fn new_numeric_from_string(x string) Numeric { + // ISO/IEC 9075-2:2016(E), 5.3 : + // 22) The declared type of an ENL is an + // implementation-defined exact numeric type whose scale is the number of + // s to the right of the . There shall be an exact numeric type + // capable of representing the value of ENL exactly. + + if x.contains('e') || x.contains('E') { + return new_numeric_from_f64(x.f64()) + } + + mut n := x + + is_negative := n[0] == `-` + if is_negative { + n = n[1..] + } + + mut size := 1 + mut scale := i16(0) + + parts := n.split('.') + if parts.len == 1 { + size = parts[0].len + } else { + size = parts[0].len + parts[1].len + scale = i16(parts[1].len) + } + + mut numerator := big.integer_from_string(parts[0]) or { big.zero_int } + mut denominator := big.one_int + + if parts.len == 2 { + denominator = big.integer_from_int(10).pow(u32(parts[1].len)) + numerator *= denominator + numerator += big.integer_from_string(parts[1]) or { big.zero_int } + } + + if is_negative { + numerator = numerator.neg() + } + + typ := Type{.is_numeric, size, scale, false} + return new_numeric(typ, numerator, denominator) +} + +fn (n Numeric) bytes() []u8 { + mut buf := new_bytes([]u8{}) + mut flags := u8(0) + if n.is_null { + flags |= vsql.numeric_is_null + } + if n.is_zero() { + flags |= vsql.numeric_is_zero + } + if n.is_negative() { + flags |= vsql.numeric_is_negative + } + buf.write_u8(flags) + + // If the value is NULL or 0 we don't need to encode anything further. + if flags & vsql.numeric_is_null != 0 || flags & vsql.numeric_is_zero != 0 { + return buf.bytes() + } + + numerator, _ := n.numerator.bytes() + buf.write_i16(i16(numerator.len)) + buf.write_u8s(numerator) + + denominator, _ := n.denominator.bytes() + buf.write_i16(i16(denominator.len)) + buf.write_u8s(denominator) + + return buf.bytes() +} + +fn new_numeric_from_bytes(typ Type, data []u8) Numeric { + mut buf := new_bytes(data) + flags := buf.read_u8() + + if flags & vsql.numeric_is_null != 0 { + return new_null_numeric(typ) + } + + if flags & vsql.numeric_is_zero != 0 { + return new_numeric(typ, big.zero_int, big.zero_int) + } + + numerator_len := buf.read_i16() + mut numerator := big.integer_from_bytes(buf.read_u8s(numerator_len), big.IntegerConfig{}) + + denominator_len := buf.read_i16() + denominator := big.integer_from_bytes(buf.read_u8s(denominator_len), big.IntegerConfig{}) + + if flags & vsql.numeric_is_negative != 0 { + numerator = numerator.neg() + } + + return new_numeric(typ, numerator, denominator) +} + +fn (n Numeric) str() string { + if n.is_null { + return 'NULL' + } + + denominator := big.integer_from_int(10).pow(u32(n.typ.scale)) + denominator_str := denominator.str() + mut numerator := n.scale_numerator(denominator).numerator.str() + + // Remove the negative, this messes with length offsets. + if n.is_negative() { + numerator = numerator[1..] + } + + mut s := if numerator.str().len >= denominator_str.len { + numerator[..numerator.len - denominator_str.len + 1] + '.' + + numerator[numerator.len - denominator_str.len + 1..] + } else { + '0.' + '0'.repeat(denominator_str.len - numerator.len - 1) + numerator.str() + } + + if n.is_negative() { + s = '-' + s + } + + // This trims off the extra digit from above. We also need to remove a + // possible trailing '.'. + return s.trim_right('.') +} + +fn (n Numeric) neg() Numeric { + return new_numeric(n.typ, big.zero_int - n.numerator, n.denominator) +} + +fn (n Numeric) f64() f64 { + return n.numerator.str().f64() / n.denominator.str().f64() +} + +// TODO(elliotchance): This doesn't correctly round, it just truncates the +// value. That because this is an extra expensive and hacky approach. Please +// improve it. +fn (n Numeric) round(scale i16) Numeric { + parts := n.str().split('.') + + // Check if there's enough digits to round. + if parts.len < 2 || parts[1].len <= scale { + return n + } + + numerator := big.integer_from_string(parts[0] + parts[1][..scale]) or { big.one_int } + denominator := n.denominator / big.integer_from_int(10).pow(u32(-(scale - n.denominator.str().len) - 1)) + + return new_numeric(Type{ + typ: n.typ.typ + size: n.typ.size + scale: scale + not_null: n.typ.not_null + }, numerator, denominator) +} + +fn (n Numeric) add(n2 Numeric) Numeric { + a, b := common_denominator(n, n2) + x := new_numeric(a.typ, a.numerator + b.numerator, a.denominator) + return x.normalize_denominator(n.typ) +} + +fn (n Numeric) subtract(n2 Numeric) Numeric { + a, b := common_denominator(n, n2) + x := new_numeric(a.typ, a.numerator - b.numerator, a.denominator) + return x.normalize_denominator(n.typ) +} + +fn (n Numeric) multiply(n2 Numeric) Numeric { + typ := new_type(n.typ.typ.str(), n.typ.size * n2.typ.size, n.typ.scale + n2.typ.scale) + x := new_numeric(typ, n.numerator * n2.numerator, n.denominator * n2.denominator) + return x.normalize_denominator(typ) +} + +fn (n Numeric) divide(n2 Numeric) !Numeric { + if n2.is_zero() { + return sqlstate_22012() // division by zero + } + + return n.multiply(n2.reciprocal()) +} + +fn (n Numeric) is_zero() bool { + return n.denominator == big.zero_int +} + +fn (n Numeric) is_negative() bool { + return n.numerator.signum == -1 +} + +// scale_numerator will return a new Numeric with a numerator that has been +// scaled (larger or smaller) to match the denominator. Where denominator is +// expected to be 10^x. +fn (n Numeric) scale_numerator(denominator big.Integer) Numeric { + // Ideally we would just divide the existing denominator with denominator, but + // since we're dealing with integers we would almost certainly lose a lot of + // precision, for example: + // + // 187/90 (~2.07777) -> (187*x)/100 + // + // Where x = 100/90, would be 1 (because it's an int), so the result would be: + // + // (187*1)/100 = 187/100 (~1.87) + // + // Which is obviously incorrect. So to avoid this we need to scale up the + // divide operation: + // + // Where s = 1000, x = (100 * s)/90, would be 1111, so the result would be: + // + // (187*1111)/(100 * s) = 207757/100000 (~2.07757) + // + // Now divide the numerator back down by s: + // + // (207757/s)/100 = 207/100 (~2.07) + + // scale+1 seems to be enough for most cases, however, it can result in x = 0, + // but using scale+2 as the multiplier seems to fix that. + s := denominator * big.integer_from_int(10).pow(u32(n.typ.scale + 2)) + + x := (denominator * s) / n.denominator + numerator := (n.numerator * x) / s + + return new_numeric(n.typ, numerator, denominator) +} + +// This is an important step for NUMERIC and DECIMAL after every operation to +// make sure the denominator is scaled correctly, which may cause the value to +// lose precision if it goes beyond the specified precision. +fn (n Numeric) normalize_denominator(typ Type) Numeric { + denominator := big.integer_from_int(10).pow(u32(typ.scale)) + max_denominator := big.integer_from_int(10).pow(u32(typ.scale + 1)) - big.one_int + + // NUMERICAL only need to scale when the denominator goes beyond the bounds. + if typ.typ == .is_numeric && n.denominator > max_denominator { + return n.scale_numerator(denominator) + } + + // DECIMAL always needs to have a fixed denominator. + if typ.typ == .is_decimal && n.denominator != denominator { + return n.scale_numerator(denominator) + } + + // No scaling needed. Avoid any unnecessary math. + return n +} + +fn common_denominator(n1 Numeric, n2 Numeric) (Numeric, Numeric) { + if n1.denominator == n2.denominator { + return n1, n2 + } + + // Pick the highest scale for the result. + typ := if n1.typ.scale > n2.typ.scale { n1.typ } else { n2.typ } + + n3 := new_numeric(typ, n1.numerator * n2.denominator, n1.denominator * n2.denominator) + n4 := new_numeric(typ, n2.numerator * n1.denominator, n2.denominator * n1.denominator) + + return n3, n4 +} + +fn (n Numeric) equals(n2 Numeric) bool { + n3, n4 := common_denominator(n, n2) + + return n3.numerator == n4.numerator +} + +fn (n Numeric) less_than(n2 Numeric) bool { + n3, n4 := common_denominator(n, n2) + + return n3.numerator < n4.numerator +} + +fn (n Numeric) greater_than(n2 Numeric) bool { + n3, n4 := common_denominator(n, n2) + + return n3.numerator > n4.numerator +} + +fn (n Numeric) i64() i64 { + return n.integer().int() +} + +fn (n Numeric) integer() big.Integer { + return n.numerator / n.denominator +} + +fn (n Numeric) reciprocal() Numeric { + return new_numeric(n.typ, n.denominator, n.numerator) +} + +fn (n Numeric) trunc() Numeric { + // TODO(elliotchance): I'm sure this is not the most efficient way to do this. + // Please improve. + return new_numeric_from_string(n.str().split('.')[0]) +} diff --git a/vsql/operators.v b/vsql/operators.v index 9b196c4..3abb464 100644 --- a/vsql/operators.v +++ b/vsql/operators.v @@ -16,6 +16,7 @@ fn register_operators(mut conn Connection) { fn register_unary_operators(mut conn Connection) { conn.unary_operators['- NUMERIC'] = unary_negate_numeric + conn.unary_operators['- DECIMAL'] = unary_negate_decimal conn.unary_operators['- BIGINT'] = unary_negate_bigint conn.unary_operators['- DOUBLE PRECISION'] = unary_negate_double_precision conn.unary_operators['- REAL'] = unary_negate_real @@ -23,6 +24,7 @@ fn register_unary_operators(mut conn Connection) { conn.unary_operators['- INTEGER'] = unary_negate_integer conn.unary_operators['+ NUMERIC'] = unary_passthru + conn.unary_operators['+ DECIMAL'] = unary_passthru conn.unary_operators['+ BIGINT'] = unary_passthru conn.unary_operators['+ DOUBLE PRECISION'] = unary_passthru conn.unary_operators['+ REAL'] = unary_passthru @@ -36,6 +38,11 @@ fn register_binary_operators(mut conn Connection) { conn.binary_operators['NUMERIC * NUMERIC'] = binary_numeric_multiply_numeric conn.binary_operators['NUMERIC / NUMERIC'] = binary_numeric_divide_numeric + conn.binary_operators['DECIMAL + DECIMAL'] = binary_decimal_plus_decimal + conn.binary_operators['DECIMAL - DECIMAL'] = binary_decimal_minus_decimal + conn.binary_operators['DECIMAL * DECIMAL'] = binary_decimal_multiply_decimal + conn.binary_operators['DECIMAL / DECIMAL'] = binary_decimal_divide_decimal + conn.binary_operators['DOUBLE PRECISION + DOUBLE PRECISION'] = binary_double_precision_plus_double_precision conn.binary_operators['DOUBLE PRECISION - DOUBLE PRECISION'] = binary_double_precision_minus_double_precision conn.binary_operators['DOUBLE PRECISION * DOUBLE PRECISION'] = binary_double_precision_multiply_double_precision @@ -67,11 +74,11 @@ fn unary_passthru(conn &Connection, v Value) !Value { } fn unary_negate_numeric(conn &Connection, v Value) !Value { - if v.string_value().starts_with('-') { - return new_numeric_value(v.string_value()[1..]) - } + return new_numeric_value_from_numeric(v.numeric_value().neg()) +} - return new_numeric_value('-${v.string_value()}') +fn unary_negate_decimal(conn &Connection, v Value) !Value { + return new_decimal_value_from_numeric(v.numeric_value().neg()) } fn unary_negate_bigint(conn &Connection, v Value) !Value { @@ -96,6 +103,17 @@ fn unary_negate_real(conn &Connection, v Value) !Value { return new_real_value(f32(-v.f64_value())) } +fn unary_not_boolean(conn &Connection, v Value) !Value { + if v.is_null { + return new_unknown_value() + } + + return match v.bool_value() { + .is_true { new_boolean_value(false) } + .is_false { new_boolean_value(true) } + } +} + fn binary_double_precision_plus_double_precision(conn &Connection, a Value, b Value) !Value { return new_double_precision_value(a.f64_value() + b.f64_value()) } @@ -111,7 +129,7 @@ fn binary_bigint_plus_bigint(conn &Connection, a Value, b Value) !Value { x := big.integer_from_i64(a.as_int()) y := big.integer_from_i64(b.as_int()) z := x + y - check_numeric_range(z, .is_bigint)! + check_numeric_range(new_numeric_from_string(z.str()), .is_bigint)! return new_bigint_value(z.int()) } @@ -130,7 +148,7 @@ fn binary_bigint_minus_bigint(conn &Connection, a Value, b Value) !Value { x := big.integer_from_i64(a.as_int()) y := big.integer_from_i64(b.as_int()) z := x - y - check_numeric_range(z, .is_bigint)! + check_numeric_range(new_numeric_from_string(z.str()), .is_bigint)! return new_bigint_value(z.int()) } @@ -149,7 +167,7 @@ fn binary_bigint_multiply_bigint(conn &Connection, a Value, b Value) !Value { x := big.integer_from_i64(a.as_int()) y := big.integer_from_i64(b.as_int()) z := x * y - check_numeric_range(z, .is_bigint)! + check_numeric_range(new_numeric_from_string(z.str()), .is_bigint)! return new_bigint_value(z.int()) } @@ -178,15 +196,15 @@ fn binary_bigint_divide_bigint(conn &Connection, a Value, b Value) !Value { } fn binary_numeric_plus_numeric(conn &Connection, a Value, b Value) !Value { - return new_numeric_value(f64_string(a.as_f64()! + b.as_f64()!, 64)) + return new_numeric_value_from_numeric(a.numeric_value().add(b.numeric_value())) } fn binary_numeric_minus_numeric(conn &Connection, a Value, b Value) !Value { - return new_numeric_value(f64_string(a.as_f64()! - b.as_f64()!, 64)) + return new_numeric_value_from_numeric(a.numeric_value().subtract(b.numeric_value())) } fn binary_numeric_multiply_numeric(conn &Connection, a Value, b Value) !Value { - return new_numeric_value(f64_string(a.as_f64()! * b.as_f64()!, 64)) + return new_numeric_value_from_numeric(a.numeric_value().multiply(b.numeric_value())) } fn binary_numeric_divide_numeric(conn &Connection, a Value, b Value) !Value { @@ -194,7 +212,7 @@ fn binary_numeric_divide_numeric(conn &Connection, a Value, b Value) !Value { return sqlstate_22012() // division by zero } - return new_numeric_value(f64_string(a.as_f64()! / b.as_f64()!, 64)) + return new_numeric_value_from_numeric(a.numeric_value().divide(b.numeric_value())!) } fn binary_smallint_plus_smallint(conn &Connection, a Value, b Value) !Value { @@ -245,3 +263,19 @@ fn binary_real_divide_real(conn &Connection, a Value, b Value) !Value { return new_real_value(f32(a.f64_value() / b.f64_value())) } + +fn binary_decimal_plus_decimal(conn &Connection, a Value, b Value) !Value { + return new_decimal_value_from_numeric(a.numeric_value().add(b.numeric_value())) +} + +fn binary_decimal_minus_decimal(conn &Connection, a Value, b Value) !Value { + return new_decimal_value_from_numeric(a.numeric_value().subtract(b.numeric_value())) +} + +fn binary_decimal_multiply_decimal(conn &Connection, a Value, b Value) !Value { + return new_decimal_value_from_numeric(a.numeric_value().multiply(b.numeric_value())) +} + +fn binary_decimal_divide_decimal(conn &Connection, a Value, b Value) !Value { + return new_decimal_value_from_numeric(a.numeric_value().divide(b.numeric_value())!) +} diff --git a/vsql/query_cache.v b/vsql/query_cache.v index b26700d..ba77bc3 100644 --- a/vsql/query_cache.v +++ b/vsql/query_cache.v @@ -41,61 +41,106 @@ fn (q QueryCache) prepare_stmt(tokens []Token) (string, map[string]Value, []Toke // placeholder so it can be replaced in place? mut new_tokens := []Token{cap: tokens.len} - for j, token in tokens { - mut ignore := false - - // Do not replace with placeholders for parts of a number. - // - // TODO(elliotchance): This should actually replace the exact decimal - // number with a placeholder instead of ignoring. - if j < tokens.len - 1 && tokens[j + 1].kind == .period { - ignore = true - } - if j > 0 && tokens[j - 1].kind == .period { - ignore = true + mut j := 0 + for j < tokens.len { + token := tokens[j] + + // Special handling for named literals. + if j < tokens.len - 1 && token.kind == .keyword + && (token.value == 'TIMESTAMP' || token.value == 'TIME' || token.value == 'DATE') + && tokens[j + 1].kind == .literal_string { + v := match token.value { + 'DATE' { + new_date_value(tokens[j + 1].value) or { panic(err) } + } + 'TIME' { + new_time_value(tokens[j + 1].value) or { panic(err) } + } + 'TIMESTAMP' { + new_timestamp_value(tokens[j + 1].value) or { panic(err) } + } + else { + panic(token.value) + } + } + params['P${i}'] = v + + key += ':P${i} ' + new_tokens << Token{.colon, ':'} + new_tokens << Token{.literal_identifier, 'P${i}'} + i++ + + j += 2 + continue } - // Do not replace with placeholders for string literals that are part of - // date time literals, these have to stay as strings because they are - // parsed internally. - if j > 0 && tokens[j - 1].kind == .keyword && (tokens[j - 1].value == 'TIMESTAMP' - || tokens[j - 1].value == 'TIME' || tokens[j - 1].value == 'DATE') { - ignore = true + // Do not replace numbers that appear in types. Such as 'NUMERIC(10, 2)'. + if j < tokens.len - 6 && token.kind == .keyword + && (token.value == 'DECIMAL' || token.value == 'NUMERIC') && tokens[j + 1].value == '(' + && tokens[j + 3].value == ',' { + key += tokens[j].value.to_upper() + ' ' + key += tokens[j + 1].value.to_upper() + ' ' + key += tokens[j + 2].value.to_upper() + ' ' + key += tokens[j + 3].value.to_upper() + ' ' + key += tokens[j + 4].value.to_upper() + ' ' + key += tokens[j + 5].value.to_upper() + ' ' + new_tokens << tokens[j..j + 6] + j += 6 + continue } // Do not replace numbers that appear in types. Such as 'VARCHAR(10)'. - if j > 1 && tokens[j - 2].kind == .keyword { - ignore = true + if j < tokens.len - 4 && token.kind == .keyword && (token.value == 'VARCHAR' + || token.value == 'CHAR' || token.value == 'VARYING' + || token.value == 'DECIMAL' || token.value == 'NUMERIC' + || token.value == 'TIMESTAMP' || token.value == 'TIME') && tokens[j + 1].value == '(' { + key += tokens[j].value.to_upper() + ' ' + key += tokens[j + 1].value.to_upper() + ' ' + key += tokens[j + 2].value.to_upper() + ' ' + key += tokens[j + 3].value.to_upper() + ' ' + new_tokens << tokens[j..j + 4] + j += 4 + continue } - if !ignore { - match token.kind { - .literal_number { - // This should never fail as the value is already well formed, but we - // have to satisfy the compiler with an "or". - v := numeric_literal(token.value) or { panic(err) } - params['P${i}'] = v - - key += ':P${i} ' - new_tokens << Token{.colon, ':'} - new_tokens << Token{.literal_identifier, 'P${i}'} - i++ - continue - } - .literal_string { - key += ':P${i} ' - params['P${i}'] = new_varchar_value(token.value) - new_tokens << Token{.colon, ':'} - new_tokens << Token{.literal_identifier, 'P${i}'} - i++ - continue + match token.kind { + .literal_number { + mut numeric_tokens := '' + // Numeric values with a decimal and approximate literals (1e2) are + // actually multiple tokens like [number, '.' number] or + // [number, 'E', number] so we need to be careful to consume all. + for j < tokens.len && (tokens[j].kind == .literal_number + || tokens[j].kind == .period || tokens[j].value == 'E') { + numeric_tokens += tokens[j].value + j++ } - else {} + + // This should never fail as the value is already well formed, but we + // have to satisfy the compiler with an "or". + v := numeric_literal(numeric_tokens) or { panic(numeric_tokens) } + params['P${i}'] = v + + key += ':P${i} ' + new_tokens << Token{.colon, ':'} + new_tokens << Token{.literal_identifier, 'P${i}'} + i++ + continue + } + .literal_string { + key += ':P${i} ' + params['P${i}'] = new_varchar_value(token.value) + new_tokens << Token{.colon, ':'} + new_tokens << Token{.literal_identifier, 'P${i}'} + i++ + j++ + continue } + else {} } key += token.value.to_upper() + ' ' new_tokens << token + j++ } return key, params, new_tokens diff --git a/vsql/row.v b/vsql/row.v index 3779fa4..db37c30 100644 --- a/vsql/row.v +++ b/vsql/row.v @@ -153,8 +153,8 @@ fn new_empty_value(typ Type) Value { .is_varchar { new_varchar_value('') } - .is_numeric { - panic('NUMERIC error') + .is_numeric, .is_decimal { + new_numeric_value('0') } } @@ -191,15 +191,12 @@ fn (r Row) bytes(t Table) []u8 { .is_varchar, .is_character, .is_date, .is_time_with_time_zone, .is_time_without_time_zone, .is_timestamp_with_time_zone, .is_timestamp_without_time_zone, .is_bigint, .is_double_precision, .is_integer, - .is_real, .is_smallint { + .is_real, .is_smallint, .is_numeric, .is_decimal { buf.write_bool(v.is_null) } .is_boolean { // BOOLEAN: NULL is encoded as one of the values. } - .is_numeric { - panic('NUMERIC error') - } } } @@ -231,8 +228,10 @@ fn (r Row) bytes(t Table) []u8 { .is_timestamp_with_time_zone, .is_timestamp_without_time_zone { buf.write_u8s(v.time_value().bytes()) } - .is_numeric { - panic('NUMERIC error') + .is_numeric, .is_decimal { + bytes := v.numeric_value().bytes() + buf.write_i16(i16(bytes.len)) + buf.write_u8s(bytes) } } } @@ -262,15 +261,12 @@ fn new_row_from_bytes(t Table, data []u8, tid int) Row { .is_varchar, .is_character, .is_date, .is_time_with_time_zone, .is_time_without_time_zone, .is_timestamp_with_time_zone, .is_timestamp_without_time_zone, .is_bigint, .is_double_precision, .is_integer, - .is_real, .is_smallint { + .is_real, .is_smallint, .is_numeric, .is_decimal { v.is_null = buf.read_bool() } .is_boolean { // BOOLEAN: NULL is encoded as one of the values. } - .is_numeric { - panic('NUMERIC error') - } } } @@ -326,8 +322,10 @@ fn new_row_from_bytes(t Table, data []u8, tid int) Row { typ := Type{.is_timestamp_without_time_zone, col.typ.size, col.typ.scale, col.not_null} v.v.time_value = new_time_from_bytes(typ, buf.read_u8s(8)) } - .is_numeric { - panic('NUMERIC error') + .is_numeric, .is_decimal { + typ := Type{col.typ.typ, col.typ.size, col.typ.scale, col.not_null} + len := buf.read_i16() + v.v.numeric_value = new_numeric_from_bytes(typ, buf.read_u8s(len)) } } } diff --git a/vsql/std_data_type.v b/vsql/std_data_type.v index 940d29d..36ca08b 100644 --- a/vsql/std_data_type.v +++ b/vsql/std_data_type.v @@ -31,10 +31,16 @@ module vsql //~ | //~ //~ /* Type */ ::= -//~ SMALLINT -> smallint -//~ | INTEGER -> integer -//~ | INT -> integer -//~ | BIGINT -> bigint +//~ NUMERIC -> numeric1 +//~ | NUMERIC -> numeric2 +//~ | NUMERIC -> numeric3 +//~ | DECIMAL -> decimal1 +//~ | DECIMAL -> decimal2 +//~ | DECIMAL -> decimal3 +//~ | SMALLINT -> smallint +//~ | INTEGER -> integer +//~ | INT -> integer +//~ | BIGINT -> bigint //~ //~ /* Type */ ::= //~ FLOAT -> float @@ -55,6 +61,9 @@ module vsql //~ /* string */ ::= //~ //~ +//~ /* string */ ::= +//~ +//~ //~ /* Type */ ::= //~ BOOLEAN -> boolean_type //~ @@ -183,3 +192,27 @@ fn parse_no() !bool { fn parse_boolean_type() !Type { return new_type('BOOLEAN', 0, 0) } + +fn parse_numeric1() !Type { + return new_type('NUMERIC', 0, 0) +} + +fn parse_numeric2(precision string) !Type { + return new_type('NUMERIC', precision.int(), 0) +} + +fn parse_numeric3(precision string, scale string) !Type { + return new_type('NUMERIC', precision.int(), scale.i16()) +} + +fn parse_decimal1() !Type { + return new_type('DECIMAL', 0, 0) +} + +fn parse_decimal2(precision string) !Type { + return new_type('DECIMAL', precision.int(), 0) +} + +fn parse_decimal3(precision string, scale string) !Type { + return new_type('DECIMAL', precision.int(), scale.i16()) +} diff --git a/vsql/std_literal.v b/vsql/std_literal.v index 79b0c64..d78afcc 100644 --- a/vsql/std_literal.v +++ b/vsql/std_literal.v @@ -118,13 +118,18 @@ fn parse_timestamp_literal(v Value) !Value { } fn numeric_literal(x string) !Value { + // This is only to handle QueryCache.prepare_stmt(). It can be removed when + // that's no longer needed. + if x.contains('E') { + parts := x.split('E') + return new_double_precision_value(parts[0].f64() * math.pow(10, parts[1].f64())) + } + // Any number that contains a decimal (even if its a whole number) must be // treated as a NUMERIC. if x.contains('.') { // The trim handles cases of "123." which should be treated as "123". - // - // TODO(elliotchance): This needs to be new_numeric_value() once supported. - return new_double_precision_value(x.trim_right('.').f64()) + return new_numeric_value(x.trim_right('.')) } // Otherwise, we know this is an int but we have to choose the smallest type. diff --git a/vsql/std_numeric_value_expression.v b/vsql/std_numeric_value_expression.v index 1219d7f..6ac3cb9 100644 --- a/vsql/std_numeric_value_expression.v +++ b/vsql/std_numeric_value_expression.v @@ -184,7 +184,8 @@ fn parse_factor_2(sign string, expr NumericPrimary) !NumericPrimary { return ValueExpressionPrimary(NonparenthesizedValueExpressionPrimary(ValueSpecification(new_integer_value(-2147483648)))) } - if v.typ.typ == .is_numeric && v.string_value() == '9223372036854775808' { + if v.typ.typ == .is_numeric + && v.numeric_value().equals(new_numeric_from_string('9223372036854775808')) { return ValueExpressionPrimary(NonparenthesizedValueExpressionPrimary(ValueSpecification(new_bigint_value(-9223372036854775808)))) } } diff --git a/vsql/std_numeric_value_function.v b/vsql/std_numeric_value_function.v index bbafdc3..67c6ba8 100644 --- a/vsql/std_numeric_value_function.v +++ b/vsql/std_numeric_value_function.v @@ -204,6 +204,16 @@ fn func_abs(args []Value) !Value { return new_double_precision_value(math.abs(args[0].f64_value())) } +// ABS(NUMERIC) NUMERIC +fn func_abs_numeric(args []Value) !Value { + n := args[0].numeric_value() + if n.is_negative() { + return new_numeric_value_from_numeric(n.neg()) + } + + return args[0] +} + // SIN(DOUBLE PRECISION) DOUBLE PRECISION fn func_sin(args []Value) !Value { return new_double_precision_value(math.sin(args[0].f64_value())) @@ -254,6 +264,14 @@ fn func_mod(args []Value) !Value { return new_double_precision_value(math.fmod(args[0].f64_value(), args[1].f64_value())) } +// MOD(NUMERIC, NUMERIC) NUMERIC +fn func_mod_numeric(args []Value) !Value { + value := args[0].numeric_value() + modulus := args[1].numeric_value() + + return new_numeric_value_from_numeric(value.subtract(value.divide(modulus)!.trunc().multiply(modulus))) +} + // LOG(DOUBLE PRECISION) DOUBLE PRECISION fn func_log(args []Value) !Value { return new_double_precision_value(math.log2(args[0].f64_value())) @@ -289,7 +307,32 @@ fn func_floor(args []Value) !Value { return new_double_precision_value(math.floor(args[0].f64_value())) } +// FLOOR(NUMERIC) NUMERIC +fn func_floor_numeric(args []Value) !Value { + n := args[0].numeric_value() + if n.is_negative() { + return new_numeric_value_from_numeric(n.subtract(new_numeric_from_string('1')).trunc()) + } + + return new_numeric_value_from_numeric(n.trunc()) +} + // CEIL(DOUBLE PRECISION) DOUBLE PRECISION fn func_ceil(args []Value) !Value { return new_double_precision_value(math.ceil(args[0].f64_value())) } + +// CEIL(NUMERIC) NUMERIC +fn func_ceil_numeric(args []Value) !Value { + n := args[0].numeric_value() + t := n.trunc() + if n.equals(t) { + return args[0] + } + + if n.is_negative() { + return new_numeric_value_from_numeric(t) + } + + return new_numeric_value_from_numeric(t.add(new_numeric_from_string('1'))) +} diff --git a/vsql/std_routine_invocation.v b/vsql/std_routine_invocation.v index 43539e6..45fa376 100644 --- a/vsql/std_routine_invocation.v +++ b/vsql/std_routine_invocation.v @@ -36,16 +36,7 @@ fn (e RoutineInvocation) pstr(params map[string]Value) string { fn (e RoutineInvocation) compile(mut c Compiler) !CompileResult { mut arg_types := []Type{} for arg in e.args { - mut arg_type := arg.compile(mut c)!.typ - - // TODO(elliotchance): There is a special case where numeric literals are - // treated as DOUBLE PRECISION. This will be changed in the future when we - // have proper support for NUMERIC. - if arg_type.typ == .is_numeric && arg_type.scale == 0 { - arg_type = Type{.is_double_precision, 0, 0, false} - } - - arg_types << arg_type + arg_types << arg.compile(mut c)!.typ } func_name := e.function_name diff --git a/vsql/std_store_assignment.v b/vsql/std_store_assignment.v index c01bb3d..ed3262c 100644 --- a/vsql/std_store_assignment.v +++ b/vsql/std_store_assignment.v @@ -1,6 +1,5 @@ module vsql -import math.big import strings // ISO/IEC 9075-2:2016(E), 9.2, Store assignment @@ -11,17 +10,17 @@ import strings // of indicator parameters or indicator variables, such as storing SQL-data or // setting the value of SQL parameters. -const min_smallint = big.integer_from_i64(-32768) +const min_smallint = new_numeric_from_string('-32768') -const max_smallint = big.integer_from_i64(32767) +const max_smallint = new_numeric_from_string('32767') -const min_integer = big.integer_from_i64(-2147483648) +const min_integer = new_numeric_from_string('-2147483648') -const max_integer = big.integer_from_i64(2147483647) +const max_integer = new_numeric_from_string('2147483647') -const min_bigint = big.integer_from_i64(-9223372036854775808) +const min_bigint = new_numeric_from_string('-9223372036854775808') -const max_bigint = big.integer_from_i64(9223372036854775807) +const max_bigint = new_numeric_from_string('9223372036854775807') type CastFunc = fn (conn &Connection, v Value, to Type) !Value @@ -200,7 +199,8 @@ fn cast(mut conn Connection, msg string, v Value, t Type) !Value { // // All of these are not supported types, so fallthrough. // - .is_numeric, .is_smallint, .is_integer, .is_bigint, .is_real, .is_double_precision { + .is_numeric, .is_decimal, .is_smallint, .is_integer, .is_bigint, .is_real, + .is_double_precision { // - 3.b.xv. If the declared type of T is numeric, then, Case: // - 3.b.xv.1. If V is a value of the declared type of T, then the value // of T is set to V. @@ -363,7 +363,7 @@ fn cast_numeric(mut conn Connection, v Value, t Type) !Value { mut numeric_value := v.as_numeric()! check_numeric_range(numeric_value, .is_smallint)! - return new_smallint_value(i16(numeric_value.int())) + return new_smallint_value(i16(numeric_value.i64())) } .is_integer { mut numeric_value := v.as_numeric()! @@ -376,7 +376,7 @@ fn cast_numeric(mut conn Connection, v Value, t Type) !Value { return new_integer_value(-2147483648) } - return new_integer_value(numeric_value.int()) + return new_integer_value(int(numeric_value.i64())) } .is_bigint { mut numeric_value := v.as_numeric()! @@ -390,6 +390,45 @@ fn cast_numeric(mut conn Connection, v Value, t Type) !Value { .is_double_precision { return new_double_precision_value(v.as_f64()!) } + .is_numeric, .is_decimal { + // There is a special case where we should pass through an already + // NUMERIC/DECIMAL value if there is no specified destination precision. + // This will prevent as_numeric() from truncating the extra NUMERIC + // precision. Technically this is not required for DECIMAL, but it's just + // more efficient to avoid the reparsing below. + if t.size == 0 && (v.typ.typ == .is_numeric || v.typ.typ == .is_decimal) { + return v + } + + mut numeric_value := v.as_numeric()! + + // If the destination size = 0, then this is a cast to NUMERIC/DECIMAL and + // so we determine the size and scale from the original rules of a NUMERIC + // literal. + if t.size == 0 { + if t.typ == .is_numeric { + return new_numeric_value(numeric_value.str()) + } + + return new_decimal_value(numeric_value.str()) + } + + // We must not lose any significant figures. We can't trust the size of + // the existing number as all the digits may not be used. + parts := numeric_value.str().split('.') + if parts[0].trim_left('-').len > t.size - t.scale { + // numeric value out of range + return sqlstate_22003() + } + + n := new_numeric(t, numeric_value.numerator, numeric_value.denominator).normalize_denominator(t) + + if t.typ == .is_numeric { + return new_numeric_value_from_numeric(n) + } + + return new_decimal_value_from_numeric(n) + } else {} } @@ -515,20 +554,20 @@ fn cast_timestamp_without_to_timestamp_without(conn &Connection, v Value, to Typ return new_timestamp_value(v.time_value().str_full_timestamp(to.size, false, true)) } -fn check_numeric_range(x big.Integer, typ SQLType) ! { +fn check_numeric_range(x Numeric, typ SQLType) ! { match typ { .is_smallint { - if x < vsql.min_smallint || x > vsql.max_smallint { + if x.less_than(vsql.min_smallint) || x.greater_than(vsql.max_smallint) { return sqlstate_22003() } } .is_integer { - if x < vsql.min_integer || x > vsql.max_integer { + if x.less_than(vsql.min_integer) || x.greater_than(vsql.max_integer) { return sqlstate_22003() } } .is_bigint { - if x < vsql.min_bigint || x > vsql.max_bigint { + if x.less_than(vsql.min_bigint) || x.greater_than(vsql.max_bigint) { return sqlstate_22003() } } diff --git a/vsql/std_table_definition.v b/vsql/std_table_definition.v index 85a0f47..ee0e6cd 100644 --- a/vsql/std_table_definition.v +++ b/vsql/std_table_definition.v @@ -89,6 +89,11 @@ fn (stmt TableDefinition) execute(mut conn Connection, params map[string]Value, for table_element in stmt.table_elements { match table_element { Column { + if (table_element.typ.typ == .is_numeric || table_element.typ.typ == .is_decimal) + && table_element.typ.size == 0 { + return sqlstate_42601('column ${table_element.name.sub_entity_name}: ${table_element.typ.typ} must specify a size') + } + columns << Column{Identifier{ catalog_name: table_name.catalog_name schema_name: table_name.schema_name diff --git a/vsql/type.v b/vsql/type.v index 3c699b6..9c10b7d 100644 --- a/vsql/type.v +++ b/vsql/type.v @@ -30,9 +30,8 @@ enum SQLType { is_time_with_time_zone // TIME WITH TIME ZONE is_timestamp_without_time_zone // TIMESTAMP, TIMESTAMP WITHOUT TIME ZONE is_timestamp_with_time_zone // TIMESTAMP WITH TIME ZONE - // This is not actually supported yet, it is a placeholder for numeric - // literals. - is_numeric + is_decimal // DECIMAL + is_numeric // NUMERIC } // The SQL representation, such as ``TIME WITHOUT TIME ZONE``. @@ -52,6 +51,7 @@ fn (t SQLType) str() string { .is_timestamp_without_time_zone { 'TIMESTAMP WITHOUT TIME ZONE' } .is_timestamp_with_time_zone { 'TIMESTAMP WITH TIME ZONE' } .is_numeric { 'NUMERIC' } + .is_decimal { 'DECIMAL' } } } @@ -106,6 +106,12 @@ fn (t SQLType) supertype() (i16, i16) { .is_bigint { 2, 2 } + .is_decimal { + 2, 3 + } + .is_numeric { + 2, 4 + } // Approximate numeric types. .is_real { 3, 0 @@ -118,10 +124,6 @@ fn (t SQLType) supertype() (i16, i16) { .is_timestamp_without_time_zone, .is_timestamp_with_time_zone { 4, 0 } - // Numeric isn't a storage type (yet), otherwise it would be (2, 3). - .is_numeric { - 5, 0 - } } } @@ -130,11 +132,14 @@ fn most_specific_type(t1 Type, t2 Type) !Type { t2_category, t2_supertype := t2.typ.supertype() if t1_category == t2_category { + // It's important that we strip the sizes so that anything that needs to be + // cast (like an integer) will get the correct size. + if t1_supertype > t2_supertype { - return t1 + return Type{t1.typ, 0, 0, false} } - return t2 + return Type{t2.typ, 0, 0, false} } // TODO(elliotchance): Is this the correct SQLSTATE? @@ -184,6 +189,12 @@ fn new_type(name string, size int, scale i16) Type { 'TIMESTAMP WITH TIME ZONE' { Type{.is_timestamp_with_time_zone, size, scale, false} } + 'DECIMAL' { + Type{.is_decimal, size, scale, false} + } + 'NUMERIC' { + Type{.is_numeric, size, scale, false} + } else { panic(name_without_size) Type{} @@ -243,8 +254,11 @@ fn (t Type) str() string { .is_timestamp_with_time_zone { 'TIMESTAMP(${t.size}) WITH TIME ZONE' } + .is_decimal { + numeric_type_str('DECIMAL', t.size, t.scale) + } .is_numeric { - 'NUMERIC' + numeric_type_str('NUMERIC', t.size, t.scale) } } @@ -255,10 +269,6 @@ fn (t Type) str() string { return s } -fn (t Type) is_numeric_literal() bool { - return t.typ == .is_numeric && t.size == 0 -} - fn (t Type) uses_int() bool { return match t.typ { .is_boolean, .is_bigint, .is_smallint, .is_integer { @@ -266,7 +276,7 @@ fn (t Type) uses_int() bool { } .is_varchar, .is_character, .is_double_precision, .is_real, .is_date, .is_time_with_time_zone, .is_time_without_time_zone, .is_timestamp_with_time_zone, - .is_timestamp_without_time_zone, .is_numeric { + .is_timestamp_without_time_zone, .is_numeric, .is_decimal { false } } @@ -279,7 +289,7 @@ fn (t Type) uses_f64() bool { true } .is_boolean, .is_varchar, .is_character, .is_bigint, .is_smallint, .is_integer, - .is_numeric { + .is_numeric, .is_decimal { false } } @@ -289,10 +299,10 @@ fn (t Type) uses_string() bool { return match t.typ { .is_boolean, .is_double_precision, .is_bigint, .is_real, .is_smallint, .is_integer, .is_date, .is_time_with_time_zone, .is_time_without_time_zone, - .is_timestamp_with_time_zone, .is_timestamp_without_time_zone { + .is_timestamp_with_time_zone, .is_timestamp_without_time_zone, .is_numeric, .is_decimal { false } - .is_varchar, .is_character, .is_numeric { + .is_varchar, .is_character { true } } @@ -301,7 +311,7 @@ fn (t Type) uses_string() bool { fn (t Type) uses_time() bool { return match t.typ { .is_boolean, .is_double_precision, .is_bigint, .is_real, .is_smallint, .is_integer, - .is_varchar, .is_character, .is_numeric { + .is_varchar, .is_character, .is_numeric, .is_decimal { false } .is_date, .is_time_with_time_zone, .is_time_without_time_zone, @@ -326,7 +336,8 @@ fn (t Type) number() u8 { .is_time_without_time_zone { 10 } .is_timestamp_with_time_zone { 11 } .is_timestamp_without_time_zone { 12 } - .is_numeric { panic('NUMERIC error') } + .is_decimal { 13 } + .is_numeric { 14 } } } @@ -345,6 +356,20 @@ fn type_from_number(number u8, size int, scale i16) Type { 10 { 'TIME(${size}) WITHOUT TIME ZONE' } 11 { 'TIMESTAMP(${size}) WITH TIME ZONE' } 12 { 'TIMESTAMP(${size}) WITHOUT TIME ZONE' } + 13 { numeric_type_str('DECIMAL', size, scale) } + 14 { numeric_type_str('NUMERIC', size, scale) } else { panic(number) } }, size, scale) } + +fn numeric_type_str(typ string, size int, scale i16) string { + if size == 0 { + return typ + } + + if scale == 0 { + return '${typ}(${size})' + } + + return '${typ}(${size}, ${scale})' +} diff --git a/vsql/value.v b/vsql/value.v index ddc0b3e..57825e2 100644 --- a/vsql/value.v +++ b/vsql/value.v @@ -4,8 +4,6 @@ module vsql -import math.big -import strconv import regex // Possible values for a BOOLEAN. @@ -63,6 +61,9 @@ mut: // TIME(n) WITH TIME ZONE and TIME(n) WITHOUT TIME ZONE // TIMESTAMP(n) WITH TIME ZONE and TIMESTAMP(n) WITHOUT TIME ZONE time_value Time + // DECIMAL(n,m) + // NUMERIC(n,m) + numeric_value Numeric } // new_null_value creates a NULL value of a specific type. In SQL, all NULL @@ -165,15 +166,66 @@ pub fn new_character_value(x string) Value { } } -// This is not public yet becuase numeric is not officially supported. It's just -// to interally create a typeless numeric value. -fn new_numeric_value(x string) Value { +// new_numeric_value expects a value to be valid and the size and scale are +// determined from the value as: +// +// 123 -> NUMERIC(3, 0) +// 123. -> NUMERIC(3, 0) +// 1.23 -> NUMERIC(3, 2) +// -1.23 -> NUMERIC(3, 2) +// 12.00 -> NUMERIC(4, 2) +// +pub fn new_numeric_value(x string) Value { + n := new_numeric_from_string(x) + return Value{ - // size = 0 means that we don't know the precision yet. It will have to be - // converted to something else at some point. - typ: Type{.is_numeric, 0, 0, false} + typ: n.typ v: InternalValue{ - string_value: x + numeric_value: n.normalize_denominator(n.typ) + } + } +} + +// new_decimal_value expects a value to be valid and the size and scale are +// determined from the value as: +// +// 123 -> DECIMAL(3, 0) +// 123. -> DECIMAL(3, 0) +// 1.23 -> DECIMAL(3, 2) +// -1.23 -> DECIMAL(3, 2) +// 12.00 -> DECIMAL(4, 2) +// +pub fn new_decimal_value(x string) Value { + // All the same rules for determining NUMERIC can be used for DECIMAL, + // including denoninator being a power of 10. We just need to change it to a + // DECIMAL type. + n := new_numeric_from_string(x) + typ := new_type('DECIMAL', n.typ.size, n.typ.scale) + + return Value{ + typ: typ + v: InternalValue{ + numeric_value: n.normalize_denominator(typ) + } + } +} + +fn new_numeric_value_from_numeric(n Numeric) Value { + return Value{ + typ: n.typ + v: InternalValue{ + numeric_value: n.normalize_denominator(n.typ) + } + } +} + +fn new_decimal_value_from_numeric(n Numeric) Value { + typ := new_type('DECIMAL', n.typ.size, n.typ.scale) + + return Value{ + typ: typ + v: InternalValue{ + numeric_value: n.normalize_denominator(n.typ) } } } @@ -233,11 +285,11 @@ fn f64_string(x f64, bits i16) string { } // as_int() is not safe to use if the value is not numeric. It is used in cases -// where a placeholder might be anythign but needs to be an int (such as for an +// where a placeholder might be anything but needs to be an int (such as for an // OFFSET). fn (v Value) as_int() i64 { if v.typ.typ == .is_numeric { - return i64(v.string_value().f64()) + return i64(v.numeric_value().f64()) } if v.typ.uses_int() { @@ -272,7 +324,7 @@ fn (v Value) as_f64() !f64 { if v.typ.typ == .is_numeric { // This will always be valid because the SQL parser wouldn't allow it // otherwise. - return v.string_value().f64() + return v.numeric_value().f64() } if v.typ.uses_int() { @@ -282,22 +334,22 @@ fn (v Value) as_f64() !f64 { return v.f64_value() } -fn (v Value) as_numeric() !big.Integer { +fn (v Value) as_numeric() !Numeric { if v.typ.typ == .is_boolean { return sqlstate_22003() } if v.typ.typ == .is_numeric { - int_part := v.string_value().split('.')[0] - - return big.integer_from_string(int_part) + return v.numeric_value() } - if v.typ.uses_int() { - return big.integer_from_i64(v.int_value()) + s := v.str() + if s.contains('e') { + // This covers the approximate to exact number conversion. + return new_numeric_from_f64(v.as_f64()!) } - return big.integer_from_string(strconv.f64_to_str_l(v.f64_value()).split('.')[0]) + return new_numeric_from_string(s) } fn (v Value) pstr(params map[string]Value) string { @@ -328,13 +380,24 @@ pub fn (v Value) str() string { .is_bigint, .is_integer, .is_smallint { v.int_value().str() } - .is_varchar, .is_character, .is_numeric { + .is_varchar, .is_character { v.string_value() } .is_date, .is_time_with_time_zone, .is_time_without_time_zone, .is_timestamp_with_time_zone, .is_timestamp_without_time_zone { v.time_value().str() } + .is_decimal { + v.numeric_value().str() + } + .is_numeric { + s := v.numeric_value().str() + if s.contains('.') { + return s.trim_right('0').trim_right('.') + } + + return s + } } } @@ -367,3 +430,9 @@ pub fn (v Value) time_value() Time { return v.v.time_value } } + +pub fn (v Value) numeric_value() Numeric { + unsafe { + return v.v.numeric_value + } +}