SQLite Custom Sort Order In Python Example

We can use the order by child clause to sort the query results in the SQL statement, but it can only sort the query results by the simple and fixed order. How about ordering the query results in a complex sort order? This article will tell you how to implement it in the SQLite database with python.

1. Define A Custom Compare Function.

  1. First, you should create a python function, this function contains 2 input parameters.
  2. You should compare the 2 input parameters according to your needs, and return an integer value  -1, 0, 1, below is an example.
    '''
    This function will compare two string value. First it will convert the string to integer value, 
    then it will compare the two integer value and return related result.
    '''
    def custom_order_by_int_value(str1, str2):
        
        str1_int = int(str1[1:-1])
        
        str2_int = int(str2[1:-1])
        
        if(str1_int > str2_int):
            
            return 1
        
        elif(str1_int < str2_int):
            
            return -1
                
        else:
        
            return 0

2. Create Custom Collation With The SQLite Database Connection Object’s create_collation(name, callable) Function.

  1. The SQLite database connection object provides a create_collation(name, callable) function.
  2. The first parameter name is the custom collation name that you defined, it should be a string.
  3. The second parameter callable is the python function that you defined in step 1, in this example the custom python function is custom_order_by_int_value.
  4. The below source code will create the custom collation with the SQLite database connection object, the collation name is ‘order_by_int_value’, the collation callable python function name is custom_order_by_int_value.
    conn.create_collation('order_by_int_value', custom_order_by_int_value)
  5. Now you can use the above custom collation in your SQL statement to sort the query result by the collation python function.
    sql = "select * from " + table_name + " order by passwd collate order_by_int_value"

3. SQLite Custom Sort Order In Python Example.

  1. In this example, the SQLite database name is ‘test-sqlite.db’, the table name is ‘user_account’. Below is the table data, we can see the passed field value are all integer strings.
    id	user_name       passwd	      email
    14	jerry	        [97531]	      [email protected]
    15	tom	        [0000888]     [email protected]
  2. In the below python example source code, we will sort the user_account results data by the passwd filed integer number.
    import sqlite3
    
    import com.dev2qa.example.sqlite.util
    
    db_name = 'test-sqlite.db'
    
    table_name = 'user_account'
    
    '''
    This function will compare two string value. First it will convert the string to integer value, 
    then it will compare the two integer value and return related result.
    '''
    def custom_order_by_int_value(str1, str2):
        
        str1_int = int(str1[1:-1])
        
        str2_int = int(str2[1:-1])
        
        if(str1_int > str2_int):
            
            return 1
        
        elif(str1_int < str2_int):
            
            return -1
                
        else:
        
            return 0
        
    '''
    This function will call the above custom order function in the order by clause.
    '''
    def custom_sort_order():
        
        # get database connection to the SQLite database.
        conn = sqlite3.connect(db_name)
        
        # create collation with the custom order by function.
        conn.create_collation('order_by_int_value', custom_order_by_int_value)
        
        # get the database cursor object.
        cursor = conn.cursor()
        
        # create the sql statement with the collate clause.
        sql = "select * from " + table_name + " order by passwd collate order_by_int_value"
            
        # execute the above sql statement.    
        cursor.execute(sql)
        
        # loop in the cursor to get all the rows.
        for row in cursor:
            # print out the row.
            print(row)
            
        # commit the database connection.    
        conn.commit()
        
        # close the cursor object.
        cursor.close()
        
        # close the database connection object.
        conn.close()    
    
    if __name__ == '__main__':
        
        custom_sort_order()
        
        
        
        
    
  3. When you run the above python source code, you will get the below output in the console.
    (15, 'tom', '[0000888]', '[email protected]')
    (14, 'jerry', '[97531]', '[email protected]')

Leave a Comment

Your email address will not be published. Required fields are marked *

This site uses Akismet to reduce spam. Learn how your comment data is processed.