PostgreSQL View for active Edges
- Moved filtering logic for active edges from inline native query to a database view (edge_active_attribute_view) to simplify the query and improve maintainability.
This commit is contained in:
		
							parent
							
								
									d6fb28ebd7
								
							
						
					
					
						commit
						08679cf561
					
				@ -44,15 +44,10 @@ public interface EdgeRepository extends JpaRepository<EdgeEntity, UUID> {
 | 
				
			|||||||
            "WHERE d.id = :edgeId")
 | 
					            "WHERE d.id = :edgeId")
 | 
				
			||||||
    EdgeInfoEntity findEdgeInfoById(@Param("edgeId") UUID edgeId);
 | 
					    EdgeInfoEntity findEdgeInfoById(@Param("edgeId") UUID edgeId);
 | 
				
			||||||
 | 
					
 | 
				
			||||||
    @Query(value = "SELECT ee.id, ee.created_time, ee.additional_info, ee.customer_id, " +
 | 
					    @Query(value = "SELECT * " +
 | 
				
			||||||
            "ee.root_rule_chain_id, ee.type, ee.name, ee.label, ee.routing_key, " +
 | 
					            "FROM edge_active_attribute_view edge_active " +
 | 
				
			||||||
            "ee.secret, ee.tenant_id, ee.version " +
 | 
					            "WHERE (:textSearch IS NULL OR edge_active.name ILIKE CONCAT('%', :textSearch, '%')) " +
 | 
				
			||||||
            "FROM edge ee " +
 | 
					            "ORDER BY edge_active.id", nativeQuery = true)
 | 
				
			||||||
            "JOIN attribute_kv ON ee.id = attribute_kv.entity_id " +
 | 
					 | 
				
			||||||
            "JOIN key_dictionary ON attribute_kv.attribute_key = key_dictionary.key_id " +
 | 
					 | 
				
			||||||
            "WHERE attribute_kv.bool_v = true AND key_dictionary.key = 'active' " +
 | 
					 | 
				
			||||||
            "AND (:textSearch IS NULL OR ee.name ILIKE CONCAT('%', :textSearch, '%')) " +
 | 
					 | 
				
			||||||
            "ORDER BY ee.id", nativeQuery = true)
 | 
					 | 
				
			||||||
    Page<EdgeEntity> findActiveEdges(@Param("textSearch") String textSearch,
 | 
					    Page<EdgeEntity> findActiveEdges(@Param("textSearch") String textSearch,
 | 
				
			||||||
                                 Pageable pageable);
 | 
					                                 Pageable pageable);
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
				
			|||||||
@ -72,6 +72,25 @@ u.first_name as assignee_first_name, u.last_name as assignee_last_name, u.email
 | 
				
			|||||||
FROM alarm a
 | 
					FROM alarm a
 | 
				
			||||||
LEFT JOIN tb_user u ON u.id = a.assignee_id;
 | 
					LEFT JOIN tb_user u ON u.id = a.assignee_id;
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					DROP VIEW IF EXISTS edge_active_attribute_view CASCADE;
 | 
				
			||||||
 | 
					CREATE OR REPLACE VIEW edge_active_attribute_view AS
 | 
				
			||||||
 | 
					SELECT ee.id
 | 
				
			||||||
 | 
					        , ee.created_time
 | 
				
			||||||
 | 
					        , ee.additional_info
 | 
				
			||||||
 | 
					        , ee.customer_id
 | 
				
			||||||
 | 
					        , ee.root_rule_chain_id
 | 
				
			||||||
 | 
					        , ee.type
 | 
				
			||||||
 | 
					        , ee.name
 | 
				
			||||||
 | 
					        , ee.label
 | 
				
			||||||
 | 
					        , ee.routing_key
 | 
				
			||||||
 | 
					        , ee.secret
 | 
				
			||||||
 | 
					        , ee.tenant_id
 | 
				
			||||||
 | 
					        , ee.version
 | 
				
			||||||
 | 
					FROM edge ee
 | 
				
			||||||
 | 
					        JOIN attribute_kv ON ee.id = attribute_kv.entity_id
 | 
				
			||||||
 | 
					        JOIN key_dictionary ON attribute_kv.attribute_key = key_dictionary.key_id
 | 
				
			||||||
 | 
					WHERE attribute_kv.bool_v = true AND key_dictionary.key = 'active';
 | 
				
			||||||
 | 
					
 | 
				
			||||||
CREATE OR REPLACE FUNCTION create_or_update_active_alarm(
 | 
					CREATE OR REPLACE FUNCTION create_or_update_active_alarm(
 | 
				
			||||||
                                        t_id uuid, c_id uuid, a_id uuid, a_created_ts bigint,
 | 
					                                        t_id uuid, c_id uuid, a_id uuid, a_created_ts bigint,
 | 
				
			||||||
                                        a_o_id uuid, a_o_type integer, a_type varchar,
 | 
					                                        a_o_id uuid, a_o_type integer, a_type varchar,
 | 
				
			||||||
 | 
				
			|||||||
@ -14,6 +14,7 @@ DROP VIEW IF EXISTS device_info_active_attribute_view CASCADE;
 | 
				
			|||||||
DROP VIEW IF EXISTS device_info_active_ts_view CASCADE;
 | 
					DROP VIEW IF EXISTS device_info_active_ts_view CASCADE;
 | 
				
			||||||
DROP VIEW IF EXISTS device_info_view CASCADE;
 | 
					DROP VIEW IF EXISTS device_info_view CASCADE;
 | 
				
			||||||
DROP VIEW IF EXISTS alarm_info CASCADE;
 | 
					DROP VIEW IF EXISTS alarm_info CASCADE;
 | 
				
			||||||
 | 
					DROP VIEW IF EXISTS edge_acitve_attribute_view CASCADE;
 | 
				
			||||||
 | 
					
 | 
				
			||||||
DROP TABLE IF EXISTS admin_settings;
 | 
					DROP TABLE IF EXISTS admin_settings;
 | 
				
			||||||
DROP TABLE IF EXISTS entity_alarm;
 | 
					DROP TABLE IF EXISTS entity_alarm;
 | 
				
			||||||
 | 
				
			|||||||
		Loading…
	
	
			
			x
			
			
		
	
		Reference in New Issue
	
	Block a user