Merge pull request #13278 from jekka001/view-for-active-edges

PostgreSQL View for active Edges
This commit is contained in:
Viacheslav Klimov 2025-05-23 15:35:32 +03:00 committed by GitHub
commit 2f061c448b
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
4 changed files with 27 additions and 15 deletions

View File

@ -44,17 +44,10 @@ public interface EdgeRepository extends JpaRepository<EdgeEntity, UUID> {
"WHERE d.id = :edgeId")
EdgeInfoEntity findEdgeInfoById(@Param("edgeId") UUID edgeId);
@Query(value = "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' " +
"AND (:textSearch IS NULL OR ee.name ILIKE CONCAT('%', :textSearch, '%')) " +
"ORDER BY ee.id", nativeQuery = true)
Page<EdgeEntity> findActiveEdges(@Param("textSearch") String textSearch,
Pageable pageable);
@Query(value = "SELECT * FROM edge_active_attribute_view edge_active",
countQuery = "SELECT count(*) FROM edge_active_attribute_view",
nativeQuery = true)
Page<EdgeEntity> findActiveEdges(Pageable pageable);
@Query("SELECT d.id FROM EdgeEntity d WHERE d.tenantId = :tenantId " +
"AND (:textSearch IS NULL OR ilike(d.name, CONCAT('%', :textSearch, '%')) = true)")
@ -171,4 +164,5 @@ public interface EdgeRepository extends JpaRepository<EdgeEntity, UUID> {
@Query("SELECT new org.thingsboard.server.common.data.edqs.fields.EdgeFields(e.id, e.createdTime, e.tenantId, e.customerId," +
"e.name, e.version, e.type, e.label, e.additionalInfo) FROM EdgeEntity e WHERE e.id > :id ORDER BY e.id")
List<EdgeFields> findNextBatch(@Param("id") UUID id, Limit limit);
}

View File

@ -68,10 +68,7 @@ public class JpaEdgeDao extends JpaAbstractDao<EdgeEntity, Edge> implements Edge
@Override
public PageData<Edge> findActiveEdges(PageLink pageLink) {
return DaoUtil.toPageData(
edgeRepository.findActiveEdges(
pageLink.getTextSearch(),
DaoUtil.toPageable(pageLink)));
return DaoUtil.toPageData(edgeRepository.findActiveEdges(DaoUtil.toPageable(pageLink)));
}
@Override

View File

@ -72,6 +72,26 @@ u.first_name as assignee_first_name, u.last_name as assignee_last_name, u.email
FROM alarm a
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'
ORDER BY ee.id;
CREATE OR REPLACE FUNCTION create_or_update_active_alarm(
t_id uuid, c_id uuid, a_id uuid, a_created_ts bigint,
a_o_id uuid, a_o_type integer, a_type varchar,

View File

@ -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_view 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 entity_alarm;